db-derby-dev mailing list archives

Site index · List index
Message view « Date » · « Thread »
Top « Date » · « Thread »
From "Tony Brusseau (JIRA)" <j...@apache.org>
Subject [jira] Issue Comment Edited: (DERBY-4422) Extremely slow subqueries when subquerying on strings
Date Fri, 05 Mar 2010 19:44:27 GMT

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

Tony Brusseau edited comment on DERBY-4422 at 3/5/10 7:43 PM:
--------------------------------------------------------------

Per the documentation on materialization:

http://db.apache.org/derby/docs/10.5/tuning/ctuntransform25857.html 

I rewrote the query from:

SELECT DISTINCT INTERNAL_ID
FROM OC_CONCEPTS
WHERE
   (INTERNAL_ID IN (SELECT DISTINCT CONCEPT_ID FROM OC_CONCEPT_STRINGS WHERE NL_LC = 'dash'))

and transformed it into:

SELECT DISTINCT INTERNAL_ID
FROM OC_CONCEPTS, (SELECT DISTINCT CONCEPT_ID FROM OC_CONCEPT_STRINGS WHERE NL_LC = 'dash')
X
WHERE (OC_CONCEPTS.INTERNAL_ID = X.CONCEPT_ID)

Now the query runs blindingly fast.  I also made a similar change to the bigger query that
I want to do, and got the same dramatic speedup. I guess the real bug here is that the optimizer
is not automatically optimizing the queries in such a manner (or possibly that the materialization
optimization is too narrow and should be broadened to apply to a larger subset of queries).
There may be a secondary issue noted by Bryan where minor changes in the query yield a dramatically
less good optimization strategy.


      was (Author: apb):
    Per the documentation on materialization:

http://db.apache.org/derby/docs/10.5/tuning/ctuntransform25857.html 

I rewrote the query from:

SELECT DISTINCT INTERNAL_ID
FROM OC_CONCEPTS
WHERE
   (INTERNAL_ID IN (SELECT DISTINCT CONCEPT_ID FROM OC_CONCEPT_STRINGS WHERE NL_LC = 'dash'))

and transformed it into:

SELECT DISTINCT INTERNAL_ID
FROM OC_CONCEPTS, (SELECT DISTINCT CONCEPT_ID FROM OC_CONCEPT_STRINGS WHERE NL_LC = 'dash')
X
WHERE (OC_CONCEPTS.INTERNAL_ID = X.CONCEPT_ID)

Now the query runs blindingly fast.  I also made a similar change to the bigger query that
I want to do, and got the same dramatic speedup. I guess the real bug here is that the optimizer
is not automatically optimizing the queries in such a manner (or possibly that the materialization
optimization is too narrow and should be broadened). There may be a secondary issue noted
by Bryan where minor changes in the query yield a dramatically less good optimization strategy.

  
> Extremely slow subqueries when subquerying on strings
> -----------------------------------------------------
>
>                 Key: DERBY-4422
>                 URL: https://issues.apache.org/jira/browse/DERBY-4422
>             Project: Derby
>          Issue Type: Bug
>    Affects Versions: 10.5.3.0
>         Environment: Suse Unix 10.3.
>            Reporter: Tony Brusseau
>         Attachments: badqp.txt, derby.log, fixed-time-derby.log, goodqp.txt, SQLFile1.sqlaa.gz,
SQLFile1.sqlab.gz, SQLFile2.sqlaa.gz, SQLFile2.sqlab.gz, SQLFile2.sqlac.gz, tmp2.sql, unlimited-time-derby.log
>
>
> SELECT DISTINCT C.INTERNAL_ID 
> FROM OC_CONCEPTS C
> WHERE
>    (C.INTERNAL_ID IN (SELECT DISTINCT OCS.CONCEPT_ID FROM OC_CONCEPT_STRINGS OCS WHERE
OCS.CONCEPT_ID=1))
> Both queries above are trivial and they are both acting on fully indexed primary key
columns. This query runs just fine. 
> However, when I make the small modification of searching on an indexed text column in
the sub query, it takes over 6 seconds to run, even though both queries independently take
< 1ms run.
> SELECT DISTINCT C.INTERNAL_ID 
> FROM OC_CONCEPTS C
> WHERE
>    (C.INTERNAL_ID IN (SELECT DISTINCT OCS.CONCEPT_ID FROM OC_CONCEPT_STRINGS OCS WHERE
OCS.NL_LC = 'dash'))

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


Mime
View raw message