1f0ee1d3cSdan# 2005 August 24 2f0ee1d3cSdan# 3f0ee1d3cSdan# The author disclaims copyright to this source code. In place of 4f0ee1d3cSdan# a legal notice, here is a blessing: 5f0ee1d3cSdan# 6f0ee1d3cSdan# May you do good and not evil. 7f0ee1d3cSdan# May you find forgiveness for yourself and forgive others. 8f0ee1d3cSdan# May you share freely, never taking more than you give. 9f0ee1d3cSdan# 10f0ee1d3cSdan#*********************************************************************** 11f0ee1d3cSdan# This file implements regression tests for SQLite library. The 12f0ee1d3cSdan# focus of this script is a test of the DELETE command. 13f0ee1d3cSdan# 14f0ee1d3cSdan 15f0ee1d3cSdanset testdir [file dirname $argv0] 16f0ee1d3cSdansource $testdir/tester.tcl 17f0ee1d3cSdanset testprefix delete4 18f0ee1d3cSdan 19f0ee1d3cSdando_execsql_test 1.1 { 20f0ee1d3cSdan CREATE TABLE t1(x INTEGER PRIMARY KEY, y); 21f0ee1d3cSdan INSERT INTO t1 VALUES(1, 0); 22f0ee1d3cSdan INSERT INTO t1 VALUES(2, 1); 23f0ee1d3cSdan INSERT INTO t1 VALUES(3, 0); 24f0ee1d3cSdan INSERT INTO t1 VALUES(4, 1); 25f0ee1d3cSdan INSERT INTO t1 VALUES(5, 0); 26f0ee1d3cSdan INSERT INTO t1 VALUES(6, 1); 27f0ee1d3cSdan INSERT INTO t1 VALUES(7, 0); 28f0ee1d3cSdan INSERT INTO t1 VALUES(8, 1); 29f0ee1d3cSdan} 30f0ee1d3cSdando_execsql_test 1.2 { 31f0ee1d3cSdan DELETE FROM t1 WHERE y=1; 32f0ee1d3cSdan} 33f0ee1d3cSdando_execsql_test 1.3 { 34f0ee1d3cSdan SELECT x FROM t1; 35f0ee1d3cSdan} {1 3 5 7} 36f0ee1d3cSdan 37f0ee1d3cSdan#------------------------------------------------------------------------- 38f0ee1d3cSdan# 39f0ee1d3cSdanreset_db 40f0ee1d3cSdando_execsql_test 2.1 { 41f0ee1d3cSdan CREATE TABLE t1(x INTEGER PRIMARY KEY, y, z); 42f0ee1d3cSdan INSERT INTO t1 VALUES(1, 0, randomblob(200)); 43f0ee1d3cSdan INSERT INTO t1 VALUES(2, 1, randomblob(200)); 44f0ee1d3cSdan INSERT INTO t1 VALUES(3, 0, randomblob(200)); 45f0ee1d3cSdan INSERT INTO t1 VALUES(4, 1, randomblob(200)); 46f0ee1d3cSdan INSERT INTO t1 VALUES(5, 0, randomblob(200)); 47f0ee1d3cSdan INSERT INTO t1 VALUES(6, 1, randomblob(200)); 48f0ee1d3cSdan INSERT INTO t1 VALUES(7, 0, randomblob(200)); 49f0ee1d3cSdan INSERT INTO t1 VALUES(8, 1, randomblob(200)); 50f0ee1d3cSdan} 51f0ee1d3cSdando_execsql_test 2.2 { 52f0ee1d3cSdan DELETE FROM t1 WHERE y=1; 53f0ee1d3cSdan} 54f0ee1d3cSdando_execsql_test 2.3 { 55f0ee1d3cSdan SELECT x FROM t1; 56f0ee1d3cSdan} {1 3 5 7} 57f0ee1d3cSdan 58f0ee1d3cSdan 59f0ee1d3cSdan#------------------------------------------------------------------------- 60f0ee1d3cSdan# 61f0ee1d3cSdanreset_db 62*a6df0e69Sdrhdo_execsql_test 3.0.1 { 63f0ee1d3cSdan CREATE TABLE t1(a, b, PRIMARY KEY(a, b)) WITHOUT ROWID; 64f0ee1d3cSdan INSERT INTO t1 VALUES(1, 2); 65f0ee1d3cSdan INSERT INTO t1 VALUES(2, 4); 66f0ee1d3cSdan INSERT INTO t1 VALUES(1, 5); 67f0ee1d3cSdan DELETE FROM t1 WHERE a=1; 68*a6df0e69Sdrh SELECT printf('(%d)',changes()); 69f0ee1d3cSdan SELECT * FROM t1; 70*a6df0e69Sdrh} {(2) 2 4} 71*a6df0e69Sdrhdo_execsql_test 3.0.2 { 72*a6df0e69Sdrh WITH RECURSIVE c(x) AS (VALUES(1) UNION ALL SELECT x+1 FROM c WHERE x<100) 73*a6df0e69Sdrh INSERT INTO t1(a,b) SELECT x, x+1 FROM c; 74*a6df0e69Sdrh SELECT printf('(%d)',changes()); 75*a6df0e69Sdrh DELETE FROM t1; 76*a6df0e69Sdrh SELECT printf('(%d)',changes()); 77*a6df0e69Sdrh} {(100) (101)} 78f0ee1d3cSdan 79f0ee1d3cSdan#------------------------------------------------------------------------- 80f0ee1d3cSdan# DELETE statement that uses the OR optimization 81f0ee1d3cSdan# 82f0ee1d3cSdanreset_db 83f0ee1d3cSdando_execsql_test 3.1 { 84f0ee1d3cSdan CREATE TABLE t1(i INTEGER PRIMARY KEY, a, b); 85f0ee1d3cSdan CREATE INDEX i1a ON t1(a); 86f0ee1d3cSdan CREATE INDEX i1b ON t1(b); 87f0ee1d3cSdan INSERT INTO t1 VALUES(1, 'one', 'i'); 88f0ee1d3cSdan INSERT INTO t1 VALUES(2, 'two', 'ii'); 89f0ee1d3cSdan INSERT INTO t1 VALUES(3, 'three', 'iii'); 90f0ee1d3cSdan INSERT INTO t1 VALUES(4, 'four', 'iv'); 91f0ee1d3cSdan INSERT INTO t1 VALUES(5, 'one', 'i'); 92f0ee1d3cSdan INSERT INTO t1 VALUES(6, 'two', 'ii'); 93f0ee1d3cSdan INSERT INTO t1 VALUES(7, 'three', 'iii'); 94f0ee1d3cSdan INSERT INTO t1 VALUES(8, 'four', 'iv'); 95f0ee1d3cSdan} {} 96f0ee1d3cSdan 97f0ee1d3cSdando_execsql_test 3.2 { 98f0ee1d3cSdan DELETE FROM t1 WHERE a='two' OR b='iv'; 99f0ee1d3cSdan} 100f0ee1d3cSdan 101f0ee1d3cSdando_execsql_test 3.3 { 102f0ee1d3cSdan SELECT i FROM t1 ORDER BY i; 103f0ee1d3cSdan} {1 3 5 7} 104f0ee1d3cSdan 105f0ee1d3cSdando_execsql_test 3.4 { 106f0ee1d3cSdan PRAGMA integrity_check; 107f0ee1d3cSdan} {ok} 108f0ee1d3cSdan 1093169713bSdrh# Between 2015-09-14 and 2015-09-28, the following test cases would result 1103169713bSdrh# in corruption (wrong # of entries in index) due to a bug in the ONEPASS 1113169713bSdrh# optimization. 1123169713bSdrh# 1133169713bSdrhdo_execsql_test 4.1 { 1143169713bSdrh DROP TABLE IF EXISTS t4; 1153169713bSdrh CREATE TABLE t4(col0, col1); 1163169713bSdrh INSERT INTO "t4" VALUES(14, 'abcde'); 1173169713bSdrh CREATE INDEX idx_t4_0 ON t4 (col1, col0); 1183169713bSdrh CREATE INDEX idx_t4_3 ON t4 (col0); 1193169713bSdrh DELETE FROM t4 WHERE col0=69 OR col0>7; 1203169713bSdrh PRAGMA integrity_check; 1213169713bSdrh} {ok} 1223169713bSdrhdo_execsql_test 4.2 { 1233169713bSdrh DROP TABLE IF EXISTS t4; 1243169713bSdrh CREATE TABLE t4(col0, col1); 1253169713bSdrh INSERT INTO "t4" VALUES(14, 'abcde'); 1263169713bSdrh CREATE INDEX idx_t4_3 ON t4 (col0); 1273169713bSdrh CREATE INDEX idx_t4_0 ON t4 (col1, col0); 1283169713bSdrh DELETE FROM t4 WHERE col0=69 OR col0>7; 1293169713bSdrh PRAGMA integrity_check; 1303169713bSdrh} {ok} 1313169713bSdrhdo_execsql_test 4.11 { 1323169713bSdrh DROP TABLE IF EXISTS t4; 1333169713bSdrh CREATE TABLE t4(col0, col1, pk PRIMARY KEY) WITHOUT ROWID; 1343169713bSdrh INSERT INTO t4 VALUES(14, 'abcde','xyzzy'); 1353169713bSdrh CREATE INDEX idx_t4_0 ON t4 (col1, col0); 1363169713bSdrh CREATE INDEX idx_t4_3 ON t4 (col0); 1373169713bSdrh DELETE FROM t4 WHERE col0=69 OR col0>7; 1383169713bSdrh PRAGMA integrity_check; 1393169713bSdrh} {ok} 1403169713bSdrhdo_execsql_test 4.12 { 1413169713bSdrh DROP TABLE IF EXISTS t4; 1423169713bSdrh CREATE TABLE t4(col0, col1, pk PRIMARY KEY) WITHOUT ROWID; 1433169713bSdrh INSERT INTO t4 VALUES(14, 'abcde','xyzzy'); 1443169713bSdrh CREATE INDEX idx_t4_3 ON t4 (col0); 1453169713bSdrh CREATE INDEX idx_t4_0 ON t4 (col1, col0); 1463169713bSdrh DELETE FROM t4 WHERE col0=69 OR col0>7; 1473169713bSdrh PRAGMA integrity_check; 1483169713bSdrh} {ok} 1493169713bSdrh 150bfc7a8bbSdrh# 2016-04-09 151bfc7a8bbSdrh# Ticket https://sqlite.org/src/info/a306e56ff68b8fa5 152bfc7a8bbSdrh# Failure to completely delete when reverse_unordered_selects is 153bfc7a8bbSdrh# engaged. 154bfc7a8bbSdrh# 155bfc7a8bbSdrhdb close 156bfc7a8bbSdrhforcedelete test.db 157bfc7a8bbSdrhsqlite3 db test.db 158bfc7a8bbSdrhdo_execsql_test 5.0 { 159bfc7a8bbSdrh PRAGMA page_size=1024; 160bfc7a8bbSdrh CREATE TABLE t1(a INTEGER PRIMARY KEY, b, c); 161bfc7a8bbSdrh CREATE INDEX x1 ON t1(b, c); 162bfc7a8bbSdrh INSERT INTO t1(a,b,c) VALUES(1, 1, zeroblob(80)); 163bfc7a8bbSdrh INSERT INTO t1(a,b,c) SELECT a+1, 1, c FROM t1; 164bfc7a8bbSdrh INSERT INTO t1(a,b,c) SELECT a+2, 1, c FROM t1; 165bfc7a8bbSdrh INSERT INTO t1(a,b,c) SELECT a+10, 2, c FROM t1 WHERE b=1; 166bfc7a8bbSdrh INSERT INTO t1(a,b,c) SELECT a+20, 3, c FROM t1 WHERE b=1; 167bfc7a8bbSdrh PRAGMA reverse_unordered_selects = ON; 168bfc7a8bbSdrh DELETE FROM t1 WHERE b=2; 169bfc7a8bbSdrh SELECT a FROM t1 WHERE b=2; 170bfc7a8bbSdrh} {} 171f0ee1d3cSdan 17257a07ba9Sdrh# 2016-05-02 17357a07ba9Sdrh# Ticket https://www.sqlite.org/src/tktview/dc6ebeda93960877 17457a07ba9Sdrh# A subquery in the WHERE clause of a one-pass DELETE can cause an 17557a07ba9Sdrh# incorrect answer. 17657a07ba9Sdrh# 17757a07ba9Sdrhdb close 17857a07ba9Sdrhforcedelete test.db 17957a07ba9Sdrhsqlite3 db test.db 18057a07ba9Sdrhdo_execsql_test 6.0 { 18157a07ba9Sdrh CREATE TABLE t2(x INT); 18257a07ba9Sdrh INSERT INTO t2(x) VALUES(1),(2),(3),(4),(5); 18357a07ba9Sdrh DELETE FROM t2 WHERE EXISTS(SELECT 1 FROM t2 AS v WHERE v.x=t2.x-1); 18457a07ba9Sdrh SELECT x FROM t2; 18557a07ba9Sdrh} {1} 18657a07ba9Sdrhdo_execsql_test 6.1 { 18757a07ba9Sdrh DROP TABLE IF EXISTS t2; 18857a07ba9Sdrh CREATE TABLE t2(x INT); 18957a07ba9Sdrh INSERT INTO t2(x) VALUES(1),(2),(3),(4),(5); 19057a07ba9Sdrh DELETE FROM t2 WHERE EXISTS(SELECT 1 FROM t2 AS v WHERE v.x=t2.x+1); 19157a07ba9Sdrh SELECT x FROM t2; 19257a07ba9Sdrh} {5} 19357a07ba9Sdrh 194b84b38fdSdan#------------------------------------------------------------------------- 195b84b38fdSdan# Test the effect of failing to find a table row based on an index key 196b84b38fdSdan# within a DELETE. Either because the db is corrupt, or a trigger on another 197b84b38fdSdan# row already deleted the entry, or because a BEFORE trigger on the current 198b84b38fdSdan# row has already deleted it. 199b84b38fdSdan# 200b84b38fdSdando_execsql_test 7.1.0 { 201b84b38fdSdan CREATE TABLE t3(id INT PRIMARY KEY, a, b) WITHOUT ROWID; 202b84b38fdSdan CREATE INDEX t3a ON t3(a); 203b84b38fdSdan CREATE INDEX t3b ON t3(b); 204b84b38fdSdan 205b84b38fdSdan INSERT INTO t3 VALUES(1, 1, 1); 206b84b38fdSdan INSERT INTO t3 VALUES(2, 2, 2); 207b84b38fdSdan INSERT INTO t3 VALUES(3, 3, 3); 208b84b38fdSdan INSERT INTO t3 VALUES(4, 4, 1); 209b84b38fdSdan} 210b84b38fdSdando_execsql_test 7.1.1 { 211b84b38fdSdan DELETE FROM t3 WHERE a=4 OR b=1; 212b84b38fdSdan} 213b84b38fdSdando_execsql_test 7.1.2 { 214b84b38fdSdan SELECT * FROM t3; 215b84b38fdSdan} { 2 2 2 3 3 3 } 216b84b38fdSdan 217b84b38fdSdando_execsql_test 7.2.0 { 218b84b38fdSdan CREATE TABLE t4(a PRIMARY KEY, b) WITHOUT ROWID; 219b84b38fdSdan CREATE INDEX t4i ON t4(b); 220b84b38fdSdan INSERT INTO t4 VALUES(1, 'hello'); 221b84b38fdSdan INSERT INTO t4 VALUES(2, 'world'); 222b84b38fdSdan 223b84b38fdSdan CREATE TABLE t5(a PRIMARY KEY, b) WITHOUT ROWID; 224b84b38fdSdan CREATE INDEX t5i ON t5(b); 225b84b38fdSdan INSERT INTO t5 VALUES(1, 'hello'); 226b84b38fdSdan INSERT INTO t5 VALUES(3, 'world'); 227b84b38fdSdan 228b84b38fdSdan PRAGMA writable_schema = 1; 229b84b38fdSdan UPDATE sqlite_master SET rootpage = ( 230b84b38fdSdan SELECT rootpage FROM sqlite_master WHERE name = 't5' 231b84b38fdSdan ) WHERE name = 't4'; 232b84b38fdSdan} 233b84b38fdSdan 234b84b38fdSdandb close 235b84b38fdSdansqlite3 db test.db 236b84b38fdSdando_execsql_test 7.2.1 { 237b84b38fdSdan DELETE FROM t4 WHERE b='world' 238b84b38fdSdan} 239b84b38fdSdanreset_db 240b84b38fdSdan 241b84b38fdSdando_execsql_test 7.3.0 { 242b84b38fdSdan CREATE TABLE t3(id INT PRIMARY KEY, a, b) WITHOUT ROWID; 243b84b38fdSdan INSERT INTO t3 VALUES(1, 2, 3); 244b84b38fdSdan INSERT INTO t3 VALUES(4, 5, 6); 245b84b38fdSdan INSERT INTO t3 VALUES(7, 8, 9); 246b84b38fdSdan CREATE TRIGGER t3t BEFORE DELETE ON t3 BEGIN 247b84b38fdSdan DELETE FROM t3 WHERE id=old.id+3; 248b84b38fdSdan END; 249b84b38fdSdan} 250b84b38fdSdan 251b84b38fdSdando_execsql_test 7.3.1 { 252b84b38fdSdan DELETE FROM t3 WHERE a IN(2, 5, 8); 253b84b38fdSdan SELECT * FROM t3; 254b84b38fdSdan} {} 255b84b38fdSdan 256b84b38fdSdando_execsql_test 7.3.2 { 257b84b38fdSdan DROP TRIGGER t3t; 258b84b38fdSdan INSERT INTO t3 VALUES(1, 2, 3); 259b84b38fdSdan INSERT INTO t3 VALUES(4, 5, 6); 260b84b38fdSdan INSERT INTO t3 VALUES(7, 8, 9); 261b84b38fdSdan CREATE TRIGGER t3t BEFORE DELETE ON t3 BEGIN 262b84b38fdSdan DELETE FROM t3 WHERE id=old.id; 263b84b38fdSdan END; 264b84b38fdSdan} 265b84b38fdSdan 266b84b38fdSdando_execsql_test 7.3.3 { 267b84b38fdSdan DELETE FROM t3 WHERE a IN(2, 5, 8); 268b84b38fdSdan SELECT * FROM t3; 269b84b38fdSdan} {} 270b84b38fdSdan 27157a07ba9Sdrh 272f0ee1d3cSdanfinish_test 273