16e11892dSdan# 2019 August 10 26e11892dSdan# 36e11892dSdan# The author disclaims copyright to this source code. In place of 46e11892dSdan# a legal notice, here is a blessing: 56e11892dSdan# 66e11892dSdan# May you do good and not evil. 76e11892dSdan# May you find forgiveness for yourself and forgive others. 86e11892dSdan# May you share freely, never taking more than you give. 96e11892dSdan# 106e11892dSdan#*********************************************************************** 116e11892dSdan# This file implements regression tests for SQLite library. 126e11892dSdan# 136e11892dSdan 146e11892dSdanset testdir [file dirname $argv0] 156e11892dSdansource $testdir/tester.tcl 166e11892dSdanset testprefix nulls1 176e11892dSdan 186e11892dSdando_execsql_test 1.0 { 196e11892dSdan DROP TABLE IF EXISTS t3; 206e11892dSdan CREATE TABLE t3(a INTEGER); 216e11892dSdan INSERT INTO t3 VALUES(NULL), (10), (30), (20), (NULL); 226e11892dSdan} {} 236e11892dSdan 2415750a26Sdanfor {set a 0} {$a < 3} {incr a} { 256e11892dSdan foreach {tn limit} { 266e11892dSdan 1 "" 276e11892dSdan 2 "LIMIT 10" 286e11892dSdan } { 296e11892dSdan do_execsql_test 1.$a.$tn.1 " 306e11892dSdan SELECT a FROM t3 ORDER BY a nULLS FIRST $limit 316e11892dSdan " {{} {} 10 20 30} 326e11892dSdan 336e11892dSdan do_execsql_test 1.$a.$tn.2 " 346e11892dSdan SELECT a FROM t3 ORDER BY a nULLS LAST $limit 356e11892dSdan " {10 20 30 {} {}} 366e11892dSdan 376e11892dSdan do_execsql_test 1.$a.$tn.3 " 386e11892dSdan SELECT a FROM t3 ORDER BY a DESC nULLS FIRST $limit 396e11892dSdan " {{} {} 30 20 10} 406e11892dSdan 416e11892dSdan do_execsql_test 1.$a.$tn.4 " 426e11892dSdan SELECT a FROM t3 ORDER BY a DESC nULLS LAST $limit 436e11892dSdan " {30 20 10 {} {}} 446e11892dSdan } 456e11892dSdan 4615750a26Sdan switch $a { 4715750a26Sdan 0 { 4815750a26Sdan execsql { CREATE INDEX i1 ON t3(a) } 496e11892dSdan } 5015750a26Sdan 1 { 5115750a26Sdan execsql { DROP INDEX i1 ; CREATE INDEX i1 ON t3(a DESC) } 5215750a26Sdan } 5315750a26Sdan } 5415750a26Sdan} 5515750a26Sdan 5615750a26Sdan#------------------------------------------------------------------------- 5715750a26Sdanreset_db 5815750a26Sdando_execsql_test 2.0 { 5915750a26Sdan CREATE TABLE t2(a, b, c); 6015750a26Sdan CREATE INDEX i2 ON t2(a, b); 6115750a26Sdan INSERT INTO t2 VALUES(1, 1, 1); 6215750a26Sdan INSERT INTO t2 VALUES(1, NULL, 2); 6315750a26Sdan INSERT INTO t2 VALUES(1, NULL, 3); 6415750a26Sdan INSERT INTO t2 VALUES(1, 4, 4); 6515750a26Sdan} 6615750a26Sdan 6715750a26Sdando_execsql_test 2.1 { 6815750a26Sdan SELECT * FROM t2 WHERE a=1 ORDER BY b NULLS LAST 6915750a26Sdan} { 7015750a26Sdan 1 1 1 1 4 4 1 {} 2 1 {} 3 7115750a26Sdan} 7215750a26Sdan 7315750a26Sdando_execsql_test 2.2 { 7415750a26Sdan SELECT * FROM t2 WHERE a=1 ORDER BY b DESC NULLS FIRST 7515750a26Sdan} { 7615750a26Sdan 1 {} 3 7715750a26Sdan 1 {} 2 7815750a26Sdan 1 4 4 7915750a26Sdan 1 1 1 8015750a26Sdan} 8115750a26Sdan 829105fd51Sdan#------------------------------------------------------------------------- 83ae8e45cbSdan# 849105fd51Sdanreset_db 859105fd51Sdando_execsql_test 3.0 { 869105fd51Sdan CREATE TABLE t1(a, b, c, d, UNIQUE (b)); 879105fd51Sdan} 889105fd51Sdanforeach {tn sql err} { 899105fd51Sdan 1 { CREATE INDEX i1 ON t1(a ASC NULLS LAST) } LAST 909105fd51Sdan 2 { CREATE INDEX i1 ON t1(a ASC NULLS FIRST) } FIRST 919105fd51Sdan 3 { CREATE INDEX i1 ON t1(a, b ASC NULLS LAST) } LAST 929105fd51Sdan 4 { CREATE INDEX i1 ON t1(a, b ASC NULLS FIRST) } FIRST 939105fd51Sdan 5 { CREATE INDEX i1 ON t1(a DESC NULLS LAST) } LAST 949105fd51Sdan 6 { CREATE INDEX i1 ON t1(a DESC NULLS FIRST) } FIRST 959105fd51Sdan 7 { CREATE INDEX i1 ON t1(a, b DESC NULLS LAST) } LAST 969105fd51Sdan 8 { CREATE INDEX i1 ON t1(a, b DESC NULLS FIRST) } FIRST 979105fd51Sdan 9 { CREATE TABLE t2(a, b, PRIMARY KEY(a DESC, b NULLS FIRST)) } FIRST 989105fd51Sdan 10 { CREATE TABLE t2(a, b, UNIQUE(a DESC NULLS FIRST, b)) } FIRST 999105fd51Sdan 11 { INSERT INTO t1 VALUES(1, 2, 3, 4) 1009105fd51Sdan ON CONFLICT (b DESC NULLS LAST) DO UPDATE SET a = a+1 } LAST 1019105fd51Sdan 12 { 1029105fd51Sdan CREATE TRIGGER tr1 AFTER INSERT ON t1 BEGIN 1039105fd51Sdan INSERT INTO t1 VALUES(1, 2, 3, 4) 1049105fd51Sdan ON CONFLICT (b DESC NULLS FIRST) DO UPDATE SET a = a+1; 1059105fd51Sdan END 1069105fd51Sdan } FIRST 1079105fd51Sdan} { 1089105fd51Sdan do_catchsql_test 3.1.$tn $sql "1 {unsupported use of NULLS $err}" 1099105fd51Sdan} 1109105fd51Sdan 1119105fd51Sdando_execsql_test 3.2 { 1129105fd51Sdan CREATE TABLE first(nulls, last); 1139105fd51Sdan INSERT INTO first(last, nulls) VALUES(100,200), (300,400), (200,300); 1149105fd51Sdan SELECT * FROM first ORDER BY nulls; 1159105fd51Sdan} { 1169105fd51Sdan 200 100 1179105fd51Sdan 300 200 1189105fd51Sdan 400 300 1199105fd51Sdan} 1209105fd51Sdan 1214fcb9caaSdan#------------------------------------------------------------------------- 1222a0c16f2Sdan# 1234fcb9caaSdanifcapable vtab { 1244fcb9caaSdan register_echo_module db 1254fcb9caaSdan do_execsql_test 4.0 { 1264fcb9caaSdan CREATE TABLE tx(a INTEGER PRIMARY KEY, b, c); 1274fcb9caaSdan CREATE INDEX i1 ON tx(b); 1284fcb9caaSdan INSERT INTO tx VALUES(1, 1, 1); 1294fcb9caaSdan INSERT INTO tx VALUES(2, NULL, 2); 1304fcb9caaSdan INSERT INTO tx VALUES(3, 3, 3); 1314fcb9caaSdan INSERT INTO tx VALUES(4, NULL, 4); 1324fcb9caaSdan INSERT INTO tx VALUES(5, 5, 5); 1334fcb9caaSdan CREATE VIRTUAL TABLE te USING echo(tx); 1344fcb9caaSdan } 1354fcb9caaSdan 1364fcb9caaSdan do_execsql_test 4.1 { 1374fcb9caaSdan SELECT * FROM tx ORDER BY b NULLS FIRST; 1384fcb9caaSdan } {2 {} 2 4 {} 4 1 1 1 3 3 3 5 5 5} 1394fcb9caaSdan do_execsql_test 4.2 { 1404fcb9caaSdan SELECT * FROM te ORDER BY b NULLS FIRST; 1414fcb9caaSdan } {2 {} 2 4 {} 4 1 1 1 3 3 3 5 5 5} 1424fcb9caaSdan 1434fcb9caaSdan do_execsql_test 4.3 { 1444fcb9caaSdan SELECT * FROM tx ORDER BY b NULLS LAST; 1454fcb9caaSdan } {1 1 1 3 3 3 5 5 5 2 {} 2 4 {} 4} 1464fcb9caaSdan do_execsql_test 4.4 { 1474fcb9caaSdan SELECT * FROM te ORDER BY b NULLS LAST; 1484fcb9caaSdan } {1 1 1 3 3 3 5 5 5 2 {} 2 4 {} 4} 1494fcb9caaSdan} 1504fcb9caaSdan 1512a0c16f2Sdan#------------------------------------------------------------------------- 1522a0c16f2Sdan# 1532a0c16f2Sdando_execsql_test 5.0 { 1542a0c16f2Sdan CREATE TABLE t4(a, b, c); 1552a0c16f2Sdan INSERT INTO t4 VALUES(1, 1, 11); 1562a0c16f2Sdan INSERT INTO t4 VALUES(1, 2, 12); 1572a0c16f2Sdan INSERT INTO t4 VALUES(1, NULL, 1); 1582a0c16f2Sdan 1592a0c16f2Sdan INSERT INTO t4 VALUES(2, NULL, 1); 1602a0c16f2Sdan INSERT INTO t4 VALUES(2, 2, 12); 1612a0c16f2Sdan INSERT INTO t4 VALUES(2, 1, 11); 1622a0c16f2Sdan 1632a0c16f2Sdan INSERT INTO t4 VALUES(3, NULL, 1); 1642a0c16f2Sdan INSERT INTO t4 VALUES(3, 2, 12); 1652a0c16f2Sdan INSERT INTO t4 VALUES(3, NULL, 3); 1662a0c16f2Sdan} 1672a0c16f2Sdan 1682a0c16f2Sdando_execsql_test 5.1 { 1692a0c16f2Sdan SELECT * FROM t4 WHERE a IN (1, 2, 3) ORDER BY a, b NULLS LAST 1702a0c16f2Sdan} { 1712a0c16f2Sdan 1 1 11 1 2 12 1 {} 1 1722a0c16f2Sdan 2 1 11 2 2 12 2 {} 1 1732a0c16f2Sdan 3 2 12 3 {} 1 3 {} 3 1742a0c16f2Sdan} 1752a0c16f2Sdando_execsql_test 5.2 { 1762a0c16f2Sdan CREATE INDEX t4ab ON t4(a, b); 1772a0c16f2Sdan SELECT * FROM t4 WHERE a IN (1, 2, 3) ORDER BY a, b NULLS LAST 1782a0c16f2Sdan} { 1792a0c16f2Sdan 1 1 11 1 2 12 1 {} 1 1802a0c16f2Sdan 2 1 11 2 2 12 2 {} 1 1812a0c16f2Sdan 3 2 12 3 {} 1 3 {} 3 1822a0c16f2Sdan} 1832a0c16f2Sdando_eqp_test 5.3 { 1842a0c16f2Sdan SELECT * FROM t4 WHERE a IN (1, 2, 3) ORDER BY a, b NULLS LAST 1852a0c16f2Sdan} { 1862a0c16f2Sdan QUERY PLAN 187*8210233cSdrh `--SEARCH t4 USING INDEX t4ab (a=?) 1882a0c16f2Sdan} 1892a0c16f2Sdan 1902a0c16f2Sdando_execsql_test 5.4 { 1912a0c16f2Sdan SELECT * FROM t4 WHERE a IN (1, 2, 3) ORDER BY a DESC, b DESC NULLS FIRST 1922a0c16f2Sdan} { 1932a0c16f2Sdan 3 {} 3 3 {} 1 3 2 12 1942a0c16f2Sdan 2 {} 1 2 2 12 2 1 11 1952a0c16f2Sdan 1 {} 1 1 2 12 1 1 11 1962a0c16f2Sdan} 1972a0c16f2Sdando_eqp_test 5.5 { 1982a0c16f2Sdan SELECT * FROM t4 WHERE a IN (1, 2, 3) ORDER BY a DESC, b DESC NULLS FIRST 1992a0c16f2Sdan} { 2002a0c16f2Sdan QUERY PLAN 201*8210233cSdrh `--SEARCH t4 USING INDEX t4ab (a=?) 2022a0c16f2Sdan} 2032a0c16f2Sdan 204546738f8Sdan#------------------------------------------------------------------------- 205546738f8Sdan# 206546738f8Sdando_execsql_test 6.0 { 207546738f8Sdan CREATE TABLE t5(a, b, c); 208546738f8Sdan WITH s(i) AS ( 209546738f8Sdan VALUES(1) UNION ALL SELECT i+1 FROM s WHERE i<200 210546738f8Sdan ) 211546738f8Sdan INSERT INTO t5 SELECT i%2, CASE WHEN (i%10)==0 THEN NULL ELSE i END, i FROM s; 212546738f8Sdan} 213546738f8Sdan 214546738f8Sdanset res1 [db eval { SELECT a,b FROM t5 WHERE a=1 ORDER BY b NULLS LAST, c }] 215546738f8Sdanset res2 [db eval { 216546738f8Sdan SELECT a,b FROM t5 WHERE a=1 ORDER BY b DESC NULLS FIRST, c DESC 217546738f8Sdan}] 218546738f8Sdan 219546738f8Sdando_execsql_test 6.1.1 { 220546738f8Sdan CREATE INDEX t5ab ON t5(a, b, c); 221546738f8Sdan SELECT a,b FROM t5 WHERE a=1 ORDER BY b NULLS LAST, c; 222546738f8Sdan} $res1 223546738f8Sdando_eqp_test 6.1.2 { 224546738f8Sdan SELECT a,b FROM t5 WHERE a=1 ORDER BY b NULLS LAST, c; 225546738f8Sdan} { 226546738f8Sdan QUERY PLAN 227*8210233cSdrh `--SEARCH t5 USING COVERING INDEX t5ab (a=?) 228546738f8Sdan} 229546738f8Sdando_execsql_test 6.2.1 { 230546738f8Sdan SELECT a,b FROM t5 WHERE a=1 ORDER BY b DESC NULLS FIRST, c DESC 231546738f8Sdan} $res2 232546738f8Sdando_eqp_test 6.2.2 { 233546738f8Sdan SELECT a,b FROM t5 WHERE a=1 ORDER BY b DESC NULLS FIRST, c DESC 234546738f8Sdan} { 235546738f8Sdan QUERY PLAN 236*8210233cSdrh `--SEARCH t5 USING COVERING INDEX t5ab (a=?) 237546738f8Sdan} 238546738f8Sdan 239bd717a4dSdan#------------------------------------------------------------------------- 240bd717a4dSdando_execsql_test 7.0 { 241bd717a4dSdan CREATE TABLE t71(a, b, c); 242bd717a4dSdan CREATE INDEX t71abc ON t71(a, b, c); 243bd717a4dSdan 244bd717a4dSdan SELECT * FROM t71 WHERE a=1 AND b=2 ORDER BY c NULLS LAST; 245bd717a4dSdan SELECT * FROM t71 WHERE a=1 AND b=2 ORDER BY c DESC NULLS FIRST; 246bd717a4dSdan 247bd717a4dSdan SELECT * FROM t71 ORDER BY a NULLS LAST; 248bd717a4dSdan SELECT * FROM t71 ORDER BY a DESC NULLS FIRST; 249bd717a4dSdan} 250546738f8Sdan 25134ab941eSdrh# 2019-12-18 gramfuzz1 find 25234ab941eSdrh# NULLS LAST not allows on an INTEGER PRIMARY KEY. 25334ab941eSdrh# 25434ab941eSdrhdo_catchsql_test 8.0 { 25534ab941eSdrh CREATE TABLE t80(a, b INTEGER, PRIMARY KEY(b NULLS LAST)) WITHOUT ROWID; 25634ab941eSdrh} {1 {unsupported use of NULLS LAST}} 25734ab941eSdrh 2584adb1d00Sdan#------------------------------------------------------------------------- 2594adb1d00Sdanreset_db 2604adb1d00Sdando_execsql_test 9.0 { 2614adb1d00Sdan CREATE TABLE v0 (c1, c2, c3); 2624adb1d00Sdan CREATE INDEX v3 ON v0 (c1, c2, c3); 2634adb1d00Sdan} 2644adb1d00Sdando_execsql_test 9.1 { 2654adb1d00Sdan ANALYZE sqlite_master; 2664adb1d00Sdan INSERT INTO sqlite_stat1 VALUES('v0','v3','648 324 81'); 2674adb1d00Sdan ANALYZE sqlite_master; 2684adb1d00Sdan} 2694adb1d00Sdan 2704adb1d00Sdando_execsql_test 9.2 { 2714adb1d00Sdan INSERT INTO v0 VALUES 2724adb1d00Sdan (1, 10, 'b'), 2734adb1d00Sdan (1, 10, 'd'), 2744adb1d00Sdan (1, 10, NULL), 2754adb1d00Sdan (2, 10, 'a'), 2764adb1d00Sdan (2, 10, NULL), 2774adb1d00Sdan (1, 10, 'c'), 2784adb1d00Sdan (2, 10, 'b'), 2794adb1d00Sdan (1, 10, 'a'), 2804adb1d00Sdan (1, 10, NULL), 2814adb1d00Sdan (2, 10, NULL), 2824adb1d00Sdan (2, 10, 'd'), 2834adb1d00Sdan (2, 10, 'c'); 2844adb1d00Sdan} 2854adb1d00Sdan 2864adb1d00Sdando_execsql_test 9.3 { 2874adb1d00Sdan SELECT c1, c2, ifnull(c3, 'NULL') FROM v0 2884adb1d00Sdan WHERE c2=10 ORDER BY c1, c3 NULLS LAST 2894adb1d00Sdan} { 2904adb1d00Sdan 1 10 a 1 10 b 1 10 c 1 10 d 1 10 NULL 1 10 NULL 2914adb1d00Sdan 2 10 a 2 10 b 2 10 c 2 10 d 2 10 NULL 2 10 NULL 2924adb1d00Sdan} 2934adb1d00Sdan 2944adb1d00Sdando_eqp_test 9.4 { 2954adb1d00Sdan SELECT c1, c2, ifnull(c3, 'NULL') FROM v0 2964adb1d00Sdan WHERE c2=10 ORDER BY c1, c3 NULLS LAST 297*8210233cSdrh} {SEARCH v0 USING COVERING INDEX v3 (ANY(c1) AND c2=?)} 2984adb1d00Sdan 2994adb1d00Sdan 3007f05d52cSdrh# 2020-03-01 ticket e12a0ae526bb51c7 3017f05d52cSdrh# NULLS LAST on a LEFT JOIN 3027f05d52cSdrh# 3037f05d52cSdrhreset_db 3047f05d52cSdrhdo_execsql_test 10.10 { 3057f05d52cSdrh CREATE TABLE t1(x); 3067f05d52cSdrh INSERT INTO t1(x) VALUES('X'); 3077f05d52cSdrh CREATE TABLE t2(c, d); 3087f05d52cSdrh CREATE INDEX t2dc ON t2(d, c); 3097f05d52cSdrh SELECT c FROM t1 LEFT JOIN t2 ON d=NULL ORDER BY d, c NULLS LAST; 3107f05d52cSdrh} {{}} 3117f05d52cSdrhdo_execsql_test 10.20 { 3127f05d52cSdrh INSERT INTO t2(c,d) VALUES(5,'X'),(6,'Y'),(7,'Z'),(3,'A'),(4,'B'); 3137f05d52cSdrh SELECT c FROM t1 LEFT JOIN t2 ON d=x ORDER BY d, c NULLS LAST; 3147f05d52cSdrh} {5} 3157f05d52cSdrhdo_execsql_test 10.30 { 3167f05d52cSdrh UPDATE t2 SET d='X'; 3177f05d52cSdrh UPDATE t2 SET c=NULL WHERE c=6; 3187f05d52cSdrh SELECT c FROM t1 LEFT JOIN t2 ON d=x ORDER BY d NULLS FIRST, c NULLS FIRST; 3197f05d52cSdrh} {{} 3 4 5 7} 3207f05d52cSdrhdo_execsql_test 10.40 { 3217f05d52cSdrh SELECT c FROM t1 LEFT JOIN t2 ON d=x ORDER BY d NULLS LAST, c NULLS LAST; 3227f05d52cSdrh} {3 4 5 7 {}} 3237f05d52cSdrhdo_execsql_test 10.41 { 3247f05d52cSdrh SELECT c FROM t1 LEFT JOIN t2 ON d=x ORDER BY c NULLS LAST; 3257f05d52cSdrh} {3 4 5 7 {}} 3267f05d52cSdrhdo_execsql_test 10.42 { 3277f05d52cSdrh SELECT c FROM t1 LEFT JOIN t2 ON d=x ORDER BY +d NULLS LAST, +c NULLS LAST; 3287f05d52cSdrh} {3 4 5 7 {}} 3297f05d52cSdrhdo_execsql_test 10.50 { 3307f05d52cSdrh INSERT INTO t1(x) VALUES(NULL),('Y'); 3317f05d52cSdrh SELECT x, c, d, '|' FROM t1 LEFT JOIN t2 ON d=x 3327f05d52cSdrh ORDER BY d NULLS LAST, c NULLS LAST; 3337f05d52cSdrh} {X 3 X | X 4 X | X 5 X | X 7 X | X {} X | {} {} {} | Y {} {} |} 3347f05d52cSdrhdo_execsql_test 10.51 { 3357f05d52cSdrh SELECT x, c, d, '|' FROM t1 LEFT JOIN t2 ON d=x 3367f05d52cSdrh ORDER BY +d NULLS LAST, +c NULLS LAST; 3377f05d52cSdrh} {X 3 X | X 4 X | X 5 X | X 7 X | X {} X | {} {} {} | Y {} {} |} 3387f05d52cSdrh 3397f05d52cSdrh 3407f05d52cSdrh 3417f05d52cSdrh 3424adb1d00Sdan 3436e11892dSdanfinish_test 344