Return-Path: Delivered-To: apmail-db-derby-dev-archive@www.apache.org Received: (qmail 22331 invoked from network); 19 Dec 2006 18:39:48 -0000 Received: from hermes.apache.org (HELO mail.apache.org) (140.211.11.2) by minotaur.apache.org with SMTP; 19 Dec 2006 18:39:48 -0000 Received: (qmail 9531 invoked by uid 500); 19 Dec 2006 18:39:54 -0000 Delivered-To: apmail-db-derby-dev-archive@db.apache.org Received: (qmail 9509 invoked by uid 500); 19 Dec 2006 18:39:54 -0000 Mailing-List: contact derby-dev-help@db.apache.org; run by ezmlm Precedence: bulk List-Help: List-Unsubscribe: List-Post: List-Id: Reply-To: Delivered-To: mailing list derby-dev@db.apache.org Received: (qmail 9492 invoked by uid 99); 19 Dec 2006 18:39:53 -0000 Received: from herse.apache.org (HELO herse.apache.org) (140.211.11.133) by apache.org (qpsmtpd/0.29) with ESMTP; Tue, 19 Dec 2006 10:39:53 -0800 X-ASF-Spam-Status: No, hits=0.0 required=10.0 tests= X-Spam-Check-By: apache.org Received: from [140.211.11.4] (HELO brutus.apache.org) (140.211.11.4) by apache.org (qpsmtpd/0.29) with ESMTP; Tue, 19 Dec 2006 10:39:45 -0800 Received: from brutus (localhost [127.0.0.1]) by brutus.apache.org (Postfix) with ESMTP id 543D4714295 for ; Tue, 19 Dec 2006 10:39:25 -0800 (PST) Message-ID: <15721226.1166553565342.JavaMail.jira@brutus> Date: Tue, 19 Dec 2006 10:39:25 -0800 (PST) From: "Daniel John Debrunner (JIRA)" To: derby-dev@db.apache.org Subject: [jira] Commented: (DERBY-47) Some possible improvements to IN optimization In-Reply-To: <933072060.1098378373674.JavaMail.apache@nagoya> MIME-Version: 1.0 Content-Type: text/plain; charset=utf-8 Content-Transfer-Encoding: 7bit X-Virus-Checked: Checked by ClamAV on apache.org [ http://issues.apache.org/jira/browse/DERBY-47?page=comments#action_12459722 ] Daniel John Debrunner commented on DERBY-47: -------------------------------------------- > The next question is how do I pass information to the VTI implementation regarding which parameters of the activation should it use > as the values in the virtual table? I suspect that the constructor will need to take the range [N, N+M) of parameter indices, and also > some array of literals; i.e. the IN list can consist of both parameter markers, and literal parameters. If the IN list were to include > columns or functions, I suspect we'd want to skip this "solution" as it wouldn't support that. Based on past experience it would be good to avoid generating code per literal value, as that's an easy way to hit limits in the compiled byte code. I think you should be able to build up a collection of literal values (DataValueDescriptors) at compile time and store it as a saved object. The runtime ResultSet can then obtain the same collection from the saved objects. See CompilerContext.addSavedObject I think you have to do the same approach for the parameters, build up a collection of valid parameters, though maybe if you limit your solution you can get away with a range. A range does not work in the general case where a single value in the IN list can be composed of multiple parameters, e.g. IN (?,?,?, ?+?) With these approaches the amount of information required to create a ResultSet for such an IN list is fixed and not a factor of the number of values, thus leading to smaller generated code to generate the result set. > Some possible improvements to IN optimization > --------------------------------------------- > > Key: DERBY-47 > URL: http://issues.apache.org/jira/browse/DERBY-47 > Project: Derby > Issue Type: Improvement > Components: SQL > Affects Versions: 10.0.2.0 > Environment: all > Reporter: Sunitha Kambhampati > Attachments: derby-47-performance-data.txt, derby-47-performance-data.txt, Derby47PerformanceTest.java, Derby47PerformanceTest.java, QueryPlanUniqueIndexAndWordIndexOneTerm.txt, QueryPlanUniqueIndexAndWordIndexTwoTerms.txt, QueryPlanUniqueIndexOnlyOneTerm.txt, QueryPlanUniqueIndexOnlyTwoTerms.txt > > > 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