1a9f5815bSdan# 2011 March 2 2a9f5815bSdan# 3a9f5815bSdan# The author disclaims copyright to this source code. In place of 4a9f5815bSdan# a legal notice, here is a blessing: 5a9f5815bSdan# 6a9f5815bSdan# May you do good and not evil. 7a9f5815bSdan# May you find forgiveness for yourself and forgive others. 8a9f5815bSdan# May you share freely, never taking more than you give. 9a9f5815bSdan# 10a9f5815bSdan#*********************************************************************** 11a9f5815bSdan# Make sure the rtreenode() testing function can handle entries with 12a9f5815bSdan# 64-bit rowids. 13a9f5815bSdan# 14a9f5815bSdan 15a9f5815bSdanif {![info exists testdir]} { 16a9f5815bSdan set testdir [file join [file dirname [info script]] .. .. test] 17a9f5815bSdan} 181917e92fSdansource [file join [file dirname [info script]] rtree_util.tcl] 19a9f5815bSdansource $testdir/tester.tcl 20a9f5815bSdanifcapable !rtree { finish_test ; return } 21a9f5815bSdanset testprefix rtreeC 22a9f5815bSdan 23a9f5815bSdando_execsql_test 1.0 { 24a9f5815bSdan CREATE VIRTUAL TABLE r_tree USING rtree(id, min_x, max_x, min_y, max_y); 25a9f5815bSdan CREATE TABLE t(x, y); 26a9f5815bSdan} 27a9f5815bSdan 28a9f5815bSdando_eqp_test 1.1 { 29a9f5815bSdan SELECT * FROM r_tree, t 30a9f5815bSdan WHERE t.x>=min_x AND t.x<=max_x AND t.y>=min_y AND t.x<=max_y 31a9f5815bSdan} { 32cdf88760Sdrh QUERY PLAN 338210233cSdrh |--SCAN t 348210233cSdrh `--SCAN r_tree VIRTUAL TABLE INDEX 2:D3B2D1B0 35a9f5815bSdan} 36a9f5815bSdan 37a9f5815bSdando_eqp_test 1.2 { 38a9f5815bSdan SELECT * FROM t, r_tree 39a9f5815bSdan WHERE t.x>=min_x AND t.x<=max_x AND t.y>=min_y AND t.x<=max_y 40a9f5815bSdan} { 41cdf88760Sdrh QUERY PLAN 428210233cSdrh |--SCAN t 438210233cSdrh `--SCAN r_tree VIRTUAL TABLE INDEX 2:D3B2D1B0 44a9f5815bSdan} 45a9f5815bSdan 46a9f5815bSdando_eqp_test 1.3 { 47a9f5815bSdan SELECT * FROM t, r_tree 48a9f5815bSdan WHERE t.x>=min_x AND t.x<=max_x AND t.y>=min_y AND ?<=max_y 49a9f5815bSdan} { 50cdf88760Sdrh QUERY PLAN 518210233cSdrh |--SCAN t 528210233cSdrh `--SCAN r_tree VIRTUAL TABLE INDEX 2:D3B2D1B0 53a9f5815bSdan} 54a9f5815bSdan 55a9f5815bSdando_eqp_test 1.5 { 56a9f5815bSdan SELECT * FROM t, r_tree 57a9f5815bSdan} { 58cdf88760Sdrh QUERY PLAN 598210233cSdrh |--SCAN r_tree VIRTUAL TABLE INDEX 2: 608210233cSdrh `--SCAN t 61a9f5815bSdan} 62a9f5815bSdan 63a9f5815bSdando_execsql_test 2.0 { 64a9f5815bSdan INSERT INTO t VALUES(0, 0); 65a9f5815bSdan INSERT INTO t VALUES(0, 1); 66a9f5815bSdan INSERT INTO t VALUES(0, 2); 67a9f5815bSdan INSERT INTO t VALUES(0, 3); 68a9f5815bSdan INSERT INTO t VALUES(0, 4); 69a9f5815bSdan INSERT INTO t VALUES(0, 5); 70a9f5815bSdan INSERT INTO t VALUES(0, 6); 71a9f5815bSdan INSERT INTO t VALUES(0, 7); 72a9f5815bSdan INSERT INTO t VALUES(0, 8); 73a9f5815bSdan INSERT INTO t VALUES(0, 9); 74a9f5815bSdan 75a9f5815bSdan INSERT INTO t SELECT x+1, y FROM t; 76a9f5815bSdan INSERT INTO t SELECT x+2, y FROM t; 77a9f5815bSdan INSERT INTO t SELECT x+4, y FROM t; 78a9f5815bSdan INSERT INTO r_tree SELECT NULL, x-1, x+1, y-1, y+1 FROM t; 79a9f5815bSdan ANALYZE; 80a9f5815bSdan} 81a9f5815bSdan 82a9f5815bSdandb close 83a9f5815bSdansqlite3 db test.db 84a9f5815bSdan 85a9f5815bSdando_eqp_test 2.1 { 86a9f5815bSdan SELECT * FROM r_tree, t 87a9f5815bSdan WHERE t.x>=min_x AND t.x<=max_x AND t.y>=min_y AND t.x<=max_y 88a9f5815bSdan} { 89cdf88760Sdrh QUERY PLAN 908210233cSdrh |--SCAN t 918210233cSdrh `--SCAN r_tree VIRTUAL TABLE INDEX 2:D3B2D1B0 92a9f5815bSdan} 93a9f5815bSdan 94a9f5815bSdando_eqp_test 2.2 { 95a9f5815bSdan SELECT * FROM t, r_tree 96a9f5815bSdan WHERE t.x>=min_x AND t.x<=max_x AND t.y>=min_y AND t.x<=max_y 97a9f5815bSdan} { 98cdf88760Sdrh QUERY PLAN 998210233cSdrh |--SCAN t 1008210233cSdrh `--SCAN r_tree VIRTUAL TABLE INDEX 2:D3B2D1B0 101a9f5815bSdan} 102a9f5815bSdan 103a9f5815bSdando_eqp_test 2.3 { 104a9f5815bSdan SELECT * FROM t, r_tree 105a9f5815bSdan WHERE t.x>=min_x AND t.x<=max_x AND t.y>=min_y AND ?<=max_y 106a9f5815bSdan} { 107cdf88760Sdrh QUERY PLAN 1088210233cSdrh |--SCAN t 1098210233cSdrh `--SCAN r_tree VIRTUAL TABLE INDEX 2:D3B2D1B0 110a9f5815bSdan} 111a9f5815bSdan 112a9f5815bSdando_eqp_test 2.5 { 113a9f5815bSdan SELECT * FROM t, r_tree 114a9f5815bSdan} { 115cdf88760Sdrh QUERY PLAN 1168210233cSdrh |--SCAN r_tree VIRTUAL TABLE INDEX 2: 1178210233cSdrh `--SCAN t 118a9f5815bSdan} 119a9f5815bSdan 120ff4b23baSdan#------------------------------------------------------------------------- 121ff4b23baSdan# Test that the special CROSS JOIN handling works with rtree tables. 122ff4b23baSdan# 123ff4b23baSdando_execsql_test 3.1 { 124ff4b23baSdan CREATE TABLE t1(x); 125ff4b23baSdan CREATE TABLE t2(y); 126ff4b23baSdan CREATE VIRTUAL TABLE t3 USING rtree(z, x1,x2, y1,y2); 127ff4b23baSdan} 128ff4b23baSdan 129ff4b23baSdando_eqp_test 3.2.1 { SELECT * FROM t1 CROSS JOIN t2 } { 130cdf88760Sdrh QUERY PLAN 1318210233cSdrh |--SCAN t1 1328210233cSdrh `--SCAN t2 133ff4b23baSdan} 134ff4b23baSdando_eqp_test 3.2.2 { SELECT * FROM t2 CROSS JOIN t1 } { 135cdf88760Sdrh QUERY PLAN 1368210233cSdrh |--SCAN t2 1378210233cSdrh `--SCAN t1 138ff4b23baSdan} 139ff4b23baSdan 140ff4b23baSdando_eqp_test 3.3.1 { SELECT * FROM t1 CROSS JOIN t3 } { 141cdf88760Sdrh QUERY PLAN 1428210233cSdrh |--SCAN t1 1438210233cSdrh `--SCAN t3 VIRTUAL TABLE INDEX 2: 144ff4b23baSdan} 145ff4b23baSdando_eqp_test 3.3.2 { SELECT * FROM t3 CROSS JOIN t1 } { 146cdf88760Sdrh QUERY PLAN 1478210233cSdrh |--SCAN t3 VIRTUAL TABLE INDEX 2: 1488210233cSdrh `--SCAN t1 149ff4b23baSdan} 150ff4b23baSdan 151ff4b23baSdan#-------------------------------------------------------------------- 152ff4b23baSdan# Test that LEFT JOINs are not reordered if the right-hand-side is 153ff4b23baSdan# a virtual table. 154ff4b23baSdan# 155ff4b23baSdanreset_db 156ff4b23baSdando_execsql_test 4.1 { 157ff4b23baSdan CREATE TABLE t1(a); 158ff4b23baSdan CREATE VIRTUAL TABLE t2 USING rtree(b, x1,x2); 159ff4b23baSdan 160ff4b23baSdan INSERT INTO t1 VALUES(1); 161ff4b23baSdan INSERT INTO t1 VALUES(2); 162ff4b23baSdan 163ff4b23baSdan INSERT INTO t2 VALUES(1, 0.0, 0.1); 164ff4b23baSdan INSERT INTO t2 VALUES(3, 0.0, 0.1); 165ff4b23baSdan} 166ff4b23baSdan 167ff4b23baSdando_execsql_test 4.2 { 168ff4b23baSdan SELECT a, b FROM t1 LEFT JOIN t2 ON (+a = +b); 169ff4b23baSdan} {1 1 2 {}} 170ff4b23baSdan 171ff4b23baSdando_execsql_test 4.3 { 172ff4b23baSdan SELECT b, a FROM t2 LEFT JOIN t1 ON (+a = +b); 173ff4b23baSdan} {1 1 3 {}} 174ff4b23baSdan 17587af14a6Sdan#-------------------------------------------------------------------- 17687af14a6Sdan# Test that the sqlite_stat1 data is used correctly. 17787af14a6Sdan# 17887af14a6Sdanreset_db 17987af14a6Sdando_execsql_test 5.1 { 180cb224ab1Sdrh CREATE TABLE t1(x INT PRIMARY KEY, y); 1817578456cSdrh CREATE VIRTUAL TABLE rt USING rtree(id, x1, x2, +d1); 18287af14a6Sdan 18387af14a6Sdan INSERT INTO t1(x) VALUES(1); 18487af14a6Sdan INSERT INTO t1(x) SELECT x+1 FROM t1; -- 2 18587af14a6Sdan INSERT INTO t1(x) SELECT x+2 FROM t1; -- 4 18687af14a6Sdan INSERT INTO t1(x) SELECT x+4 FROM t1; -- 8 18787af14a6Sdan INSERT INTO t1(x) SELECT x+8 FROM t1; -- 16 18887af14a6Sdan INSERT INTO t1(x) SELECT x+16 FROM t1; -- 32 18987af14a6Sdan INSERT INTO t1(x) SELECT x+32 FROM t1; -- 64 19087af14a6Sdan INSERT INTO t1(x) SELECT x+64 FROM t1; -- 128 19187af14a6Sdan INSERT INTO t1(x) SELECT x+128 FROM t1; -- 256 19287af14a6Sdan INSERT INTO t1(x) SELECT x+256 FROM t1; -- 512 19387af14a6Sdan INSERT INTO t1(x) SELECT x+512 FROM t1; --1024 19487af14a6Sdan 1957578456cSdrh INSERT INTO rt SELECT x, x, x+1, printf('x%04xy',x) FROM t1 WHERE x<=5; 19687af14a6Sdan} 1971917e92fSdando_rtree_integrity_test 5.1.1 rt 19887af14a6Sdan 19987af14a6Sdan# First test a query with no ANALYZE data at all. The outer loop is 20087af14a6Sdan# real table "t1". 20187af14a6Sdan# 20287af14a6Sdando_eqp_test 5.2 { 20387af14a6Sdan SELECT * FROM t1, rt WHERE x==id; 20487af14a6Sdan} { 205cdf88760Sdrh QUERY PLAN 2068210233cSdrh |--SCAN t1 2078210233cSdrh `--SCAN rt VIRTUAL TABLE INDEX 1: 20887af14a6Sdan} 20987af14a6Sdan 21087af14a6Sdan# Now create enough ANALYZE data to tell SQLite that virtual table "rt" 21187af14a6Sdan# contains very few rows. This causes it to move "rt" to the outer loop. 21287af14a6Sdan# 21387af14a6Sdando_execsql_test 5.3 { 21487af14a6Sdan ANALYZE; 21587af14a6Sdan DELETE FROM sqlite_stat1 WHERE tbl='t1'; 21687af14a6Sdan} 21787af14a6Sdandb close 21887af14a6Sdansqlite3 db test.db 21987af14a6Sdando_eqp_test 5.4 { 22087af14a6Sdan SELECT * FROM t1, rt WHERE x==id; 22187af14a6Sdan} { 222cdf88760Sdrh QUERY PLAN 2238210233cSdrh |--SCAN rt VIRTUAL TABLE INDEX 2: 2248210233cSdrh `--SEARCH t1 USING INDEX sqlite_autoindex_t1_1 (x=?) 22587af14a6Sdan} 22687af14a6Sdan 22787af14a6Sdan# Delete the ANALYZE data. "t1" should be the outer loop again. 22887af14a6Sdan# 22987af14a6Sdando_execsql_test 5.5 { DROP TABLE sqlite_stat1; } 23087af14a6Sdandb close 23187af14a6Sdansqlite3 db test.db 23287af14a6Sdando_eqp_test 5.6 { 23387af14a6Sdan SELECT * FROM t1, rt WHERE x==id; 23487af14a6Sdan} { 235cdf88760Sdrh QUERY PLAN 2368210233cSdrh |--SCAN t1 2378210233cSdrh `--SCAN rt VIRTUAL TABLE INDEX 1: 23887af14a6Sdan} 23987af14a6Sdan 24087af14a6Sdan# This time create and attach a database that contains ANALYZE data for 24187af14a6Sdan# tables of the same names as those used internally by virtual table 24287af14a6Sdan# "rt". Check that the rtree module is not fooled into using this data. 24387af14a6Sdan# Table "t1" should remain the outer loop. 24487af14a6Sdan# 24587af14a6Sdando_test 5.7 { 24687af14a6Sdan db backup test.db2 24787af14a6Sdan sqlite3 db2 test.db2 24887af14a6Sdan db2 eval { 24987af14a6Sdan ANALYZE; 25087af14a6Sdan DELETE FROM sqlite_stat1 WHERE tbl='t1'; 25187af14a6Sdan } 25287af14a6Sdan db2 close 25387af14a6Sdan db close 25487af14a6Sdan sqlite3 db test.db 25587af14a6Sdan execsql { ATTACH 'test.db2' AS aux; } 25687af14a6Sdan} {} 25787af14a6Sdando_eqp_test 5.8 { 25887af14a6Sdan SELECT * FROM t1, rt WHERE x==id; 25987af14a6Sdan} { 260cdf88760Sdrh QUERY PLAN 2618210233cSdrh |--SCAN t1 2628210233cSdrh `--SCAN rt VIRTUAL TABLE INDEX 1: 26387af14a6Sdan} 26487af14a6Sdan 265d88e521fSdan#-------------------------------------------------------------------- 266d88e521fSdan# Test that having a second connection drop the sqlite_stat1 table 267d88e521fSdan# before it is required by rtreeConnect() does not cause problems. 268d88e521fSdan# 269d88e521fSdanifcapable rtree { 270d88e521fSdan reset_db 271d88e521fSdan do_execsql_test 6.1 { 272d88e521fSdan CREATE TABLE t1(x); 273d88e521fSdan CREATE VIRTUAL TABLE rt USING rtree(id, x1, x2); 274d88e521fSdan INSERT INTO t1 VALUES(1); 275d88e521fSdan INSERT INTO rt VALUES(1,2,3); 276d88e521fSdan ANALYZE; 277d88e521fSdan } 278d88e521fSdan db close 279d88e521fSdan sqlite3 db test.db 280d88e521fSdan do_execsql_test 6.2 { SELECT * FROM t1 } {1} 281d88e521fSdan 282d88e521fSdan do_test 6.3 { 283d88e521fSdan sqlite3 db2 test.db 284d88e521fSdan db2 eval { DROP TABLE sqlite_stat1 } 285d88e521fSdan db2 close 286d88e521fSdan execsql { SELECT * FROM rt } 287d88e521fSdan } {1 2.0 3.0} 288d88e521fSdan db close 289d88e521fSdan} 290d88e521fSdan 2914f20cd40Sdan#-------------------------------------------------------------------- 2924f20cd40Sdan# Test that queries featuring LEFT or CROSS JOINS are handled correctly. 2934f20cd40Sdan# Handled correctly in this case means: 2944f20cd40Sdan# 2954f20cd40Sdan# * Terms with prereqs that appear to the left of a LEFT JOIN against 2964f20cd40Sdan# the virtual table are always available to xBestIndex. 2974f20cd40Sdan# 2984f20cd40Sdan# * Terms with prereqs that appear to the right of a LEFT JOIN against 2994f20cd40Sdan# the virtual table are never available to xBestIndex. 3004f20cd40Sdan# 3014f20cd40Sdan# And the same behaviour for CROSS joins. 3024f20cd40Sdan# 3034f20cd40Sdanreset_db 3044f20cd40Sdando_execsql_test 7.0 { 3054f20cd40Sdan CREATE TABLE xdir(x1); 3064f20cd40Sdan CREATE TABLE ydir(y1); 3074f20cd40Sdan CREATE VIRTUAL TABLE rt USING rtree_i32(id, xmin, xmax, ymin, ymax); 3084f20cd40Sdan 3094f20cd40Sdan INSERT INTO xdir VALUES(5); 3104f20cd40Sdan INSERT INTO ydir VALUES(10); 3114f20cd40Sdan 3124f20cd40Sdan INSERT INTO rt VALUES(1, 2, 7, 12, 14); -- Not a hit 3134f20cd40Sdan INSERT INTO rt VALUES(2, 2, 7, 8, 12); -- A hit! 3144f20cd40Sdan INSERT INTO rt VALUES(3, 7, 11, 8, 12); -- Not a hit! 3154f20cd40Sdan INSERT INTO rt VALUES(4, 5, 5, 10, 10); -- A hit! 3164f20cd40Sdan 3174f20cd40Sdan} 3184f20cd40Sdan 319cdf88760Sdrhproc do_eqp_execsql_test {tn sql res1 res2} { 320cdf88760Sdrh do_eqp_test $tn.1 $sql $res1 321cdf88760Sdrh do_execsql_test $tn.2 $sql $res2 3224f20cd40Sdan} 3234f20cd40Sdan 3244f20cd40Sdando_eqp_execsql_test 7.1 { 3254f20cd40Sdan SELECT id FROM xdir, rt, ydir 3264f20cd40Sdan ON (y1 BETWEEN ymin AND ymax) 3274f20cd40Sdan WHERE (x1 BETWEEN xmin AND xmax); 3284f20cd40Sdan} { 329cdf88760Sdrh QUERY PLAN 3308210233cSdrh |--SCAN xdir 3318210233cSdrh |--SCAN ydir 3328210233cSdrh `--SCAN rt VIRTUAL TABLE INDEX 2:B2D3B0D1 333cdf88760Sdrh} { 3344f20cd40Sdan 2 4 3354f20cd40Sdan} 3364f20cd40Sdan 3374f20cd40Sdando_eqp_execsql_test 7.2 { 3384f20cd40Sdan SELECT * FROM xdir, rt LEFT JOIN ydir 3394f20cd40Sdan ON (y1 BETWEEN ymin AND ymax) 3404f20cd40Sdan WHERE (x1 BETWEEN xmin AND xmax); 3414f20cd40Sdan} { 342cdf88760Sdrh QUERY PLAN 3438210233cSdrh |--SCAN xdir 3448210233cSdrh |--SCAN rt VIRTUAL TABLE INDEX 2:B0D1 345*c583719bSdrh `--SCAN ydir LEFT-JOIN 346cdf88760Sdrh} { 3474f20cd40Sdan 5 1 2 7 12 14 {} 3484f20cd40Sdan 5 2 2 7 8 12 10 3494f20cd40Sdan 5 4 5 5 10 10 10 3504f20cd40Sdan} 3514f20cd40Sdan 3524f20cd40Sdando_eqp_execsql_test 7.3 { 3534f20cd40Sdan SELECT id FROM xdir, rt CROSS JOIN ydir 3544f20cd40Sdan ON (y1 BETWEEN ymin AND ymax) 3554f20cd40Sdan WHERE (x1 BETWEEN xmin AND xmax); 3564f20cd40Sdan} { 357cdf88760Sdrh QUERY PLAN 3588210233cSdrh |--SCAN xdir 3598210233cSdrh |--SCAN rt VIRTUAL TABLE INDEX 2:B0D1 3608210233cSdrh `--SCAN ydir 361cdf88760Sdrh} { 3624f20cd40Sdan 2 4 3634f20cd40Sdan} 3644f20cd40Sdan 3654f20cd40Sdando_eqp_execsql_test 7.4 { 3664f20cd40Sdan SELECT id FROM rt, xdir CROSS JOIN ydir 3674f20cd40Sdan ON (y1 BETWEEN ymin AND ymax) 3684f20cd40Sdan WHERE (x1 BETWEEN xmin AND xmax); 3694f20cd40Sdan} { 370cdf88760Sdrh QUERY PLAN 3718210233cSdrh |--SCAN xdir 3728210233cSdrh |--SCAN rt VIRTUAL TABLE INDEX 2:B0D1 3738210233cSdrh `--SCAN ydir 374cdf88760Sdrh} { 3754f20cd40Sdan 2 4 3764f20cd40Sdan} 3774f20cd40Sdan 3784f20cd40Sdanfinish_test 379