[ http://issues.apache.org/jira/browse/DERBY-713?page=comments#action_12363227 ]
Frank Karlstrøm commented on DERBY-713: --------------------------------------- > I'm really surprised that this problem doesn't seem to be affecting a lot > more people. Is it really the case that most users' queries are simple and > straight-forward enough not to be hit by this? Or are most Derby databases > small enough to perform acceptably even when the optimizer makes poor > choices? I consider my database to be rather small, and my query to be relatively simple, but I think I am affected by this issue. Explanation: I have two tables, aTable and bTable with about 15 cols on a Table and 5 cols on bTable. bTable refers to aTable. aTable has about 3000 rows, while the bTable has about 30000 rows. The following query is executed against these two tables: select a.col1, a.col2, a.col3, (select sum(b.col1) from bTable as b where bTable.aTable_id=a.id) where a.id=#### both table have appropiate indexes on a.id, b.id and b.aTable_id. When this query is executed, the queryplan indicates that a tablescan across the btable is executed, and all the rows are visited. there are only about 20 records for each aTable reference in bTable. this query averages to about 3-500ms, while the indexes had been used, I would guess the time would be max 30ms. Alternatives for this query: Create a in memory table of the sums for the bTable, and update it when needed. This cache will increase the memoryreq. for my application, and introduce extra maintenance and extra processing on insert/update/delete. rewrite the query to use joins and group by. Have tried it, and the same result happened, a tablescan acosss bTable. create a view over the bTable sum(). Have not tried. Will this increase performance perhaps? Create a flattened table for the bTable sums, and update it with triggers. This will increase performance, but introduce extra maintenace overhead, and extra processing on insert/update/delete. The best thing would of course be that this query used the indexes. DERBY-573 has exactly what I need, a way to specify how the join should be performed. Other suggestions are welcome. :) > CLONE - Query optimizer should not make poor choices when optimizing IN and > WHERE clauses > ----------------------------------------------------------------------------------------- > > Key: DERBY-713 > URL: http://issues.apache.org/jira/browse/DERBY-713 > Project: Derby > Type: Improvement > Components: SQL > Versions: 10.0.2.0 > Environment: all > Reporter: Daniel James Neades > > Consider a simple case of - > A table tbl has 10000 rows, there is a primary key index on i1 > and the query in question is > select * from tbl where i1 in (-1,100000) > derby does a table scan of the entire table even though the "IN" list has > only two values and the comparison is on a field that has an index. > Briefly looking at the code, it seems like we insert a between and use the IN > list to get the start and stop values for the scan. Thus the range of the > values in the "IN" list here plays an important role. > Thus if the query was changed to select * from tbl where i1 in (-1, 1), an > index scan would be chosen. > It would be nice if we could do something clever in this case where there is > clearly an index on the field and the number of values in the IN list is > known. Maybe use the rowcount estimate and the IN list size to do some > optimizations. > - consider the length of the "IN" list to do searches on the table. ie use > the IN list values to do index key searches on the table, > -or try to convert it to a join. Use the "IN" list values to create a > temporary table and do a join. It is most likely that the optimizer will > choose the table with "IN" list here as the outer table in the join and thus > will do key searches on the larger table. > ------------------------------------------------------------------- > some query plans that I logged using derby.language.logQueryPlan=true for > some similar queries: > Table has ascending values from 0 - 9999 for i1. primary key index on i1. > GMT Thread[UT0,5,main] (XID = 19941), (SESSIONID = 0), select * from > scanfixed where i1 in (-1,9999,9998,9997,9996,9995,9994,9993,9992,9991,9990) > ******* Project-Restrict ResultSet (2): > Number of opens = 1 > Rows seen = 10000 > Rows filtered = 9990 > restriction = true > projection = false > constructor time (milliseconds) = 0 > open time (milliseconds) = 0 > next time (milliseconds) = 0 > close time (milliseconds) = 0 > restriction time (milliseconds) = 0 > projection time (milliseconds) = 0 > optimizer estimated row count: 750.38 > optimizer estimated cost: 8579.46 > Source result set: > Table Scan ResultSet for SCANFIXED at read committed isolation level > using instantaneous share row locking chosen by the optimizer > Number of opens = 1 > Rows seen = 10000 > Rows filtered = 0 > Fetch Size = 16 > constructor time (milliseconds) = 0 > open time (milliseconds) = 0 > next time (milliseconds) = 0 > close time (milliseconds) = 0 > next time in milliseconds/row = 0 > scan information: > Bit set of columns fetched=All > Number of columns fetched=9 > Number of pages visited=417 > Number of rows qualified=10000 > Number of rows visited=10000 > Scan type=heap > start position: > null stop position: > null qualifiers: > Column[0][0] Id: 0 > Operator: <= > Ordered nulls: false > Unknown return value: false > Negate comparison result: false > Column[0][1] Id: 0 > Operator: < > Ordered nulls: false > Unknown return value: true > Negate comparison result: true > optimizer estimated row count: 750.38 > optimizer estimated cost: 8579.46 > --------------------------------------------------------------------------------------------------------------------------------------------------------------------------- > l > 2004-10-14 18:59:47.577 GMT Thread[UT0,5,main] (XID = 19216), (SESSIONID = > 0), select * from scanfixed where i1 in > (9999,9998,9997,9996,9995,9994,9993,9992,9991,9990) ******* Project-Restrict > ResultSet (3): > Number of opens = 1 > Rows seen = 10 > Rows filtered = 0 > restriction = true > projection = true > constructor time (milliseconds) = 0 > open time (milliseconds) = 0 > next time (milliseconds) = 0 > close time (milliseconds) = 0 > restriction time (milliseconds) = 0 > projection time (milliseconds) = 0 > optimizer estimated row count: 4.80 > optimizer estimated cost: 39.53 > Source result set: > Index Row to Base Row ResultSet for SCANFIXED: > Number of opens = 1 > Rows seen = 10 > Columns accessed from heap = {0, 1, 2, 3, 4, 5, 6, 7, 8} > constructor time (milliseconds) = 0 > open time (milliseconds) = 0 > next time (milliseconds) = 0 > close time (milliseconds) = 0 > optimizer estimated row count: 4.80 > optimizer estimated cost: 39.53 > Index Scan ResultSet for SCANFIXED using index SCANFIXEDX at > read committed isolation level using instantaneous share row locking chosen > by the optimizer > Number of opens = 1 > Rows seen = 10 > Rows filtered = 0 > Fetch Size = 16 > constructor time (milliseconds) = 0 > open time (milliseconds) = 0 > next time (milliseconds) = 0 > close time (milliseconds) = 0 > next time in milliseconds/row = 0 > scan information: > Bit set of columns fetched=All > Number of columns fetched=2 > Number of deleted rows visited=0 > Number of pages visited=2 > Number of rows qualified=10 > Number of rows visited=10 > Scan type=btree > Tree height=2 > start position: > >= on first 1 column(s). > Ordered null semantics on the following columns: > stop position: > > on first 1 column(s). > Ordered null semantics on the following columns: > qualifiers: > None > optimizer estimated row count: 4.80 > optimizer estimated cost: 39.53 -- This message is automatically generated by JIRA. - If you think it was sent incorrectly contact one of the administrators: http://issues.apache.org/jira/secure/Administrators.jspa - For more information on JIRA, see: http://www.atlassian.com/software/jira
