Return-Path: X-Original-To: apmail-db-derby-dev-archive@www.apache.org Delivered-To: apmail-db-derby-dev-archive@www.apache.org Received: from mail.apache.org (hermes.apache.org [140.211.11.3]) by minotaur.apache.org (Postfix) with SMTP id 751DEC3D3 for ; Wed, 9 May 2012 18:50:16 +0000 (UTC) Received: (qmail 67998 invoked by uid 500); 9 May 2012 18:50:16 -0000 Delivered-To: apmail-db-derby-dev-archive@db.apache.org Received: (qmail 67979 invoked by uid 500); 9 May 2012 18:50:16 -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 67972 invoked by uid 99); 9 May 2012 18:50:16 -0000 Received: from nike.apache.org (HELO nike.apache.org) (192.87.106.230) by apache.org (qpsmtpd/0.29) with ESMTP; Wed, 09 May 2012 18:50:16 +0000 X-ASF-Spam-Status: No, hits=-2000.0 required=5.0 tests=ALL_TRUSTED,T_RP_MATCHES_RCVD X-Spam-Check-By: apache.org Received: from [140.211.11.116] (HELO hel.zones.apache.org) (140.211.11.116) by apache.org (qpsmtpd/0.29) with ESMTP; Wed, 09 May 2012 18:50:11 +0000 Received: from hel.zones.apache.org (hel.zones.apache.org [140.211.11.116]) by hel.zones.apache.org (Postfix) with ESMTP id 8FBB348A0B1 for ; Wed, 9 May 2012 18:49:49 +0000 (UTC) Date: Wed, 9 May 2012 18:49:49 +0000 (UTC) From: "Mamta A. Satoor (JIRA)" To: derby-dev@db.apache.org Message-ID: <345106567.45847.1336589389590.JavaMail.tomcat@hel.zones.apache.org> In-Reply-To: <1396323358.28.1334955453011.JavaMail.tomcat@hel.zones.apache.org> Subject: [jira] [Commented] (DERBY-5702) Creating a foreign key constraint does not automatically create a statistics row if foreign key constraint will share a backing index created for a primary key MIME-Version: 1.0 Content-Type: text/plain; charset=utf-8 Content-Transfer-Encoding: 7bit X-JIRA-FingerPrint: 30527f35849b9dde25b450d4833f0394 [ https://issues.apache.org/jira/browse/DERBY-5702?page=com.atlassian.jira.plugin.system.issuetabpanels:comment-tabpanel&focusedCommentId=13271690#comment-13271690 ] Mamta A. Satoor commented on DERBY-5702: ---------------------------------------- While working on an upgrade test for DERBY-4115, I found that a missing statistics like this can be created with update statistics procedure but that procedure was added in 10.5 and hence is only available in 10.5 and higher. Additionally, A table compress is supposed to update the statistics as well which was added in 10.3 but I found that running table compress did not create this missing statistics. So, whenever we decide to fix this issue, we probably want to also see why table compress would not add missing statistics for a constraint which is sharing a backing index. > Creating a foreign key constraint does not automatically create a statistics row if foreign key constraint will share a backing index created for a primary key > --------------------------------------------------------------------------------------------------------------------------------------------------------------- > > Key: DERBY-5702 > URL: https://issues.apache.org/jira/browse/DERBY-5702 > Project: Derby > Issue Type: Bug > Components: SQL > Affects Versions: 10.8.2.2 > Reporter: Mamta A. Satoor > > When a foreign key constraints is created on a column which already has a primary key constraint, the statistics for foreign key constraint do not get created automatically. Have to run update statistics by hand to add statistics for foreign key constraint. I hope my understanding of statistics creation is correct in this regards. Following script shows the issue > java -Dderby.storage.indexStats.auto=false -Dij.exceptionTrace=true org.apache.derby.tools.ij > connect 'jdbc:derby:db1;create=true'; > CREATE TABLE TEST_TAB_1 > ( > ID INTEGER NOT NULL primary key > ); > CREATE TABLE TEST_TAB_2 > ( > ID INTEGER not null, ID1 INTEGER not null > ); > insert into TEST_TAB_1 values (1); > insert into test_tab_2 values(1,1); > CALL SYSCS_UTIL.SYSCS_UPDATE_STATISTICS('APP','TEST_TAB_1', null); > CALL SYSCS_UTIL.SYSCS_UPDATE_STATISTICS('APP','TEST_TAB_2', null); > --At this point, we will find statistics row for primary key constraint on TEST_TAB_1 > select > c.TABLEID, > c.CONGLOMERATENUMBER, > c.CONGLOMERATENAME, > c.ISINDEX, > c.ISCONSTRAINT, > c.CONGLOMERATEID, > t.TABLEID, > t.TABLENAME, > t.TABLETYPE, > s.STATID, > s.REFERENCEID, > s.TABLEID, > s.CREATIONTIMESTAMP, > s.TYPE, > s.VALID, > s.COLCOUNT, > CAST(STATISTICS AS VARCHAR(40)) as STATISTICS > from sys.SYSCONGLOMERATES c join sys.SYSTABLES t on c.TABLEID = t.TABLEID join sys.SYSSTATISTICS s on s.TABLEID = t.TABLEID > where t.TABLENAME = 'TEST_TAB_1' and c.ISINDEX = false; > --Now create primary key constraint on TEST_TAB_2 > ALTER TABLE TEST_TAB_2 > ADD CONSTRAINT TEST_TAB_2_PK_1 > PRIMARY KEY (id); > --At this point, we will find statistics row for primary key constraint on TEST_TAB_2 > select > c.TABLEID, > c.CONGLOMERATENUMBER, > c.CONGLOMERATENAME, > c.ISINDEX, > c.ISCONSTRAINT, > c.CONGLOMERATEID, > t.TABLEID, > t.TABLENAME, > t.TABLETYPE, > s.STATID, > s.REFERENCEID, > s.TABLEID, > s.CREATIONTIMESTAMP, > s.TYPE, > s.VALID, > s.COLCOUNT, > CAST(STATISTICS AS VARCHAR(40)) as STATISTICS > from sys.SYSCONGLOMERATES c join sys.SYSTABLES t on c.TABLEID = t.TABLEID join sys.SYSSTATISTICS s on s.TABLEID = t.TABLEID > where t.TABLENAME = 'TEST_TAB_2' and c.ISINDEX = false; > --Now if we create a foreign key constraint on TEST_TAB_2(ID), there will be no statistics created for it. > ALTER TABLE TEST_TAB_2 > ADD CONSTRAINT TEST_TAB_2_FK_1 > FOREIGN KEY(id) REFERENCES TEST_TAB_1(id); > --still only one statistics row for TEST_TAB_2 > select > c.TABLEID, > c.CONGLOMERATENUMBER, > c.CONGLOMERATENAME, > c.ISINDEX, > c.ISCONSTRAINT, > c.CONGLOMERATEID, > t.TABLEID, > t.TABLENAME, > t.TABLETYPE, > s.STATID, > s.REFERENCEID, > s.TABLEID, > s.CREATIONTIMESTAMP, > s.TYPE, > s.VALID, > s.COLCOUNT, > CAST(STATISTICS AS VARCHAR(40)) as STATISTICS > from sys.SYSCONGLOMERATES c join sys.SYSTABLES t on c.TABLEID = t.TABLEID join sys.SYSSTATISTICS s on s.TABLEID = t.TABLEID > where t.TABLENAME = 'TEST_TAB_2' and c.ISINDEX = false; > --Running statistics creation by hand will create 2nd statistics row for TEST_TAB_2 > CALL SYSCS_UTIL.SYSCS_UPDATE_STATISTICS('APP','TEST_TAB_2', null); > -- now will have 2 statistics rows for TEST_TAB_2 > select > c.TABLEID, > c.CONGLOMERATENUMBER, > c.CONGLOMERATENAME, > c.ISINDEX, > c.ISCONSTRAINT, > c.CONGLOMERATEID, > t.TABLEID, > t.TABLENAME, > t.TABLETYPE, > s.STATID, > s.REFERENCEID, > s.TABLEID, > s.CREATIONTIMESTAMP, > s.TYPE, > s.VALID, > s.COLCOUNT, > CAST(STATISTICS AS VARCHAR(40)) as STATISTICS > from sys.SYSCONGLOMERATES c join sys.SYSTABLES t on c.TABLEID = t.TABLEID join sys.SYSSTATISTICS s on s.TABLEID = t.TABLEID > where t.TABLENAME = 'TEST_TAB_2' and c.ISINDEX = false; > --If I create foreign key on a column that does not share backing index with primary key, stats will get created automatically > ALTER TABLE TEST_TAB_2 > ADD CONSTRAINT TEST_TAB_2_FK_2 > FOREIGN KEY(id1) REFERENCES TEST_TAB_1(id); > --will have additional constraint row for new foreign key constraint on TEST_TAB_2 > select > c.TABLEID, > c.CONGLOMERATENUMBER, > c.CONGLOMERATENAME, > c.ISINDEX, > c.ISCONSTRAINT, > c.CONGLOMERATEID, > t.TABLEID, > t.TABLENAME, > t.TABLETYPE, > s.STATID, > s.REFERENCEID, > s.TABLEID, > s.CREATIONTIMESTAMP, > s.TYPE, > s.VALID, > s.COLCOUNT, > CAST(STATISTICS AS VARCHAR(40)) as STATISTICS > from sys.SYSCONGLOMERATES c join sys.SYSTABLES t on c.TABLEID = t.TABLEID join sys.SYSSTATISTICS s on s.TABLEID = t.TABLEID > where t.TABLENAME = 'TEST_TAB_2' and c.ISINDEX = false; -- This message is automatically generated by JIRA. If you think it was sent incorrectly, please contact your JIRA administrators: https://issues.apache.org/jira/secure/ContactAdministrators!default.jspa For more information on JIRA, see: http://www.atlassian.com/software/jira