12daa64cdSdrh# 2014-06-17 22daa64cdSdrh# 32daa64cdSdrh# The author disclaims copyright to this source code. In place of 42daa64cdSdrh# a legal notice, here is a blessing: 52daa64cdSdrh# 62daa64cdSdrh# May you do good and not evil. 72daa64cdSdrh# May you find forgiveness for yourself and forgive others. 82daa64cdSdrh# May you share freely, never taking more than you give. 92daa64cdSdrh# 102daa64cdSdrh#************************************************************************* 112daa64cdSdrh# 122daa64cdSdrh# This file implements regression tests for SQLite library. The 132daa64cdSdrh# focus of this script is testing automatic index creation logic. 142daa64cdSdrh# 152daa64cdSdrh# This file contains a single real-world test case that was giving 162daa64cdSdrh# suboptimal performance because of over-use of automatic indexes. 172daa64cdSdrh# 182daa64cdSdrh 192daa64cdSdrhset testdir [file dirname $argv0] 202daa64cdSdrhsource $testdir/tester.tcl 212daa64cdSdrh 222daa64cdSdrh 232daa64cdSdrhdo_execsql_test autoindex2-100 { 242daa64cdSdrh CREATE TABLE t1( 252daa64cdSdrh t1_id largeint, 262daa64cdSdrh did char(9), 272daa64cdSdrh ptime largeint, 282daa64cdSdrh exbyte char(4), 292daa64cdSdrh pe_id int, 302daa64cdSdrh field_id int, 312daa64cdSdrh mass float, 322daa64cdSdrh param10 float, 332daa64cdSdrh param11 float, 342daa64cdSdrh exmass float, 352daa64cdSdrh deviation float, 362daa64cdSdrh trange float, 372daa64cdSdrh vstatus int, 382daa64cdSdrh commit_status int, 392daa64cdSdrh formula char(329), 402daa64cdSdrh tier int DEFAULT 2, 412daa64cdSdrh ssid int DEFAULT 0, 422daa64cdSdrh last_operation largeint DEFAULT 0, 432daa64cdSdrh admin_uuid int DEFAULT 0, 442daa64cdSdrh previous_value float, 452daa64cdSdrh job_id largeint, 462daa64cdSdrh last_t1 largeint DEFAULT 0, 472daa64cdSdrh data_t1 int, 482daa64cdSdrh previous_date largeint DEFAULT 0, 492daa64cdSdrh flg8 int DEFAULT 1, 502daa64cdSdrh failed_fields char(100) 512daa64cdSdrh ); 522daa64cdSdrh CREATE INDEX t1x0 on t1 (t1_id); 532daa64cdSdrh CREATE INDEX t1x1 on t1 (ptime, vstatus); 542daa64cdSdrh CREATE INDEX t1x2 on t1 (did, ssid, ptime, vstatus, exbyte, t1_id); 552daa64cdSdrh CREATE INDEX t1x3 on t1 (job_id); 562daa64cdSdrh 572daa64cdSdrh CREATE TABLE t2( 582daa64cdSdrh did char(9), 592daa64cdSdrh client_did char(30), 602daa64cdSdrh description char(49), 612daa64cdSdrh uid int, 622daa64cdSdrh tzid int, 632daa64cdSdrh privilege int, 642daa64cdSdrh param2 int, 652daa64cdSdrh type char(30), 662daa64cdSdrh subtype char(32), 672daa64cdSdrh dparam1 char(7) DEFAULT '', 682daa64cdSdrh param5 char(3) DEFAULT '', 692daa64cdSdrh notional float DEFAULT 0.000000, 702daa64cdSdrh create_time largeint, 712daa64cdSdrh sample_time largeint DEFAULT 0, 722daa64cdSdrh param6 largeint, 732daa64cdSdrh frequency int, 742daa64cdSdrh expiration largeint, 752daa64cdSdrh uw_status int, 762daa64cdSdrh next_sample largeint, 772daa64cdSdrh last_sample largeint, 782daa64cdSdrh reserve1 char(29) DEFAULT '', 792daa64cdSdrh reserve2 char(29) DEFAULT '', 802daa64cdSdrh reserve3 char(29) DEFAULT '', 812daa64cdSdrh bxcdr char(19) DEFAULT 'XY', 822daa64cdSdrh ssid int DEFAULT 1, 832daa64cdSdrh last_t1_id largeint, 842daa64cdSdrh reserve4 char(29) DEFAULT '', 852daa64cdSdrh reserve5 char(29) DEFAULT '', 862daa64cdSdrh param12 int DEFAULT 0, 872daa64cdSdrh long_did char(100) DEFAULT '', 882daa64cdSdrh gr_code int DEFAULT 0, 892daa64cdSdrh drx char(100) DEFAULT '', 902daa64cdSdrh parent_id char(9) DEFAULT '', 912daa64cdSdrh param13 int DEFAULT 0, 922daa64cdSdrh position float DEFAULT 1.000000, 932daa64cdSdrh client_did3 char(100) DEFAULT '', 942daa64cdSdrh client_did4 char(100) DEFAULT '', 952daa64cdSdrh dlib_id char(9) DEFAULT '' 962daa64cdSdrh ); 972daa64cdSdrh CREATE INDEX t2x0 on t2 (did); 982daa64cdSdrh CREATE INDEX t2x1 on t2 (client_did); 992daa64cdSdrh CREATE INDEX t2x2 on t2 (long_did); 1002daa64cdSdrh CREATE INDEX t2x3 on t2 (uid); 1012daa64cdSdrh CREATE INDEX t2x4 on t2 (param2); 1022daa64cdSdrh CREATE INDEX t2x5 on t2 (type); 1032daa64cdSdrh CREATE INDEX t2x6 on t2 (subtype); 1042daa64cdSdrh CREATE INDEX t2x7 on t2 (last_sample); 1052daa64cdSdrh CREATE INDEX t2x8 on t2 (param6); 1062daa64cdSdrh CREATE INDEX t2x9 on t2 (frequency); 1072daa64cdSdrh CREATE INDEX t2x10 on t2 (privilege); 1082daa64cdSdrh CREATE INDEX t2x11 on t2 (sample_time); 1092daa64cdSdrh CREATE INDEX t2x12 on t2 (notional); 1102daa64cdSdrh CREATE INDEX t2x13 on t2 (tzid); 1112daa64cdSdrh CREATE INDEX t2x14 on t2 (gr_code); 1122daa64cdSdrh CREATE INDEX t2x15 on t2 (parent_id); 1132daa64cdSdrh 1142daa64cdSdrh CREATE TABLE t3( 1152daa64cdSdrh uid int, 1162daa64cdSdrh param3 int, 1172daa64cdSdrh uuid int, 1182daa64cdSdrh acc_id int, 1192daa64cdSdrh cust_num int, 1202daa64cdSdrh numerix_id int, 1212daa64cdSdrh pfy char(29), 1222daa64cdSdrh param4 char(29), 1232daa64cdSdrh param15 int DEFAULT 0, 1242daa64cdSdrh flg7 int DEFAULT 0, 1252daa64cdSdrh param21 int DEFAULT 0, 1262daa64cdSdrh bxcdr char(2) DEFAULT 'PC', 1272daa64cdSdrh c31 int DEFAULT 0, 1282daa64cdSdrh c33 int DEFAULT 0, 1292daa64cdSdrh c35 int DEFAULT 0, 1302daa64cdSdrh c37 int, 1312daa64cdSdrh mgr_uuid int, 1322daa64cdSdrh back_up_uuid int, 1332daa64cdSdrh priv_mars int DEFAULT 0, 1342daa64cdSdrh is_qc int DEFAULT 0, 1352daa64cdSdrh c41 int DEFAULT 0, 1362daa64cdSdrh deleted int DEFAULT 0, 1372daa64cdSdrh c47 int DEFAULT 1 1382daa64cdSdrh ); 1392daa64cdSdrh CREATE INDEX t3x0 on t3 (uid); 1402daa64cdSdrh CREATE INDEX t3x1 on t3 (param3); 1412daa64cdSdrh CREATE INDEX t3x2 on t3 (uuid); 1422daa64cdSdrh CREATE INDEX t3x3 on t3 (acc_id); 1432daa64cdSdrh CREATE INDEX t3x4 on t3 (param4); 1442daa64cdSdrh CREATE INDEX t3x5 on t3 (pfy); 1452daa64cdSdrh CREATE INDEX t3x6 on t3 (is_qc); 1462daa64cdSdrh SELECT count(*) FROM sqlite_master; 1472daa64cdSdrh} {30} 1482daa64cdSdrhdo_execsql_test autoindex2-110 { 1492daa64cdSdrh ANALYZE sqlite_master; 1502daa64cdSdrh INSERT INTO sqlite_stat1 VALUES('t1','t1x3','10747267 260'); 1512daa64cdSdrh INSERT INTO sqlite_stat1 VALUES('t1','t1x2','10747267 121 113 2 2 2 1'); 1522daa64cdSdrh INSERT INTO sqlite_stat1 VALUES('t1','t1x1','10747267 50 40'); 1532daa64cdSdrh INSERT INTO sqlite_stat1 VALUES('t1','t1x0','10747267 1'); 1542daa64cdSdrh INSERT INTO sqlite_stat1 VALUES('t2','t2x15','39667 253'); 1552daa64cdSdrh INSERT INTO sqlite_stat1 VALUES('t2','t2x14','39667 19834'); 1562daa64cdSdrh INSERT INTO sqlite_stat1 VALUES('t2','t2x13','39667 13223'); 1572daa64cdSdrh INSERT INTO sqlite_stat1 VALUES('t2','t2x12','39667 7'); 1582daa64cdSdrh INSERT INTO sqlite_stat1 VALUES('t2','t2x11','39667 17'); 1592daa64cdSdrh INSERT INTO sqlite_stat1 VALUES('t2','t2x10','39667 19834'); 1602daa64cdSdrh INSERT INTO sqlite_stat1 VALUES('t2','t2x9','39667 7934'); 1612daa64cdSdrh INSERT INTO sqlite_stat1 VALUES('t2','t2x8','39667 11'); 1622daa64cdSdrh INSERT INTO sqlite_stat1 VALUES('t2','t2x7','39667 5'); 1632daa64cdSdrh INSERT INTO sqlite_stat1 VALUES('t2','t2x6','39667 242'); 1642daa64cdSdrh INSERT INTO sqlite_stat1 VALUES('t2','t2x5','39667 1984'); 1652daa64cdSdrh INSERT INTO sqlite_stat1 VALUES('t2','t2x4','39667 4408'); 1662daa64cdSdrh INSERT INTO sqlite_stat1 VALUES('t2','t2x3','39667 81'); 1672daa64cdSdrh INSERT INTO sqlite_stat1 VALUES('t2','t2x2','39667 551'); 1682daa64cdSdrh INSERT INTO sqlite_stat1 VALUES('t2','t2x1','39667 2'); 1692daa64cdSdrh INSERT INTO sqlite_stat1 VALUES('t2','t2x0','39667 1'); 1702daa64cdSdrh INSERT INTO sqlite_stat1 VALUES('t3','t3x6','569 285'); 1712daa64cdSdrh INSERT INTO sqlite_stat1 VALUES('t3','t3x5','569 2'); 1722daa64cdSdrh INSERT INTO sqlite_stat1 VALUES('t3','t3x4','569 2'); 1732daa64cdSdrh INSERT INTO sqlite_stat1 VALUES('t3','t3x3','569 5'); 1742daa64cdSdrh INSERT INTO sqlite_stat1 VALUES('t3','t3x2','569 3'); 1752daa64cdSdrh INSERT INTO sqlite_stat1 VALUES('t3','t3x1','569 6'); 1762daa64cdSdrh INSERT INTO sqlite_stat1 VALUES('t3','t3x0','569 1'); 1772daa64cdSdrh ANALYZE sqlite_master; 1782daa64cdSdrh} {} 1792daa64cdSdrhdo_execsql_test autoindex2-120 { 1802daa64cdSdrh EXPLAIN QUERY PLAN 1812daa64cdSdrh SELECT 1822daa64cdSdrh t1_id, 1832daa64cdSdrh t1.did, 1842daa64cdSdrh param2, 1852daa64cdSdrh param3, 1862daa64cdSdrh t1.ptime, 1872daa64cdSdrh t1.trange, 1882daa64cdSdrh t1.exmass, 1892daa64cdSdrh t1.mass, 1902daa64cdSdrh t1.vstatus, 1912daa64cdSdrh type, 1922daa64cdSdrh subtype, 1932daa64cdSdrh t1.deviation, 1942daa64cdSdrh t1.formula, 1952daa64cdSdrh dparam1, 1962daa64cdSdrh reserve1, 1972daa64cdSdrh reserve2, 1982daa64cdSdrh param4, 1992daa64cdSdrh t1.last_operation, 2002daa64cdSdrh t1.admin_uuid, 2012daa64cdSdrh t1.previous_value, 2022daa64cdSdrh t1.job_id, 2032daa64cdSdrh client_did, 2042daa64cdSdrh t1.last_t1, 2052daa64cdSdrh t1.data_t1, 2062daa64cdSdrh t1.previous_date, 2072daa64cdSdrh param5, 2082daa64cdSdrh param6, 2092daa64cdSdrh mgr_uuid 2102daa64cdSdrh FROM 2112daa64cdSdrh t1, 2122daa64cdSdrh t2, 2132daa64cdSdrh t3 2142daa64cdSdrh WHERE 2152daa64cdSdrh t1.ptime > 1393520400 2162daa64cdSdrh AND param3<>9001 2172daa64cdSdrh AND t3.flg7 = 1 2182daa64cdSdrh AND t1.did = t2.did 2192daa64cdSdrh AND t2.uid = t3.uid 2202daa64cdSdrh ORDER BY t1.ptime desc LIMIT 500; 221*87eb919dSdrh} {~/AUTO/} 2222daa64cdSdrh# 2232daa64cdSdrh# ^^^--- Before being fixed, the above was using an automatic covering 2242daa64cdSdrh# on t3 and reordering the tables so that t3 was in the outer loop and 2252daa64cdSdrh# implementing the ORDER BY clause using a B-Tree. 226*87eb919dSdrh# 227*87eb919dSdrh# This test is sanitized data received from a user. The original unsanitized 228*87eb919dSdrh# data and STAT4 data is found in the th3private test repository. See one of 229*87eb919dSdrh# the th3private check-ins on 2016-02-25. The test is much more accurate when 230*87eb919dSdrh# STAT4 data is used. 2312daa64cdSdrh 2322daa64cdSdrhfinish_test 233