18416fc7fSdrh# 2013-04-25 28416fc7fSdrh# 38416fc7fSdrh# The author disclaims copyright to this source code. In place of 48416fc7fSdrh# a legal notice, here is a blessing: 58416fc7fSdrh# 68416fc7fSdrh# May you do good and not evil. 78416fc7fSdrh# May you find forgiveness for yourself and forgive others. 88416fc7fSdrh# May you share freely, never taking more than you give. 98416fc7fSdrh# 108416fc7fSdrh#*********************************************************************** 118416fc7fSdrh# 128416fc7fSdrh# Test cases for transitive_closure virtual table. 138416fc7fSdrh 148416fc7fSdrhset testdir [file dirname $argv0] 158416fc7fSdrhsource $testdir/tester.tcl 168416fc7fSdrhset testprefix closure01 178416fc7fSdrh 183c2aeae1Sdrhifcapable !vtab||!cte { finish_test ; return } 1911f71d6aSdan 208416fc7fSdrhload_static_extension db closure 218416fc7fSdrh 228416fc7fSdrhdo_execsql_test 1.0 { 238416fc7fSdrh BEGIN; 248416fc7fSdrh CREATE TABLE t1(x INTEGER PRIMARY KEY, y INTEGER); 253c2aeae1Sdrh WITH RECURSIVE 263c2aeae1Sdrh cnt(i) AS (VALUES(1) UNION ALL SELECT i+1 FROM cnt LIMIT 131072) 273c2aeae1Sdrh INSERT INTO t1(x, y) SELECT i, nullif(i,1)/2 FROM cnt; 288416fc7fSdrh CREATE INDEX t1y ON t1(y); 298416fc7fSdrh COMMIT; 308416fc7fSdrh CREATE VIRTUAL TABLE cx 318416fc7fSdrh USING transitive_closure(tablename=t1, idcolumn=x, parentcolumn=y); 328416fc7fSdrh} {} 338416fc7fSdrh 348416fc7fSdrh# The entire table 353c2aeae1Sdrhdo_timed_execsql_test 1.1 { 368416fc7fSdrh SELECT count(*), depth FROM cx WHERE root=1 GROUP BY depth ORDER BY 1; 378416fc7fSdrh} {/1 0 1 17 2 1 4 2 8 3 16 4 .* 65536 16/} 383c2aeae1Sdrhdo_timed_execsql_test 1.1-cte { 393c2aeae1Sdrh WITH RECURSIVE 403c2aeae1Sdrh below(id,depth) AS ( 413c2aeae1Sdrh VALUES(1,0) 423c2aeae1Sdrh UNION ALL 433c2aeae1Sdrh SELECT t1.x, below.depth+1 443c2aeae1Sdrh FROM t1 JOIN below on t1.y=below.id 453c2aeae1Sdrh ) 463c2aeae1Sdrh SELECT count(*), depth FROM below GROUP BY depth ORDER BY 1; 473c2aeae1Sdrh} {/1 0 1 17 2 1 4 2 8 3 16 4 .* 65536 16/} 488416fc7fSdrh 498416fc7fSdrh# descendents of 32768 509e2c7ae1Sdrhdo_timed_execsql_test 1.2 { 518416fc7fSdrh SELECT * FROM cx WHERE root=32768 ORDER BY id; 528416fc7fSdrh} {32768 0 65536 1 65537 1 131072 2} 539e2c7ae1Sdrhdo_timed_execsql_test 1.2-cte { 549e2c7ae1Sdrh WITH RECURSIVE 559e2c7ae1Sdrh below(id,depth) AS ( 569e2c7ae1Sdrh VALUES(32768,0) 579e2c7ae1Sdrh UNION ALL 589e2c7ae1Sdrh SELECT t1.x, below.depth+1 599e2c7ae1Sdrh FROM t1 JOIN below on t1.y=below.id 609e2c7ae1Sdrh WHERE below.depth<2 619e2c7ae1Sdrh ) 629e2c7ae1Sdrh SELECT id, depth FROM below ORDER BY id; 639e2c7ae1Sdrh} {32768 0 65536 1 65537 1 131072 2} 648416fc7fSdrh 658416fc7fSdrh# descendents of 16384 663c2aeae1Sdrhdo_timed_execsql_test 1.3 { 678416fc7fSdrh SELECT * FROM cx WHERE root=16384 AND depth<=2 ORDER BY id; 688416fc7fSdrh} {16384 0 32768 1 32769 1 65536 2 65537 2 65538 2 65539 2} 693c2aeae1Sdrhdo_timed_execsql_test 1.3-cte { 703c2aeae1Sdrh WITH RECURSIVE 713c2aeae1Sdrh below(id,depth) AS ( 723c2aeae1Sdrh VALUES(16384,0) 733c2aeae1Sdrh UNION ALL 743c2aeae1Sdrh SELECT t1.x, below.depth+1 753c2aeae1Sdrh FROM t1 JOIN below on t1.y=below.id 763c2aeae1Sdrh WHERE below.depth<2 773c2aeae1Sdrh ) 783c2aeae1Sdrh SELECT id, depth FROM below ORDER BY id; 793c2aeae1Sdrh} {16384 0 32768 1 32769 1 65536 2 65537 2 65538 2 65539 2} 808416fc7fSdrh 818416fc7fSdrh# children of 16384 828416fc7fSdrhdo_execsql_test 1.4 { 838416fc7fSdrh SELECT id, depth, root, tablename, idcolumn, parentcolumn FROM cx 848416fc7fSdrh WHERE root=16384 858416fc7fSdrh AND depth=1 868416fc7fSdrh ORDER BY id; 878416fc7fSdrh} {32768 1 {} t1 x y 32769 1 {} t1 x y} 888416fc7fSdrh 898416fc7fSdrh# great-grandparent of 16384 909e2c7ae1Sdrhdo_timed_execsql_test 1.5 { 918416fc7fSdrh SELECT id, depth, root, tablename, idcolumn, parentcolumn FROM cx 928416fc7fSdrh WHERE root=16384 938416fc7fSdrh AND depth=3 948416fc7fSdrh AND idcolumn='Y' 958416fc7fSdrh AND parentcolumn='X'; 968416fc7fSdrh} {2048 3 {} t1 Y X} 979e2c7ae1Sdrhdo_timed_execsql_test 1.5-cte { 989e2c7ae1Sdrh WITH RECURSIVE 999e2c7ae1Sdrh above(id,depth) AS ( 1009e2c7ae1Sdrh VALUES(16384,0) 1019e2c7ae1Sdrh UNION ALL 1029e2c7ae1Sdrh SELECT t1.y, above.depth+1 1039e2c7ae1Sdrh FROM t1 JOIN above ON t1.x=above.id 1049e2c7ae1Sdrh WHERE above.depth<3 1059e2c7ae1Sdrh ) 1069e2c7ae1Sdrh SELECT id FROM above WHERE depth=3; 1079e2c7ae1Sdrh} {2048} 1088416fc7fSdrh 1098416fc7fSdrh# depth<5 1109e2c7ae1Sdrhdo_timed_execsql_test 1.6 { 1118416fc7fSdrh SELECT count(*), depth FROM cx WHERE root=1 AND depth<5 1128416fc7fSdrh GROUP BY depth ORDER BY 1; 1138416fc7fSdrh} {1 0 2 1 4 2 8 3 16 4} 1149e2c7ae1Sdrhdo_timed_execsql_test 1.6-cte { 1159e2c7ae1Sdrh WITH RECURSIVE 1169e2c7ae1Sdrh below(id,depth) AS ( 1179e2c7ae1Sdrh VALUES(1,0) 1189e2c7ae1Sdrh UNION ALL 1199e2c7ae1Sdrh SELECT t1.x, below.depth+1 1209e2c7ae1Sdrh FROM t1 JOIN below ON t1.y=below.id 1219e2c7ae1Sdrh WHERE below.depth<4 1229e2c7ae1Sdrh ) 1239e2c7ae1Sdrh SELECT count(*), depth FROM below GROUP BY depth ORDER BY 1; 1249e2c7ae1Sdrh} {1 0 2 1 4 2 8 3 16 4} 1258416fc7fSdrh 1268416fc7fSdrh# depth<=5 1278416fc7fSdrhdo_execsql_test 1.7 { 1288416fc7fSdrh SELECT count(*), depth FROM cx WHERE root=1 AND depth<=5 1298416fc7fSdrh GROUP BY depth ORDER BY 1; 1308416fc7fSdrh} {1 0 2 1 4 2 8 3 16 4 32 5} 1318416fc7fSdrh 1328416fc7fSdrh# depth==5 1338416fc7fSdrhdo_execsql_test 1.8 { 1348416fc7fSdrh SELECT count(*), depth FROM cx WHERE root=1 AND depth=5 1358416fc7fSdrh GROUP BY depth ORDER BY 1; 1368416fc7fSdrh} {32 5} 1378416fc7fSdrh 1388416fc7fSdrh# depth BETWEEN 3 AND 5 1398416fc7fSdrhdo_execsql_test 1.9 { 1408416fc7fSdrh SELECT count(*), depth FROM cx WHERE root=1 AND depth BETWEEN 3 AND 5 1418416fc7fSdrh GROUP BY depth ORDER BY 1; 1428416fc7fSdrh} {8 3 16 4 32 5} 1438416fc7fSdrh 1448416fc7fSdrh# depth==5 with min() and max() 1459e2c7ae1Sdrhdo_timed_execsql_test 1.10 { 1468416fc7fSdrh SELECT count(*), min(id), max(id) FROM cx WHERE root=1 AND depth=5; 1478416fc7fSdrh} {32 32 63} 1489e2c7ae1Sdrhdo_timed_execsql_test 1.10-cte { 1499e2c7ae1Sdrh WITH RECURSIVE 1509e2c7ae1Sdrh below(id,depth) AS ( 1519e2c7ae1Sdrh VALUES(1,0) 1529e2c7ae1Sdrh UNION ALL 1539e2c7ae1Sdrh SELECT t1.x, below.depth+1 1549e2c7ae1Sdrh FROM t1 JOIN below ON t1.y=below.id 1559e2c7ae1Sdrh WHERE below.depth<5 1569e2c7ae1Sdrh ) 1579e2c7ae1Sdrh SELECT count(*), min(id), max(id) FROM below WHERE depth=5; 1589e2c7ae1Sdrh} {32 32 63} 1598416fc7fSdrh 1608416fc7fSdrh# Create a much smaller table t2 with only 32 elements 1618416fc7fSdrhdb eval { 1628416fc7fSdrh CREATE TABLE t2(x INTEGER PRIMARY KEY, y INTEGER); 1638416fc7fSdrh INSERT INTO t2 SELECT x, y FROM t1 WHERE x<32; 1648416fc7fSdrh CREATE INDEX t2y ON t2(y); 1658416fc7fSdrh CREATE VIRTUAL TABLE c2 1668416fc7fSdrh USING transitive_closure(tablename=t2, idcolumn=x, parentcolumn=y); 1678416fc7fSdrh} 1688416fc7fSdrh 1698416fc7fSdrh# t2 full-table 1708416fc7fSdrhdo_execsql_test 2.1 { 1718416fc7fSdrh SELECT count(*), min(id), max(id) FROM c2 WHERE root=1; 1728416fc7fSdrh} {31 1 31} 1738416fc7fSdrh# t2 root=10 1748416fc7fSdrhdo_execsql_test 2.2 { 1758416fc7fSdrh SELECT id FROM c2 WHERE root=10; 1768416fc7fSdrh} {10 20 21} 1778416fc7fSdrh# t2 root=11 1788416fc7fSdrhdo_execsql_test 2.3 { 1798416fc7fSdrh SELECT id FROM c2 WHERE root=12; 1808416fc7fSdrh} {12 24 25} 1818416fc7fSdrh# t2 root IN [10,12] 1828416fc7fSdrhdo_execsql_test 2.4 { 1838416fc7fSdrh SELECT id FROM c2 WHERE root IN (10,12) ORDER BY id; 1848416fc7fSdrh} {10 12 20 21 24 25} 1858416fc7fSdrh# t2 root IN [10,12] (sorted) 1868416fc7fSdrhdo_execsql_test 2.5 { 1878416fc7fSdrh SELECT id FROM c2 WHERE root IN (10,12) ORDER BY +id; 1888416fc7fSdrh} {10 12 20 21 24 25} 1898416fc7fSdrh 1908416fc7fSdrh# t2 c2up from 20 1918416fc7fSdrhdo_execsql_test 3.0 { 1928416fc7fSdrh CREATE VIRTUAL TABLE c2up USING transitive_closure( 1938416fc7fSdrh tablename = t2, 1948416fc7fSdrh idcolumn = y, 1958416fc7fSdrh parentcolumn = x 1968416fc7fSdrh ); 1978416fc7fSdrh SELECT id FROM c2up WHERE root=20; 1988416fc7fSdrh} {1 2 5 10 20} 1998416fc7fSdrh 2008416fc7fSdrh# cx as c2up 2018416fc7fSdrhdo_execsql_test 3.1 { 2028416fc7fSdrh SELECT id FROM cx 2038416fc7fSdrh WHERE root=20 2048416fc7fSdrh AND tablename='t2' 2058416fc7fSdrh AND idcolumn='y' 2068416fc7fSdrh AND parentcolumn='x'; 2078416fc7fSdrh} {1 2 5 10 20} 2088416fc7fSdrh 2098416fc7fSdrh# t2 first cousins of 20 2108416fc7fSdrhdo_execsql_test 3.2 { 2118416fc7fSdrh SELECT DISTINCT id FROM c2 2128416fc7fSdrh WHERE root IN (SELECT id FROM c2up 2138416fc7fSdrh WHERE root=20 AND depth<=2) 2148416fc7fSdrh ORDER BY id; 2158416fc7fSdrh} {5 10 11 20 21 22 23} 2168416fc7fSdrh 2178416fc7fSdrh# t2 first cousins of 20 2188416fc7fSdrhdo_execsql_test 3.3 { 2198416fc7fSdrh SELECT id FROM c2 2208416fc7fSdrh WHERE root=(SELECT id FROM c2up 2218416fc7fSdrh WHERE root=20 AND depth=2) 2228416fc7fSdrh AND depth=2 2238416fc7fSdrh EXCEPT 2248416fc7fSdrh SELECT id FROM c2 2258416fc7fSdrh WHERE root=(SELECT id FROM c2up 2268416fc7fSdrh WHERE root=20 AND depth=1) 2278416fc7fSdrh AND depth<=1 2288416fc7fSdrh ORDER BY id; 2298416fc7fSdrh} {22 23} 2308416fc7fSdrh 2318416fc7fSdrh# missing tablename. 2328416fc7fSdrhdo_test 4.1 { 2338416fc7fSdrh catchsql { 2348416fc7fSdrh SELECT id FROM cx 2358416fc7fSdrh WHERE root=20 2368416fc7fSdrh AND tablename='t3' 2378416fc7fSdrh AND idcolumn='y' 2388416fc7fSdrh AND parentcolumn='x'; 2398416fc7fSdrh } 2408416fc7fSdrh} {1 {no such table: t3}} 2418416fc7fSdrh 2428416fc7fSdrh# missing idcolumn 2438416fc7fSdrhdo_test 4.2 { 2448416fc7fSdrh catchsql { 2458416fc7fSdrh SELECT id FROM cx 2468416fc7fSdrh WHERE root=20 2478416fc7fSdrh AND tablename='t2' 2488416fc7fSdrh AND idcolumn='xyz' 2498416fc7fSdrh AND parentcolumn='x'; 2508416fc7fSdrh } 2518416fc7fSdrh} {1 {no such column: t2.xyz}} 2528416fc7fSdrh 2538416fc7fSdrh# missing parentcolumn 2548416fc7fSdrhdo_test 4.3 { 2558416fc7fSdrh catchsql { 2568416fc7fSdrh SELECT id FROM cx 2578416fc7fSdrh WHERE root=20 2588416fc7fSdrh AND tablename='t2' 2598416fc7fSdrh AND idcolumn='x' 2608416fc7fSdrh AND parentcolumn='pqr'; 2618416fc7fSdrh } 2628416fc7fSdrh} {1 {no such column: t2.pqr}} 2638416fc7fSdrh 2648416fc7fSdrh# generic closure 2658416fc7fSdrhdo_execsql_test 5.1 { 2668416fc7fSdrh CREATE VIRTUAL TABLE temp.closure USING transitive_closure; 2678416fc7fSdrh SELECT id FROM closure 2688416fc7fSdrh WHERE root=1 2698416fc7fSdrh AND depth=3 2708416fc7fSdrh AND tablename='t1' 2718416fc7fSdrh AND idcolumn='x' 2728416fc7fSdrh AND parentcolumn='y' 2738416fc7fSdrh ORDER BY id; 2748416fc7fSdrh} {8 9 10 11 12 13 14 15} 2758416fc7fSdrh 276*fa5c69f5Sdan#------------------------------------------------------------------------- 277*fa5c69f5Sdan# At one point the following join query was causing a malfunction in 278*fa5c69f5Sdan# xBestIndex. 279*fa5c69f5Sdan# 280*fa5c69f5Sdando_execsql_test 6.0 { 281*fa5c69f5Sdan CREATE TABLE t4 ( 282*fa5c69f5Sdan id INTEGER PRIMARY KEY, 283*fa5c69f5Sdan name TEXT NOT NULL, 284*fa5c69f5Sdan parent_id INTEGER 285*fa5c69f5Sdan ); 286*fa5c69f5Sdan CREATE VIRTUAL TABLE vt4 USING transitive_closure ( 287*fa5c69f5Sdan idcolumn=id, parentcolumn=parent_id, tablename=t4 288*fa5c69f5Sdan ); 289*fa5c69f5Sdan} 290*fa5c69f5Sdan 291*fa5c69f5Sdando_execsql_test 6.1 { 292*fa5c69f5Sdan SELECT * FROM t4, vt4 WHERE t4.id = vt4.root AND vt4.id=4 AND vt4.depth=2; 293*fa5c69f5Sdan} 294*fa5c69f5Sdan 2958416fc7fSdrhfinish_test 296