[ 
https://issues.apache.org/jira/browse/DERBY-3301?page=com.atlassian.jira.plugin.system.issuetabpanels:comment-tabpanel&focusedCommentId=12562582#action_12562582
 ] 

A B commented on DERBY-3301:
----------------------------

Thank you for your continued work on this, Thomas, and for your patience with 
my feedback.
A couple of follow-up comments...

-- 1 --

> Not flattening in the case where SQ2 is an ANY or IN query
> is already handled in the existing code.

Can you point me to the place in the code where this check currently occurs?  
Note how if I replace
all occurrences of "WHERE EXISTS" from derby-3301.sql with "WHERE ... IN", the 
query returns 5 rows
after applying your patch--but I think it should return 7 like the others?  So 
it seems the existing
code to handle ANY or IN queries may be incorrect, as well...

ij> select unbound_e.empid, unbound_p.projid
from departments this,
     employees unbound_e,
     projects unbound_p
where this.id in (
    select this_employees_e.department from employees this_employees_e
    where this_employees_e.empid in (
        select this_employees_e_projects_p.empid
          from project_employees this_employees_e_projects_p
        where this_employees_e_projects_p.empid = this_employees_e.empid
        and this_employees_e.department = this.id
        and unbound_p.projid = this_employees_e_projects_p.projid
        and unbound_e.empid = this_employees_e.empid)
    );

EMPID      |PROJID
-----------------------
11         |101
12         |102
13         |102
14         |103
15         |103

5 rows selected

If I make the following change w.r.t your patch:

