12da8d6feSdrh# 2001-09-15 262c68191Sdrh# 3b19a2bc6Sdrh# The author disclaims copyright to this source code. In place of 4b19a2bc6Sdrh# a legal notice, here is a blessing: 562c68191Sdrh# 6b19a2bc6Sdrh# May you do good and not evil. 7b19a2bc6Sdrh# May you find forgiveness for yourself and forgive others. 8b19a2bc6Sdrh# May you share freely, never taking more than you give. 962c68191Sdrh# 1062c68191Sdrh#*********************************************************************** 1162c68191Sdrh# This file implements regression tests for SQLite library. The 1262c68191Sdrh# focus of this file is testing the INSERT statement. 1362c68191Sdrh# 1462c68191Sdrh 1562c68191Sdrhset testdir [file dirname $argv0] 1662c68191Sdrhsource $testdir/tester.tcl 1762c68191Sdrh 1862c68191Sdrh# Try to insert into a non-existant table. 1962c68191Sdrh# 2062c68191Sdrhdo_test insert-1.1 { 2162c68191Sdrh set v [catch {execsql {INSERT INTO test1 VALUES(1,2,3)}} msg] 2262c68191Sdrh lappend v $msg 231d37e284Sdrh} {1 {no such table: test1}} 2462c68191Sdrh 2562c68191Sdrh# Try to insert into sqlite_master 2662c68191Sdrh# 2762c68191Sdrhdo_test insert-1.2 { 2862c68191Sdrh set v [catch {execsql {INSERT INTO sqlite_master VALUES(1,2,3,4)}} msg] 2962c68191Sdrh lappend v $msg 301d37e284Sdrh} {1 {table sqlite_master may not be modified}} 3162c68191Sdrh 3262c68191Sdrh# Try to insert the wrong number of entries. 3362c68191Sdrh# 3462c68191Sdrhdo_test insert-1.3 { 3562c68191Sdrh execsql {CREATE TABLE test1(one int, two int, three int)} 3662c68191Sdrh set v [catch {execsql {INSERT INTO test1 VALUES(1,2)}} msg] 3762c68191Sdrh lappend v $msg 3862c68191Sdrh} {1 {table test1 has 3 columns but 2 values were supplied}} 3962c68191Sdrhdo_test insert-1.3b { 4062c68191Sdrh set v [catch {execsql {INSERT INTO test1 VALUES(1,2,3,4)}} msg] 4162c68191Sdrh lappend v $msg 4262c68191Sdrh} {1 {table test1 has 3 columns but 4 values were supplied}} 4362c68191Sdrhdo_test insert-1.3c { 4462c68191Sdrh set v [catch {execsql {INSERT INTO test1(one,two) VALUES(1,2,3,4)}} msg] 4562c68191Sdrh lappend v $msg 4662c68191Sdrh} {1 {4 values for 2 columns}} 4762c68191Sdrhdo_test insert-1.3d { 4862c68191Sdrh set v [catch {execsql {INSERT INTO test1(one,two) VALUES(1)}} msg] 4962c68191Sdrh lappend v $msg 5062c68191Sdrh} {1 {1 values for 2 columns}} 5162c68191Sdrh 5262c68191Sdrh# Try to insert into a non-existant column of a table. 5362c68191Sdrh# 5462c68191Sdrhdo_test insert-1.4 { 5562c68191Sdrh set v [catch {execsql {INSERT INTO test1(one,four) VALUES(1,2)}} msg] 5662c68191Sdrh lappend v $msg 5762c68191Sdrh} {1 {table test1 has no column named four}} 5862c68191Sdrh 5962c68191Sdrh# Make sure the inserts actually happen 6062c68191Sdrh# 6162c68191Sdrhdo_test insert-1.5 { 6262c68191Sdrh execsql {INSERT INTO test1 VALUES(1,2,3)} 6362c68191Sdrh execsql {SELECT * FROM test1} 6462c68191Sdrh} {1 2 3} 6562c68191Sdrhdo_test insert-1.5b { 6662c68191Sdrh execsql {INSERT INTO test1 VALUES(4,5,6)} 6762c68191Sdrh execsql {SELECT * FROM test1 ORDER BY one} 6862c68191Sdrh} {1 2 3 4 5 6} 6962c68191Sdrhdo_test insert-1.5c { 7062c68191Sdrh execsql {INSERT INTO test1 VALUES(7,8,9)} 7162c68191Sdrh execsql {SELECT * FROM test1 ORDER BY one} 7262c68191Sdrh} {1 2 3 4 5 6 7 8 9} 7362c68191Sdrh 7462c68191Sdrhdo_test insert-1.6 { 7562c68191Sdrh execsql {DELETE FROM test1} 7662c68191Sdrh execsql {INSERT INTO test1(one,two) VALUES(1,2)} 7762c68191Sdrh execsql {SELECT * FROM test1 ORDER BY one} 7862c68191Sdrh} {1 2 {}} 7962c68191Sdrhdo_test insert-1.6b { 8062c68191Sdrh execsql {INSERT INTO test1(two,three) VALUES(5,6)} 8162c68191Sdrh execsql {SELECT * FROM test1 ORDER BY one} 8262c68191Sdrh} {{} 5 6 1 2 {}} 8362c68191Sdrhdo_test insert-1.6c { 8462c68191Sdrh execsql {INSERT INTO test1(three,one) VALUES(7,8)} 8562c68191Sdrh execsql {SELECT * FROM test1 ORDER BY one} 8662c68191Sdrh} {{} 5 6 1 2 {} 8 {} 7} 8762c68191Sdrh 887020f651Sdrh# A table to use for testing default values 897020f651Sdrh# 90c4a3c779Sdrhdo_test insert-2.1 { 917020f651Sdrh execsql { 927020f651Sdrh CREATE TABLE test2( 93c4a3c779Sdrh f1 int default -111, 94c4a3c779Sdrh f2 real default +4.32, 95c4a3c779Sdrh f3 int default +222, 96c4a3c779Sdrh f4 int default 7.89 97c4a3c779Sdrh ) 98c4a3c779Sdrh } 99c4a3c779Sdrh execsql {SELECT * from test2} 100c4a3c779Sdrh} {} 101c4a3c779Sdrhdo_test insert-2.2 { 102c4a3c779Sdrh execsql {INSERT INTO test2(f1,f3) VALUES(+10,-10)} 103c4a3c779Sdrh execsql {SELECT * FROM test2} 104c4a3c779Sdrh} {10 4.32 -10 7.89} 105c4a3c779Sdrhdo_test insert-2.3 { 106c4a3c779Sdrh execsql {INSERT INTO test2(f2,f4) VALUES(1.23,-3.45)} 107c4a3c779Sdrh execsql {SELECT * FROM test2 WHERE f1==-111} 108c4a3c779Sdrh} {-111 1.23 222 -3.45} 109c4a3c779Sdrhdo_test insert-2.4 { 110c4a3c779Sdrh execsql {INSERT INTO test2(f1,f2,f4) VALUES(77,+1.23,3.45)} 111c4a3c779Sdrh execsql {SELECT * FROM test2 WHERE f1==77} 112c4a3c779Sdrh} {77 1.23 222 3.45} 113c4a3c779Sdrhdo_test insert-2.10 { 114c4a3c779Sdrh execsql { 115c4a3c779Sdrh DROP TABLE test2; 116c4a3c779Sdrh CREATE TABLE test2( 1177020f651Sdrh f1 int default 111, 1187020f651Sdrh f2 real default -4.32, 1197020f651Sdrh f3 text default hi, 1207020f651Sdrh f4 text default 'abc-123', 1217020f651Sdrh f5 varchar(10) 1227020f651Sdrh ) 1237020f651Sdrh } 1247020f651Sdrh execsql {SELECT * from test2} 1257020f651Sdrh} {} 126c4a3c779Sdrhdo_test insert-2.11 { 1277020f651Sdrh execsql {INSERT INTO test2(f2,f4) VALUES(-2.22,'hi!')} 1287020f651Sdrh execsql {SELECT * FROM test2} 1297020f651Sdrh} {111 -2.22 hi hi! {}} 130c4a3c779Sdrhdo_test insert-2.12 { 1317020f651Sdrh execsql {INSERT INTO test2(f1,f5) VALUES(1,'xyzzy')} 1327020f651Sdrh execsql {SELECT * FROM test2 ORDER BY f1} 1337020f651Sdrh} {1 -4.32 hi abc-123 xyzzy 111 -2.22 hi hi! {}} 1347020f651Sdrh 1357020f651Sdrh# Do additional inserts with default values, but this time 1367020f651Sdrh# on a table that has indices. In particular we want to verify 1377020f651Sdrh# that the correct default values are inserted into the indices. 1387020f651Sdrh# 1397020f651Sdrhdo_test insert-3.1 { 1405974a30fSdrh execsql { 1415974a30fSdrh DELETE FROM test2; 1425974a30fSdrh CREATE INDEX index9 ON test2(f1,f2); 1435974a30fSdrh CREATE INDEX indext ON test2(f4,f5); 1445974a30fSdrh SELECT * from test2; 1455974a30fSdrh } 1467020f651Sdrh} {} 147452c989fSdanielk1977 148ef4ac8f9Sdrh# Update for sqlite3 v3: 149452c989fSdanielk1977# Change the 111 to '111' in the following two test cases, because 150452c989fSdanielk1977# the default value is being inserted as a string. TODO: It shouldn't be. 1517020f651Sdrhdo_test insert-3.2 { 1527020f651Sdrh execsql {INSERT INTO test2(f2,f4) VALUES(-3.33,'hum')} 153452c989fSdanielk1977 execsql {SELECT * FROM test2 WHERE f1='111' AND f2=-3.33} 1547020f651Sdrh} {111 -3.33 hi hum {}} 1557020f651Sdrhdo_test insert-3.3 { 1567020f651Sdrh execsql {INSERT INTO test2(f1,f2,f5) VALUES(22,-4.44,'wham')} 157452c989fSdanielk1977 execsql {SELECT * FROM test2 WHERE f1='111' AND f2=-3.33} 1587020f651Sdrh} {111 -3.33 hi hum {}} 1597020f651Sdrhdo_test insert-3.4 { 1607020f651Sdrh execsql {SELECT * FROM test2 WHERE f1=22 AND f2=-4.44} 1617020f651Sdrh} {22 -4.44 hi abc-123 wham} 162e497f005Sdrhifcapable {reindex} { 163e497f005Sdrh do_test insert-3.5 { 164e497f005Sdrh execsql REINDEX 165e497f005Sdrh } {} 166e497f005Sdrh} 1672150432eSdrhintegrity_check insert-3.5 16824e97df9Sdrh 169adbe353fSdrh# Test of expressions in the VALUES clause 170adbe353fSdrh# 171e64e7b20Sdrhdo_test insert-4.1 { 172e64e7b20Sdrh execsql { 173e64e7b20Sdrh CREATE TABLE t3(a,b,c); 174e64e7b20Sdrh INSERT INTO t3 VALUES(1+2+3,4,5); 175e64e7b20Sdrh SELECT * FROM t3; 176e64e7b20Sdrh } 177e64e7b20Sdrh} {6 4 5} 178e64e7b20Sdrhdo_test insert-4.2 { 1793e8c37e7Sdanielk1977 ifcapable subquery { 1803e8c37e7Sdanielk1977 execsql {INSERT INTO t3 VALUES((SELECT max(a) FROM t3)+1,5,6);} 1813e8c37e7Sdanielk1977 } else { 1823e8c37e7Sdanielk1977 set maxa [execsql {SELECT max(a) FROM t3}] 1833e8c37e7Sdanielk1977 execsql "INSERT INTO t3 VALUES($maxa+1,5,6);" 1843e8c37e7Sdanielk1977 } 185e64e7b20Sdrh execsql { 186e64e7b20Sdrh SELECT * FROM t3 ORDER BY a; 187e64e7b20Sdrh } 188e64e7b20Sdrh} {6 4 5 7 5 6} 1893e8c37e7Sdanielk1977ifcapable subquery { 190e64e7b20Sdrh do_test insert-4.3 { 191e64e7b20Sdrh catchsql { 192e64e7b20Sdrh INSERT INTO t3 VALUES((SELECT max(a) FROM t3)+1,t3.a,6); 193e64e7b20Sdrh SELECT * FROM t3 ORDER BY a; 194e64e7b20Sdrh } 195e64e7b20Sdrh } {1 {no such column: t3.a}} 1963e8c37e7Sdanielk1977} 197e64e7b20Sdrhdo_test insert-4.4 { 1983e8c37e7Sdanielk1977 ifcapable subquery { 1993e8c37e7Sdanielk1977 execsql {INSERT INTO t3 VALUES((SELECT b FROM t3 WHERE a=0),6,7);} 2003e8c37e7Sdanielk1977 } else { 2013e8c37e7Sdanielk1977 set b [execsql {SELECT b FROM t3 WHERE a = 0}] 2023e8c37e7Sdanielk1977 if {$b==""} {set b NULL} 2033e8c37e7Sdanielk1977 execsql "INSERT INTO t3 VALUES($b,6,7);" 2043e8c37e7Sdanielk1977 } 205e64e7b20Sdrh execsql { 206e64e7b20Sdrh SELECT * FROM t3 ORDER BY a; 207e64e7b20Sdrh } 208e64e7b20Sdrh} {{} 6 7 6 4 5 7 5 6} 209e64e7b20Sdrhdo_test insert-4.5 { 210e64e7b20Sdrh execsql { 211e64e7b20Sdrh SELECT b,c FROM t3 WHERE a IS NULL; 212e64e7b20Sdrh } 213e64e7b20Sdrh} {6 7} 214adbe353fSdrhdo_test insert-4.6 { 215adbe353fSdrh catchsql { 216adbe353fSdrh INSERT INTO t3 VALUES(notafunc(2,3),2,3); 217adbe353fSdrh } 218adbe353fSdrh} {1 {no such function: notafunc}} 219adbe353fSdrhdo_test insert-4.7 { 220adbe353fSdrh execsql { 221adbe353fSdrh INSERT INTO t3 VALUES(min(1,2,3),max(1,2,3),99); 222adbe353fSdrh SELECT * FROM t3 WHERE c=99; 223adbe353fSdrh } 224adbe353fSdrh} {1 3 99} 225adbe353fSdrh 226048c530cSdrh# Test the ability to insert from a temporary table into itself. 227048c530cSdrh# Ticket #275. 228048c530cSdrh# 22953c0f748Sdanielk1977ifcapable tempdb { 230048c530cSdrh do_test insert-5.1 { 231048c530cSdrh execsql { 232048c530cSdrh CREATE TEMP TABLE t4(x); 233048c530cSdrh INSERT INTO t4 VALUES(1); 234048c530cSdrh SELECT * FROM t4; 235048c530cSdrh } 236048c530cSdrh } {1} 237048c530cSdrh do_test insert-5.2 { 238048c530cSdrh execsql { 239048c530cSdrh INSERT INTO t4 SELECT x+1 FROM t4; 240048c530cSdrh SELECT * FROM t4; 241048c530cSdrh } 242048c530cSdrh } {1 2} 2436bf89570Sdrh ifcapable {explain} { 244048c530cSdrh do_test insert-5.3 { 245048c530cSdrh # verify that a temporary table is used to copy t4 to t4 246048c530cSdrh set x [execsql { 247048c530cSdrh EXPLAIN INSERT INTO t4 SELECT x+2 FROM t4; 248048c530cSdrh }] 249b9bb7c18Sdrh expr {[lsearch $x OpenEphemeral]>0} 250048c530cSdrh } {1} 2516bf89570Sdrh } 252bf57cfebSdanielk1977 253048c530cSdrh do_test insert-5.4 { 254048c530cSdrh # Verify that table "test1" begins on page 3. This should be the same 255048c530cSdrh # page number used by "t4" above. 256bf57cfebSdanielk1977 # 257bf57cfebSdanielk1977 # Update for v3 - the first table now begins on page 2 of each file, not 3. 258048c530cSdrh execsql { 259048c530cSdrh SELECT rootpage FROM sqlite_master WHERE name='test1'; 260048c530cSdrh } 26145901d62Sdanielk1977 } [expr $AUTOVACUUM?3:2] 262048c530cSdrh do_test insert-5.5 { 263048c530cSdrh # Verify that "t4" begins on page 3. 264bf57cfebSdanielk1977 # 265bf57cfebSdanielk1977 # Update for v3 - the first table now begins on page 2 of each file, not 3. 266048c530cSdrh execsql { 267048c530cSdrh SELECT rootpage FROM sqlite_temp_master WHERE name='t4'; 268048c530cSdrh } 269bf57cfebSdanielk1977 } {2} 270048c530cSdrh do_test insert-5.6 { 271048c530cSdrh # This should not use an intermediate temporary table. 272048c530cSdrh execsql { 273048c530cSdrh INSERT INTO t4 SELECT one FROM test1 WHERE three=7; 274048c530cSdrh SELECT * FROM t4 275048c530cSdrh } 276048c530cSdrh } {1 2 8} 2776bf89570Sdrh ifcapable {explain} { 278048c530cSdrh do_test insert-5.7 { 279048c530cSdrh # verify that no temporary table is used to copy test1 to t4 280048c530cSdrh set x [execsql { 281048c530cSdrh EXPLAIN INSERT INTO t4 SELECT one FROM test1; 282048c530cSdrh }] 283048c530cSdrh expr {[lsearch $x OpenTemp]>0} 284048c530cSdrh } {0} 2856bf89570Sdrh } 28653c0f748Sdanielk1977} 287048c530cSdrh 2885383ae5cSdrh# Ticket #334: REPLACE statement corrupting indices. 2895383ae5cSdrh# 2903bdca9c9Sdanielk1977ifcapable conflict { 2913bdca9c9Sdanielk1977 # The REPLACE command is not available if SQLITE_OMIT_CONFLICT is 2923bdca9c9Sdanielk1977 # defined at compilation time. 2935383ae5cSdrh do_test insert-6.1 { 2945383ae5cSdrh execsql { 2955383ae5cSdrh CREATE TABLE t1(a INTEGER PRIMARY KEY, b UNIQUE); 2965383ae5cSdrh INSERT INTO t1 VALUES(1,2); 2975383ae5cSdrh INSERT INTO t1 VALUES(2,3); 2985383ae5cSdrh SELECT b FROM t1 WHERE b=2; 2995383ae5cSdrh } 3005383ae5cSdrh } {2} 3015383ae5cSdrh do_test insert-6.2 { 3025383ae5cSdrh execsql { 3035383ae5cSdrh REPLACE INTO t1 VALUES(1,4); 3045383ae5cSdrh SELECT b FROM t1 WHERE b=2; 3055383ae5cSdrh } 3065383ae5cSdrh } {} 3077d02cb73Sdrh do_test insert-6.3 { 3087d02cb73Sdrh execsql { 3097d02cb73Sdrh UPDATE OR REPLACE t1 SET a=2 WHERE b=4; 3107d02cb73Sdrh SELECT * FROM t1 WHERE b=4; 3117d02cb73Sdrh } 3127d02cb73Sdrh } {2 4} 3137d02cb73Sdrh do_test insert-6.4 { 3147d02cb73Sdrh execsql { 3157d02cb73Sdrh SELECT * FROM t1 WHERE b=3; 3167d02cb73Sdrh } 3177d02cb73Sdrh } {} 318e497f005Sdrh ifcapable {reindex} { 3193bdca9c9Sdanielk1977 do_test insert-6.5 { 320e497f005Sdrh execsql REINDEX 321e497f005Sdrh } {} 322e497f005Sdrh } 3233bdca9c9Sdanielk1977 do_test insert-6.6 { 3243bdca9c9Sdanielk1977 execsql { 3253bdca9c9Sdanielk1977 DROP TABLE t1; 3263bdca9c9Sdanielk1977 } 3273bdca9c9Sdanielk1977 } {} 3283bdca9c9Sdanielk1977} 3297020f651Sdrh 3303719d7f9Sdanielk1977# Test that the special optimization for queries of the form 3313719d7f9Sdanielk1977# "SELECT max(x) FROM tbl" where there is an index on tbl(x) works with 3323719d7f9Sdanielk1977# INSERT statments. 3333719d7f9Sdanielk1977do_test insert-7.1 { 3343719d7f9Sdanielk1977 execsql { 3353719d7f9Sdanielk1977 CREATE TABLE t1(a); 3363719d7f9Sdanielk1977 INSERT INTO t1 VALUES(1); 3373719d7f9Sdanielk1977 INSERT INTO t1 VALUES(2); 3383719d7f9Sdanielk1977 CREATE INDEX i1 ON t1(a); 3393719d7f9Sdanielk1977 } 3403719d7f9Sdanielk1977} {} 3413719d7f9Sdanielk1977do_test insert-7.2 { 3423719d7f9Sdanielk1977 execsql { 3433719d7f9Sdanielk1977 INSERT INTO t1 SELECT max(a) FROM t1; 3443719d7f9Sdanielk1977 } 3453719d7f9Sdanielk1977} {} 3463719d7f9Sdanielk1977do_test insert-7.3 { 3473719d7f9Sdanielk1977 execsql { 3483719d7f9Sdanielk1977 SELECT a FROM t1; 3493719d7f9Sdanielk1977 } 3503719d7f9Sdanielk1977} {1 2 2} 3513719d7f9Sdanielk1977 35238fba691Sdrh# Ticket #1140: Check for an infinite loop in the algorithm that tests 35338fba691Sdrh# to see if the right-hand side of an INSERT...SELECT references the left-hand 35438fba691Sdrh# side. 35538fba691Sdrh# 356ff890793Sdanielk1977ifcapable subquery&&compound { 35738fba691Sdrh do_test insert-8.1 { 35838fba691Sdrh execsql { 35938fba691Sdrh INSERT INTO t3 SELECT * FROM (SELECT * FROM t3 UNION ALL SELECT 1,2,3) 36038fba691Sdrh } 36138fba691Sdrh } {} 362a38b4134Sdanielk1977} 36338fba691Sdrh 3647c4ac0c5Sdrh# Make sure the rowid cache in the VDBE is reset correctly when 3657c4ac0c5Sdrh# an explicit rowid is given. 3667c4ac0c5Sdrh# 3677c4ac0c5Sdrhdo_test insert-9.1 { 3687c4ac0c5Sdrh execsql { 3697c4ac0c5Sdrh CREATE TABLE t5(x); 3707c4ac0c5Sdrh INSERT INTO t5 VALUES(1); 3717c4ac0c5Sdrh INSERT INTO t5 VALUES(2); 3727c4ac0c5Sdrh INSERT INTO t5 VALUES(3); 3737c4ac0c5Sdrh INSERT INTO t5(rowid, x) SELECT nullif(x*2+10,14), x+100 FROM t5; 3747c4ac0c5Sdrh SELECT rowid, x FROM t5; 3757c4ac0c5Sdrh } 3767c4ac0c5Sdrh} {1 1 2 2 3 3 12 101 13 102 16 103} 3777c4ac0c5Sdrhdo_test insert-9.2 { 3787c4ac0c5Sdrh execsql { 3797c4ac0c5Sdrh CREATE TABLE t6(x INTEGER PRIMARY KEY, y); 3807c4ac0c5Sdrh INSERT INTO t6 VALUES(1,1); 3817c4ac0c5Sdrh INSERT INTO t6 VALUES(2,2); 3827c4ac0c5Sdrh INSERT INTO t6 VALUES(3,3); 3837c4ac0c5Sdrh INSERT INTO t6 SELECT nullif(y*2+10,14), y+100 FROM t6; 3847c4ac0c5Sdrh SELECT x, y FROM t6; 3857c4ac0c5Sdrh } 3867c4ac0c5Sdrh} {1 1 2 2 3 3 12 101 13 102 16 103} 38738fba691Sdrh 3887b113babSdrh# Multiple VALUES clauses 3897b113babSdrh# 3902f56da3fSdanifcapable compound { 3917b113babSdrh do_test insert-10.1 { 3927b113babSdrh execsql { 3937b113babSdrh CREATE TABLE t10(a,b,c); 3947b113babSdrh INSERT INTO t10 VALUES(1,2,3), (4,5,6), (7,8,9); 3957b113babSdrh SELECT * FROM t10; 3967b113babSdrh } 3977b113babSdrh } {1 2 3 4 5 6 7 8 9} 3987b113babSdrh do_test insert-10.2 { 3997b113babSdrh catchsql { 40005a86c5cSdrh INSERT INTO t10 VALUES(11,12,13), (14,15), (16,17,28); 4017b113babSdrh } 4027b113babSdrh } {1 {all VALUES must have the same number of terms}} 4032f56da3fSdan} 4047b113babSdrh 4058be09304Sdrh# Need for the OP_SoftNull opcode 4068be09304Sdrh# 4078be09304Sdrhdo_execsql_test insert-11.1 { 4088be09304Sdrh CREATE TABLE t11a AS SELECT '123456789' AS x; 4098be09304Sdrh CREATE TABLE t11b (a INTEGER PRIMARY KEY, b, c); 4108be09304Sdrh INSERT INTO t11b SELECT x, x, x FROM t11a; 4118be09304Sdrh SELECT quote(a), quote(b), quote(c) FROM t11b; 4128be09304Sdrh} {123456789 '123456789' '123456789'} 4138be09304Sdrh 4148be09304Sdrh 415e48ae715Sdrh# More columns of input than there are columns in the table. 416e48ae715Sdrh# Ticket http://www.sqlite.org/src/info/e9654505cfda9361 417e48ae715Sdrh# 418e48ae715Sdrhdo_execsql_test insert-12.1 { 419e48ae715Sdrh CREATE TABLE t12a(a,b,c,d,e,f,g); 420e48ae715Sdrh INSERT INTO t12a VALUES(101,102,103,104,105,106,107); 421e48ae715Sdrh CREATE TABLE t12b(x); 422e48ae715Sdrh INSERT INTO t12b(x,rowid,x,x,x,x,x) SELECT * FROM t12a; 423e48ae715Sdrh SELECT rowid, x FROM t12b; 424e48ae715Sdrh} {102 101} 425e48ae715Sdrhdo_execsql_test insert-12.2 { 426e48ae715Sdrh CREATE TABLE tab1( value INTEGER); 427e48ae715Sdrh INSERT INTO tab1 (value, _rowid_) values( 11, 1); 428e48ae715Sdrh INSERT INTO tab1 (value, _rowid_) SELECT 22,999; 429e48ae715Sdrh SELECT * FROM tab1; 430e48ae715Sdrh} {11 22} 431e48ae715Sdrhdo_execsql_test insert-12.3 { 432e48ae715Sdrh CREATE TABLE t12c(a, b DEFAULT 'xyzzy', c); 433e48ae715Sdrh INSERT INTO t12c(a, rowid, c) SELECT 'one', 999, 'two'; 434e48ae715Sdrh SELECT * FROM t12c; 435e48ae715Sdrh} {one xyzzy two} 436e48ae715Sdrh 437ea647159Sdrh# 2018-06-11. From OSSFuzz. A column cache malfunction in 438ea647159Sdrh# the constraint checking on an index of expressions causes 439ea647159Sdrh# an assertion fault in a REPLACE. Ticket 440ea647159Sdrh# https://www.sqlite.org/src/info/c2432ef9089ee73b 441ea647159Sdrh# 442ea647159Sdrhdo_execsql_test insert-13.1 { 443ea647159Sdrh DROP TABLE IF EXISTS t13; 444ea647159Sdrh CREATE TABLE t13(a INTEGER PRIMARY KEY,b UNIQUE); 445ea647159Sdrh CREATE INDEX t13x1 ON t13(-b=b); 446ea647159Sdrh INSERT INTO t13 VALUES(1,5),(6,2); 447ea647159Sdrh REPLACE INTO t13 SELECT b,0 FROM t13; 448ea647159Sdrh SELECT * FROM t13 ORDER BY +b; 449ea647159Sdrh} {2 0 6 2 1 5} 450e48ae715Sdrh 45104fcef00Sdrh# 2019-01-17. From the chromium fuzzer. 45204fcef00Sdrh# 45304fcef00Sdrhdo_execsql_test insert-14.1 { 45404fcef00Sdrh DROP TABLE IF EXISTS t14; 45504fcef00Sdrh CREATE TABLE t14(x INTEGER PRIMARY KEY); 45604fcef00Sdrh INSERT INTO t14 VALUES(CASE WHEN 1 THEN null END); 45704fcef00Sdrh SELECT x FROM t14; 45804fcef00Sdrh} {1} 45904fcef00Sdrh 4602da8d6feSdrhintegrity_check insert-14.2 461ed717fe3Sdrh 462554a19dbSdrh# 2019-08-12. 463554a19dbSdrh# 464554a19dbSdrhdo_execsql_test insert-15.1 { 465554a19dbSdrh DROP TABLE IF EXISTS t1; 466554a19dbSdrh DROP TABLE IF EXISTS t2; 467554a19dbSdrh CREATE TABLE t1(a INTEGER PRIMARY KEY, b TEXT); 468554a19dbSdrh CREATE INDEX i1 ON t1(b); 469554a19dbSdrh CREATE TABLE t2(a, b); 470554a19dbSdrh INSERT INTO t2 VALUES(4, randomblob(31000)); 471554a19dbSdrh INSERT INTO t2 VALUES(4, randomblob(32000)); 472554a19dbSdrh INSERT INTO t2 VALUES(4, randomblob(33000)); 473554a19dbSdrh REPLACE INTO t1 SELECT a, b FROM t2; 474554a19dbSdrh SELECT a, length(b) FROM t1; 475554a19dbSdrh} {4 33000} 476554a19dbSdrh 4772da8d6feSdrh# 2019-10-16 4782da8d6feSdrh# ticket https://www.sqlite.org/src/info/a8a4847a2d96f5de 4792da8d6feSdrh# On a REPLACE INTO, if an AFTER trigger adds back the conflicting 4802da8d6feSdrh# row, you can end up with the wrong number of rows in an index. 4812da8d6feSdrh# 4822da8d6feSdrhdb close 4832da8d6feSdrhsqlite3 db :memory: 4842da8d6feSdrhdo_catchsql_test insert-16.1 { 4852da8d6feSdrh PRAGMA recursive_triggers = true; 4862da8d6feSdrh CREATE TABLE t0(c0,c1); 4872da8d6feSdrh CREATE UNIQUE INDEX i0 ON t0(c0); 4882da8d6feSdrh INSERT INTO t0(c0,c1) VALUES(123,1); 4892da8d6feSdrh CREATE TRIGGER tr0 AFTER DELETE ON t0 4902da8d6feSdrh BEGIN 4912da8d6feSdrh INSERT INTO t0 VALUES(123,2); 4922da8d6feSdrh END; 4932da8d6feSdrh REPLACE INTO t0(c0,c1) VALUES(123,3); 4942da8d6feSdrh} {1 {UNIQUE constraint failed: t0.c0}} 4952da8d6feSdrhdo_execsql_test insert-16.2 { 4962da8d6feSdrh SELECT * FROM t0; 4972da8d6feSdrh} {123 1} 4982da8d6feSdrhintegrity_check insert-16.3 4992da8d6feSdrhdo_catchsql_test insert-16.4 { 5002da8d6feSdrh CREATE TABLE t1(a INTEGER PRIMARY KEY, b); 5012da8d6feSdrh CREATE INDEX t1b ON t1(b); 5022da8d6feSdrh INSERT INTO t1 VALUES(1, 'one'); 5032da8d6feSdrh CREATE TRIGGER tr3 AFTER DELETE ON t1 BEGIN 5042da8d6feSdrh INSERT INTO t1 VALUES(1, 'three'); 5052da8d6feSdrh END; 5062da8d6feSdrh REPLACE INTO t1 VALUES(1, 'two'); 5072da8d6feSdrh} {1 {UNIQUE constraint failed: t1.a}} 5082da8d6feSdrhintegrity_check insert-16.5 5092da8d6feSdrhdo_catchsql_test insert-16.6 { 5102da8d6feSdrh PRAGMA foreign_keys = 1; 5112da8d6feSdrh CREATE TABLE p1(a, b UNIQUE); 5122da8d6feSdrh CREATE TABLE c1(c, d REFERENCES p1(b) ON DELETE CASCADE); 5132da8d6feSdrh CREATE TRIGGER tr6 AFTER DELETE ON c1 BEGIN 5142da8d6feSdrh INSERT INTO p1 VALUES(4, 1); 5152da8d6feSdrh END; 5162da8d6feSdrh INSERT INTO p1 VALUES(1, 1); 5172da8d6feSdrh INSERT INTO c1 VALUES(2, 1); 518*0660884eSdrh REPLACE INTO p1 VALUES(3, 1);2 5192da8d6feSdrh} {1 {UNIQUE constraint failed: p1.b}} 5202da8d6feSdrhintegrity_check insert-16.7 5212da8d6feSdrh 522a407eccbSdrh# 2019-10-25 ticket c1e19e12046d23fe 523a407eccbSdrhdo_catchsql_test insert-17.1 { 524a407eccbSdrh PRAGMA temp.recursive_triggers = true; 525a407eccbSdrh DROP TABLE IF EXISTS t0; 526a407eccbSdrh CREATE TABLE t0(aa, bb); 527a407eccbSdrh CREATE UNIQUE INDEX t0bb ON t0(bb); 528a407eccbSdrh CREATE TRIGGER "r17.1" BEFORE DELETE ON t0 529a407eccbSdrh BEGIN INSERT INTO t0(aa,bb) VALUES(99,1); 530a407eccbSdrh END; 531a407eccbSdrh INSERT INTO t0(aa,bb) VALUES(10,20); 532a407eccbSdrh REPLACE INTO t0(aa,bb) VALUES(30,20); 533a407eccbSdrh} {1 {UNIQUE constraint failed: t0.rowid}} 534a407eccbSdrhintegrity_check insert-17.2 535a407eccbSdrhdo_catchsql_test insert-17.3 { 536a407eccbSdrh DROP TABLE IF EXISTS t1; 537a407eccbSdrh CREATE TABLE t1(a, b UNIQUE, c UNIQUE); 538a407eccbSdrh INSERT INTO t1(a,b,c) VALUES(1,1,1),(2,2,2),(3,3,3),(4,4,4); 539a407eccbSdrh CREATE TRIGGER "r17.3" AFTER DELETE ON t1 WHEN OLD.c<>3 BEGIN 540a407eccbSdrh INSERT INTO t1(rowid,a,b,c) VALUES(100,100,100,3); 541a407eccbSdrh END; 542a407eccbSdrh REPLACE INTO t1(rowid,a,b,c) VALUES(200,1,2,3); 543a407eccbSdrh} {1 {UNIQUE constraint failed: t1.c}} 544a407eccbSdrhintegrity_check insert-17.4 545*0660884eSdrhdo_execsql_test insert-17.5 { 546*0660884eSdrh CREATE TABLE t2(a INTEGER PRIMARY KEY, b); 547*0660884eSdrh CREATE UNIQUE INDEX t2b ON t2(b); 548*0660884eSdrh INSERT INTO t2(a,b) VALUES(1,1),(2,2),(3,3),(4,4); 549*0660884eSdrh CREATE TABLE fire(x); 550*0660884eSdrh CREATE TRIGGER t2r1 AFTER DELETE ON t2 BEGIN 551*0660884eSdrh INSERT INTO fire VALUES(old.a); 552*0660884eSdrh END; 553*0660884eSdrh UPDATE OR REPLACE t2 SET a=4, b=3 WHERE a=1; 554*0660884eSdrh SELECT *, 'x' FROM t2 ORDER BY a; 555*0660884eSdrh} {2 2 x 4 3 x} 556*0660884eSdrhdo_execsql_test insert-17.6 { 557*0660884eSdrh SELECT x FROM fire ORDER BY x; 558*0660884eSdrh} {3 4} 559*0660884eSdrhdo_execsql_test insert-17.7 { 560*0660884eSdrh DELETE FROM t2; 561*0660884eSdrh DELETE FROM fire; 562*0660884eSdrh INSERT INTO t2(a,b) VALUES(1,1),(2,2),(3,3),(4,4); 563*0660884eSdrh UPDATE OR REPLACE t2 SET a=1, b=3 WHERE a=1; 564*0660884eSdrh SELECT *, 'x' FROM t2 ORDER BY a; 565*0660884eSdrh} {1 3 x 2 2 x 4 4 x} 566*0660884eSdrhdo_execsql_test insert-17.8 { 567*0660884eSdrh SELECT x FROM fire ORDER BY x; 568*0660884eSdrh} {3} 569*0660884eSdrhdo_execsql_test insert-17.10 { 570*0660884eSdrh CREATE TABLE t3(a INTEGER PRIMARY KEY, b INT, c INT, d INT); 571*0660884eSdrh CREATE UNIQUE INDEX t3bpi ON t3(b) WHERE c<=d; 572*0660884eSdrh CREATE UNIQUE INDEX t3d ON t3(d); 573*0660884eSdrh INSERT INTO t3(a,b,c,d) VALUES(1,1,1,1),(2,1,3,2),(3,4,5,6); 574*0660884eSdrh CREATE TRIGGER t3r1 AFTER DELETE ON t3 BEGIN 575*0660884eSdrh SELECT 'hi'; 576*0660884eSdrh END; 577*0660884eSdrh REPLACE INTO t3(a,b,c,d) VALUES(4,4,8,9); 578*0660884eSdrh} {} 579*0660884eSdrhdo_execsql_test insert-17.11 { 580*0660884eSdrh SELECT *, 'x' FROM t3 ORDER BY a; 581*0660884eSdrh} {1 1 1 1 x 2 1 3 2 x 4 4 8 9 x} 582*0660884eSdrhdo_execsql_test insert-17.12 { 583*0660884eSdrh REPLACE INTO t3(a,b,c,d) VALUES(5,1,11,2); 584*0660884eSdrh SELECT *, 'x' FROM t3 ORDER BY a; 585*0660884eSdrh} {1 1 1 1 x 4 4 8 9 x 5 1 11 2 x} 586*0660884eSdrh 587*0660884eSdrhdo_execsql_test insert-17.13 { 588*0660884eSdrh DELETE FROM t3; 589*0660884eSdrh INSERT INTO t3(a,b,c,d) VALUES(1,1,1,1),(2,1,3,2),(3,4,5,6); 590*0660884eSdrh DROP TRIGGER t3r1; 591*0660884eSdrh CREATE TRIGGER t3r1 AFTER DELETE ON t3 BEGIN 592*0660884eSdrh INSERT INTO t3(b,c,d) VALUES(old.b,old.c,old.d); 593*0660884eSdrh END; 594*0660884eSdrh} {} 595*0660884eSdrhdo_catchsql_test insert-17.14 { 596*0660884eSdrh REPLACE INTO t3(a,b,c,d) VALUES(4,4,8,9); 597*0660884eSdrh} {1 {UNIQUE constraint failed: t3.b}} 598*0660884eSdrhdo_catchsql_test insert-17.15 { 599*0660884eSdrh REPLACE INTO t3(a,b,c,d) VALUES(5,1,11,2); 600*0660884eSdrh} {1 {UNIQUE constraint failed: t3.d}} 6012da8d6feSdrh 602554a19dbSdrh 60362c68191Sdrhfinish_test 604