-        if ( isWhereSubquery() && isEXISTS() ) {
+        if ( isWhereSubquery() && (isEXISTS() || isANY() || isIN()) ) {

then the above query returns 7 rows, as I think it should.

-- 2 --

With respect to derby-3301-4.diff, I noticed that we still check for an EXISTS 
WHERE subquery for the
second if statement, i.e.: at line 2382 (with your patch applied):

                if (sn.originalWhereClause != null &&
                    sn.originalWhereClause instanceof SubqueryNode){
                        SubqueryNode tmp = (SubqueryNode) 
sn.originalWhereClause;
                        if ( tmp.isWhereSubquery() && tmp.isEXISTS() ) { -- *** 
Note the "isExists()" check...

Is there any reason not to remove "tmp.isEXISTS()" from inner "if" statement, 
similar to what you
did in the first half of this method?    Note how the query I posted yesterday 
with "WHERE ... IN" still
looks to return incorrect results (3 rows, when I think it should return 
7?)--but if I remove the
"tmp.isEXISTS()" check from the "if" statement, that query returns 7 rows.  I.e.

                        SubqueryNode tmp = (SubqueryNode) 
sn.originalWhereClause;
-                       if ( tmp.isWhereSubquery() && tmp.isEXISTS() ) {
+                       if ( tmp.isWhereSubquery() ) {

Yields:

ij> select unbound_e.empid, unbound_p.projid
from departments this,
     employees unbound_e,
     projects unbound_p
where exists (
    select 1 from employees this_employees_e
    where this_employees_e.empid in (
        select this_employees_e_projects_p.empid
          from project_employees this_employees_e_projects_p
        where this_employees_e_projects_p.empid = this_employees_e.empid
        and this_employees_e.department = this.id
        and unbound_p.projid = this_employees_e_projects_p.projid
        and unbound_e.empid = this_employees_e.empid)
    );

EMPID      |PROJID
-----------------------
11         |101
12         |101
13         |101
12         |102
13         |102
14         |103
15         |103

7 rows selected

>From what I can tell, the two modifications to your patch mentioned above make 
>the method
agree fully with the documentation, and appear to make all of the queries in 
question return
the correct number of rows.  Do they seem like reasonable modifications to you?

Of course this entire comment is based on the assumption that the two queries I 
wrote above
with "WHERE ... IN" are in fact supposed to return 7 rows.  If that's not true, 
then you can pretty
much ignore everything in this particular comment...

> Incorrect result from query with nested EXIST
> ---------------------------------------------
>
>                 Key: DERBY-3301
>                 URL: https://issues.apache.org/jira/browse/DERBY-3301
>             Project: Derby
>          Issue Type: Bug
>          Components: SQL
>    Affects Versions: 10.1.3.1, 10.2.1.6, 10.3.2.1
>            Reporter: Craig Russell
>            Assignee: Thomas Nielsen
>         Attachments: d3301-queryplan.log, derby-3301-1.diff, 
> derby-3301-1.stat, derby-3301-2.diff, derby-3301-3.diff, derby-3301-3b.diff, 
> derby-3301-4.diff, derby-3301-test-1.diff, derby-3301-test-1.stat, 
> derby-3301.sql
>
>
> Derby returns unexpected results from a query with embedded EXIST clauses. 
> The query SQL is generated by the JPOX jdo implementation and is supposed to 
> return all of the PERSONS and PROJECTS where there is an entry in the join 
> table. This query works as expected when using MySQL.
> Here's the query:
> SELECT UNBOUND_E.PERSONID, UNBOUND_P.PROJID 
> FROM applicationidentity0.DEPARTMENTS THIS, 
>      applicationidentity0.PERSONS UNBOUND_E, 
>      applicationidentity0.PROJECTS UNBOUND_P 
> WHERE EXISTS ( 
>     SELECT 1 FROM applicationidentity0.PERSONS THIS_EMPLOYEES_E 
>     WHERE EXISTS ( 
>         SELECT 1 FROM applicationidentity0.PROJECT_MEMBER 
> THIS_EMPLOYEES_E_PROJECTS_P 
>         WHERE THIS_EMPLOYEES_E_PROJECTS_P."MEMBER" = 
> THIS_EMPLOYEES_E.PERSONID 
>         AND THIS_EMPLOYEES_E_PROJECTS_P."MEMBER" = THIS_EMPLOYEES_E.PERSONID 
>         AND THIS_EMPLOYEES_E.DEPARTMENT = THIS.ID 
>         AND THIS_EMPLOYEES_E.DEPARTMENT = THIS.ID 
>         AND UNBOUND_P.PROJID = THIS_EMPLOYEES_E_PROJECTS_P.PROJID 
>         AND UNBOUND_E.PERSONID = THIS_EMPLOYEES_E.PERSONID) 
>     );
> PERSONID   |PROJID     
> -----------------------
> 3          |1          
> 5          |3          
> 4          |3          
> 2          |1          
> 1          |1          
> 5 rows selected
> I'm expecting 7 rows to be returned here, one row for each row in the join 
> table. 
> Here's the schema:
> CREATE TABLE departments (
>     ID INTEGER NOT NULL,
>     NAME VARCHAR(32) NOT NULL,
>     EMP_OF_THE_MONTH INTEGER,
>     COMPANYID INTEGER,
>     DISCRIMINATOR VARCHAR(255),
>     CONSTRAINT DEPTS_COMP_FK FOREIGN KEY (COMPANYID) REFERENCES companies,
>     CONSTRAINT DEPTS_PK PRIMARY KEY (ID)
> );
> CREATE TABLE persons (
>     PERSONID INTEGER NOT NULL,
>     FIRSTNAME VARCHAR(32) NOT NULL,
>     LASTNAME VARCHAR(32) NOT NULL,
>     MIDDLENAME VARCHAR(32),
>     BIRTHDATE TIMESTAMP NOT NULL,
>     ADDRID INTEGER,
>     STREET VARCHAR(64),
>     CITY VARCHAR(64),
>     STATE CHAR(2),
>     ZIPCODE CHAR(5),
>     COUNTRY VARCHAR(64),
>     HIREDATE TIMESTAMP,
>     WEEKLYHOURS REAL,
>     DEPARTMENT INTEGER,
>     FUNDINGDEPT INTEGER,
>     MANAGER INTEGER,
>     MENTOR INTEGER,
>     HRADVISOR INTEGER,
>     SALARY REAL,
>     WAGE REAL,
>     DISCRIMINATOR varchar(255) NOT NULL,
>     CONSTRAINT PERS_DEPT_FK FOREIGN KEY (DEPARTMENT) REFERENCES departments,
>     CONSTRAINT PERS_FUNDDEPT_FK FOREIGN KEY (FUNDINGDEPT) REFERENCES 
> departments,
>     CONSTRAINT PERS_MANAGER_FK FOREIGN KEY (MANAGER) REFERENCES persons,
>     CONSTRAINT PERS_MENTOR_FK FOREIGN KEY (MENTOR) REFERENCES persons,
>     CONSTRAINT PERS_HRADVISOR_FK FOREIGN KEY (HRADVISOR) REFERENCES persons,
>     CONSTRAINT EMPS_PK PRIMARY KEY (PERSONID)
> );
> CREATE TABLE projects (
>     PROJID INTEGER NOT NULL,
>     NAME VARCHAR(32) NOT NULL,
>     BUDGET DECIMAL(11,2) NOT NULL,
>     DISCRIMINATOR VARCHAR(255),
>     CONSTRAINT PROJS_PK PRIMARY KEY (PROJID)
> );
> CREATE TABLE project_member (
>     PROJID INTEGER REFERENCES projects NOT NULL,
>     MEMBER INTEGER REFERENCES persons NOT NULL
> );
> ij> connect 
> 'jdbc:derby:/Users/clr/apache/jdo/trunk/tck2/target/database/derby/jdotckdb';
> ij> set schema applicationidentity0;
> 0 rows inserted/updated/deleted
> ij> select * from persons;
> PERSONID   |FIRSTNAME                       |LASTNAME                        
> |MIDDLENAME                      |BIRTHDATE                 |ADDRID     
> |STREET                                                          |CITY        
>                                                     |STA&|ZIPC&|COUNTRY       
>                                                   |HIREDATE                  
> |WEEKLYHOURS  |DEPARTMENT |FUNDINGDEPT|MANAGER    |MENTOR     |HRADVISOR  
> |SALARY       |WAGE         |DISCRIMINATOR                                    
>                                                                               
>  
> -------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
> 1          |emp1First                       |emp1Last                        
> |emp1Middle                      |1970-06-09 21:00:00.0     |NULL       |NULL 
>                                                            |NULL              
>                                               |NULL|NULL |NULL                
>                                             |1998-12-31 21:00:00.0     |40.0  
>        |NULL       |NULL       |NULL       |NULL       |NULL       |20000.0   
>    |NULL         |org.apache.jdo.tck.pc.company.FullTimeEmployee              
>                                                                     
> 2          |emp2First                       |emp2Last                        
> |emp2Middle                      |1975-12-21 21:00:00.0     |NULL       |NULL 
>                                                            |NULL              
>                                               |NULL|NULL |NULL                
>                                             |2003-06-30 21:00:00.0     |40.0  
>        |NULL       |NULL       |NULL       |NULL       |NULL       |10000.0   
>    |NULL         |org.apache.jdo.tck.pc.company.FullTimeEmployee              
>                                                                     
> 3          |emp3First                       |emp3Last                        
> |emp3Middle                      |1972-09-04 21:00:00.0     |NULL       |NULL 
>                                                            |NULL              
>                                               |NULL|NULL |NULL                
>                                             |2002-08-14 21:00:00.0     |19.0  
>        |NULL       |NULL       |NULL       |NULL       |NULL       |NULL      
>    |15.0         |org.apache.jdo.tck.pc.company.PartTimeEmployee              
>                                                                     
> 4          |emp4First                       |emp4Last                        
> |emp4Middle                      |1973-09-05 21:00:00.0     |NULL       |NULL 
>                                                            |NULL              
>                                               |NULL|NULL |NULL                
>                                             |2001-04-14 21:00:00.0     |0.0   
>        |NULL       |NULL       |NULL       |NULL       |NULL       |NULL      
>    |13.0         |org.apache.jdo.tck.pc.company.PartTimeEmployee              
>                                                                     
> 5          |emp5First                       |emp5Last                        
> |emp5Middle                      |1962-07-04 21:00:00.0     |NULL       |NULL 
>                                                            |NULL              
>                                               |NULL|NULL |NULL                
>                                             |1998-08-14 21:00:00.0     |0.0   
>        |NULL       |NULL       |NULL       |NULL       |NULL       |45000.0   
>    |NULL         |org.apache.jdo.tck.pc.company.FullTimeEmployee              
>                                                                     
> 5 rows selected
> ij> select * from projects;
> PROJID     |NAME                            |BUDGET       |DISCRIMINATOR      
>                                                                               
>                                
> -------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
> 1          |orange                          |2500000.99   
> |org.apache.jdo.tck.pc.company.Project                                        
>                                                    
> 2          |blue                            |50000.00     
> |org.apache.jdo.tck.pc.company.Project                                        
>                                                    
> 3          |green                           |2000.99      
> |org.apache.jdo.tck.pc.company.Project                                        
>                                                    
> 3 rows selected
> ij> select * from project_member;
> PROJID     |MEMBER     
> -----------------------
> 2          |3          
> 1          |3          
> 2          |2          
> 3          |5          
> 3          |4          
> 1          |2          
> 1          |1          
> 7 rows selected

-- 
This message is automatically generated by JIRA.
-
You can reply to this email to add a comment to the issue online.

Reply via email to