3 # The author disclaims copyright to this source code. In place of
4 # a legal notice, here is a blessing:
6 # May you do good and not evil.
7 # May you find forgiveness for yourself and forgive others.
8 # May you share freely, never taking more than you give.
10 #***********************************************************************
13 source [file join [file dirname [info script]] rbu_common.tcl]
14 if_no_rbu_support { finish_test ; return }
19 # Create a simple RBU database. That expects to write to a table:
21 # CREATE TABLE t1(a INTEGER PRIMARY KEY, b, c);
23 proc create_rbu1 {filename} {
25 sqlite3 rbu1 $filename
27 CREATE TABLE data_t1(a, b, c, rbu_control);
28 INSERT INTO data_t1 VALUES(1, 2, 3, 0);
29 INSERT INTO data_t1 VALUES(2, 'two', 'three', 0);
30 INSERT INTO data_t1 VALUES(3, NULL, 8.2, 0);
36 # Create a simple RBU database. That expects to write to a table:
38 # CREATE TABLE t1(a INTEGER PRIMARY KEY, b, c);
40 # This RBU includes both insert and delete operations.
42 proc create_rbu4 {filename} {
44 sqlite3 rbu1 $filename
46 CREATE TABLE data_t1(a, b, c, rbu_control);
47 INSERT INTO data_t1 VALUES(1, 2, 3, 0);
48 INSERT INTO data_t1 VALUES(2, NULL, 5, 1);
49 INSERT INTO data_t1 VALUES(3, 8, 9, 0);
50 INSERT INTO data_t1 VALUES(4, NULL, 11, 1);
56 # Create a simple RBU database. That expects to write to a table:
58 # CREATE TABLE t1(c, b, '(a)' INTEGER PRIMARY KEY);
60 # This RBU includes both insert and delete operations.
62 proc create_rbu4b {filename} {
64 sqlite3 rbu1 $filename
66 CREATE TABLE data_t1(c, b, '(a)', rbu_control);
67 INSERT INTO data_t1 VALUES(3, 2, 1, 0);
68 INSERT INTO data_t1 VALUES(5, NULL, 2, 1);
69 INSERT INTO data_t1 VALUES(9, 8, 3, 0);
70 INSERT INTO data_t1 VALUES(11, NULL, 4, 1);
76 # Create a simple RBU database. That expects to write to a table:
78 # CREATE TABLE t1(a INTEGER PRIMARY KEY, b, c, d);
80 # This RBU includes update statements.
82 proc create_rbu5 {filename} {
84 sqlite3 rbu5 $filename
86 CREATE TABLE data_t1(a, b, c, d, rbu_control);
87 INSERT INTO data_t1 VALUES(1, NULL, NULL, 5, '...x'); -- SET d = 5
88 INSERT INTO data_t1 VALUES(2, NULL, 10, 5, '..xx'); -- SET c=10, d = 5
89 INSERT INTO data_t1 VALUES(3, 11, NULL, NULL, '.x..'); -- SET b=11
96 # Same as [step_rbu], except using a URI to open the target db.
98 proc step_rbu_uri {target rbu} {
100 sqlite3rbu rbu file:$target?xyz=&abc=123 $rbu
103 if {$rc != "SQLITE_OK"} break
108 # Same as [step_rbu], except using an external state database - "state.db"
110 proc step_rbu_state {target rbu} {
112 sqlite3rbu rbu $target $rbu state.db
115 if {$rc != "SQLITE_OK"} break
120 proc dbfilecksum {file} {
122 set cksum [dbcksum ck main]
127 foreach {tn3 create_vfs destroy_vfs} {
130 sqlite3rbu_create_vfs -default myrbu ""
132 sqlite3rbu_destroy_vfs myrbu
135 sqlite3_register_cksumvfs
137 sqlite3_unregister_cksumvfs
145 2 step_rbu 3 step_rbu_uri 4 step_rbu_state
148 foreach {tn schema} {
150 CREATE TABLE t1(a INTEGER PRIMARY KEY, b, c);
153 CREATE TABLE t1(a INTEGER PRIMARY KEY, b, c);
154 CREATE INDEX i1 ON t1(b);
157 CREATE TABLE t1(a PRIMARY KEY, b, c) WITHOUT ROWID;
160 CREATE TABLE t1(a PRIMARY KEY, b, c) WITHOUT ROWID;
161 CREATE INDEX i1 ON t1(b);
164 CREATE TABLE t1(a, b, c, PRIMARY KEY(a, c)) WITHOUT ROWID;
165 CREATE INDEX i1 ON t1(b);
168 CREATE TABLE t1(a, b, c, PRIMARY KEY(c)) WITHOUT ROWID;
169 CREATE INDEX i1 ON t1(b, a);
172 CREATE TABLE t1(a INTEGER PRIMARY KEY, b, c);
173 CREATE INDEX i1 ON t1(b, c);
174 CREATE INDEX i2 ON t1(c, b);
175 CREATE INDEX i3 ON t1(a, b, c, a, b, c);
179 CREATE TABLE t1(a PRIMARY KEY, b, c);
180 CREATE INDEX i1 ON t1(b, c);
181 CREATE INDEX i2 ON t1(c, b);
182 CREATE INDEX i3 ON t1(a, b, c, a, b, c);
186 CREATE TABLE t1(a, b, c, PRIMARY KEY(a, c));
187 CREATE INDEX i1 ON t1(b);
191 CREATE TABLE t1(a INTEGER PRIMARY KEY, b, c);
192 CREATE INDEX i1 ON t1(b DESC);
196 CREATE TABLE t1(a INTEGER PRIMARY KEY, b, c);
197 CREATE INDEX i1 ON t1(b DESC, a ASC, c DESC);
201 CREATE TABLE t1(a INT PRIMARY KEY DESC, b, c) WITHOUT ROWID;
205 CREATE TABLE t1(a INT, b, c, PRIMARY KEY(a DESC)) WITHOUT ROWID;
209 CREATE TABLE t1(a, b, c, PRIMARY KEY(a DESC, c)) WITHOUT ROWID;
210 CREATE INDEX i1 ON t1(b);
214 CREATE TABLE t1(a, b, c, PRIMARY KEY(a, c DESC)) WITHOUT ROWID;
215 CREATE INDEX i1 ON t1(b);
219 CREATE TABLE t1(a, b, c, PRIMARY KEY(c DESC, a)) WITHOUT ROWID;
220 CREATE INDEX i1 ON t1(b DESC, c, a);
226 set check [dbfilecksum rbu.db]
229 do_test $tn3.1.$tn2.$tn.1 {
233 do_execsql_test $tn3.1.$tn2.$tn.2 { SELECT * FROM t1 ORDER BY a ASC } {
238 do_execsql_test $tn3.1.$tn2.$tn.3 { SELECT * FROM t1 ORDER BY b ASC } {
243 do_execsql_test $tn3.1.$tn2.$tn.4 { SELECT * FROM t1 ORDER BY c ASC } {
249 do_execsql_test $tn3.1.$tn2.$tn.5 { PRAGMA integrity_check } ok
251 if {$cmd=="step_rbu_state"} {
252 do_test $tn3.1.$tn2.$tn.6 { file exists state.db } 1
253 do_test $tn3.1.$tn2.$tn.7 { expr {$check == [dbfilecksum rbu.db]} } 1
255 do_test $tn3.1.$tn2.$tn.8 { file exists state.db } 0
256 do_test $tn3.1.$tn2.$tn.9 { expr {$check == [dbfilecksum rbu.db]} } 0
261 #-------------------------------------------------------------------------
262 # Check that an RBU cannot be applied to a table that has no PK.
264 # UPDATE: At one point RBU required that all tables featured either
265 # explicit IPK columns or were declared WITHOUT ROWID. This has been
266 # relaxed so that external PRIMARY KEYs on tables with automatic rowids
269 # UPDATE 2: Tables without any PRIMARY KEY declaration are now allowed.
270 # However the input table must feature an "rbu_rowid" column.
274 do_execsql_test $tn3.2.1 { CREATE TABLE t1(a, b, c) }
276 sqlite3rbu rbu test.db rbu.db
280 list [catch { rbu close } msg] $msg
281 } {1 {SQLITE_ERROR - table data_t1 requires rbu_rowid column}}
283 do_execsql_test $tn3.2.4 { CREATE TABLE t1(a PRIMARY KEY, b, c) }
285 sqlite3rbu rbu test.db rbu.db
289 list [catch { rbu close } msg] $msg
292 #-------------------------------------------------------------------------
293 # Check that if a UNIQUE constraint is violated the current and all
294 # subsequent [rbu step] calls return SQLITE_CONSTRAINT. And that the RBU
295 # transaction is rolled back by the [rbu close] that deletes the rbu
298 foreach {tn errcode errmsg schema} {
299 1 SQLITE_CONSTRAINT "UNIQUE constraint failed: t1.a" {
300 CREATE TABLE t1(a INTEGER PRIMARY KEY, b, c);
301 INSERT INTO t1 VALUES(3, 2, 1);
304 2 SQLITE_CONSTRAINT "UNIQUE constraint failed: t1.c" {
305 CREATE TABLE t1(a INTEGER PRIMARY KEY, b, c UNIQUE);
306 INSERT INTO t1 VALUES(4, 2, 'three');
309 3 SQLITE_CONSTRAINT "UNIQUE constraint failed: t1.a" {
310 CREATE TABLE t1(a PRIMARY KEY, b, c);
311 INSERT INTO t1 VALUES(3, 2, 1);
314 4 SQLITE_CONSTRAINT "UNIQUE constraint failed: t1.c" {
315 CREATE TABLE t1(a PRIMARY KEY, b, c UNIQUE);
316 INSERT INTO t1 VALUES(4, 2, 'three');
322 set cksum [dbcksum db main]
324 do_test $tn3.3.$tn.1 {
326 sqlite3rbu rbu test.db rbu.db
327 while {[set res [rbu step]]=="SQLITE_OK"} {}
331 do_test $tn3.3.$tn.2 { rbu step } $errcode
333 do_test $tn3.3.$tn.3 {
334 list [catch { rbu close } msg] $msg
335 } [list 1 "$errcode - $errmsg"]
337 do_test $tn3.3.$tn.4 { dbcksum db main } $cksum
340 #-------------------------------------------------------------------------
342 foreach {tn2 cmd} {1 run_rbu 2 step_rbu 3 step_rbu_state } {
343 foreach {tn schema} {
345 CREATE TABLE t1(a INTEGER PRIMARY KEY, b, c);
348 CREATE TABLE t1(a INTEGER PRIMARY KEY, b, c);
349 CREATE INDEX i1 ON t1(b);
352 CREATE TABLE t1(a INTEGER PRIMARY KEY, b, c);
353 CREATE INDEX i1 ON t1(b);
354 CREATE INDEX i2 ON t1(c, b);
355 CREATE INDEX i3 ON t1(c, b, c);
358 CREATE TABLE t1(a INT PRIMARY KEY, b, c) WITHOUT ROWID;
359 CREATE INDEX i1 ON t1(b);
360 CREATE INDEX i2 ON t1(c, b);
361 CREATE INDEX i3 ON t1(c, b, c);
364 CREATE TABLE t1(a INT PRIMARY KEY, b, c);
365 CREATE INDEX i1 ON t1(b);
366 CREATE INDEX i2 ON t1(c, b);
367 CREATE INDEX i3 ON t1(c, b, c);
371 CREATE TABLE t1(a INT PRIMARY KEY DESC, b, c);
372 CREATE INDEX i1 ON t1(b DESC);
373 CREATE INDEX i2 ON t1(c, b);
374 CREATE INDEX i3 ON t1(c DESC, b, c);
377 CREATE TABLE t1(a INT PRIMARY KEY DESC, b, c) WITHOUT ROWID;
378 CREATE INDEX i1 ON t1(b);
379 CREATE INDEX i2 ON t1(c, b);
380 CREATE INDEX i3 ON t1(c, b, c);
386 INSERT INTO t1 VALUES(2, 'hello', 'world');
387 INSERT INTO t1 VALUES(4, 'hello', 'planet');
388 INSERT INTO t1 VALUES(6, 'hello', 'xyz');
392 set check [dbfilecksum rbu.db]
395 do_test $tn3.4.$tn2.$tn.1 {
399 do_execsql_test $tn3.4.$tn2.$tn.2 {
400 SELECT * FROM t1 ORDER BY a ASC;
407 do_execsql_test $tn3.4.$tn2.$tn.3 { PRAGMA integrity_check } ok
409 if {$cmd=="step_rbu_state"} {
410 do_test $tn3.4.$tn2.$tn.4 { file exists state.db } 1
411 do_test $tn3.4.$tn2.$tn.5 { expr {$check == [dbfilecksum rbu.db]} } 1
413 do_test $tn3.4.$tn2.$tn.6 { file exists state.db } 0
414 do_test $tn3.4.$tn2.$tn.7 { expr {$check == [dbfilecksum rbu.db]} } 0
419 foreach {tn2 cmd} {1 run_rbu 2 step_rbu 3 step_rbu_state} {
420 foreach {tn schema} {
422 CREATE TABLE t1(c, b, '(a)' INTEGER PRIMARY KEY);
423 CREATE INDEX i1 ON t1(c, b);
426 CREATE TABLE t1(c, b, '(a)' PRIMARY KEY);
429 CREATE TABLE t1(c, b, '(a)' PRIMARY KEY) WITHOUT ROWID;
435 INSERT INTO t1('(a)', b, c) VALUES(2, 'hello', 'world');
436 INSERT INTO t1('(a)', b, c) VALUES(4, 'hello', 'planet');
437 INSERT INTO t1('(a)', b, c) VALUES(6, 'hello', 'xyz');
441 set check [dbfilecksum rbu.db]
444 do_test $tn3.5.$tn2.$tn.1 {
448 do_execsql_test $tn3.5.$tn2.$tn.2 {
449 SELECT * FROM t1 ORDER BY "(a)" ASC;
456 do_execsql_test $tn3.4.$tn2.$tn.3 { PRAGMA integrity_check } ok
458 if {$cmd=="step_rbu_state"} {
459 do_test $tn3.5.$tn2.$tn.4 { file exists state.db } 1
460 do_test $tn3.5.$tn2.$tn.5 { expr {$check == [dbfilecksum rbu.db]} } 1
462 do_test $tn3.5.$tn2.$tn.6 { file exists state.db } 0
463 do_test $tn3.5.$tn2.$tn.7 { expr {$check == [dbfilecksum rbu.db]} } 0
468 #-------------------------------------------------------------------------
470 foreach {tn2 cmd} {1 run_rbu 2 step_rbu 3 step_rbu_state} {
471 foreach {tn schema} {
473 CREATE TABLE t1(a INTEGER PRIMARY KEY, b, c, d);
476 CREATE TABLE t1(a INTEGER PRIMARY KEY, b, c, d);
477 CREATE INDEX i1 ON t1(d);
478 CREATE INDEX i2 ON t1(d, c);
479 CREATE INDEX i3 ON t1(d, c, b);
480 CREATE INDEX i4 ON t1(b);
481 CREATE INDEX i5 ON t1(c);
482 CREATE INDEX i6 ON t1(c, b);
485 CREATE TABLE t1(a PRIMARY KEY, b, c, d) WITHOUT ROWID;
486 CREATE INDEX i1 ON t1(d);
487 CREATE INDEX i2 ON t1(d, c);
488 CREATE INDEX i3 ON t1(d, c, b);
489 CREATE INDEX i4 ON t1(b);
490 CREATE INDEX i5 ON t1(c);
491 CREATE INDEX i6 ON t1(c, b);
494 CREATE TABLE t1(a PRIMARY KEY, b, c, d);
495 CREATE INDEX i1 ON t1(d);
496 CREATE INDEX i2 ON t1(d, c);
497 CREATE INDEX i3 ON t1(d, c, b);
498 CREATE INDEX i4 ON t1(b);
499 CREATE INDEX i5 ON t1(c);
500 CREATE INDEX i6 ON t1(c, b);
506 INSERT INTO t1 VALUES(1, 2, 3, 4);
507 INSERT INTO t1 VALUES(2, 5, 6, 7);
508 INSERT INTO t1 VALUES(3, 8, 9, 10);
512 set check [dbfilecksum rbu.db]
515 do_test $tn3.5.$tn2.$tn.1 {
519 do_execsql_test $tn3.5.$tn2.$tn.2 {
520 SELECT * FROM t1 ORDER BY a ASC;
527 do_execsql_test $tn3.6.$tn2.$tn.3 { PRAGMA integrity_check } ok
529 if {$cmd=="step_rbu_state"} {
530 do_test $tn3.6.$tn2.$tn.4 { file exists state.db } 1
531 do_test $tn3.6.$tn2.$tn.5 { expr {$check == [dbfilecksum rbu.db]} } 1
533 do_test $tn3.6.$tn2.$tn.6 { file exists state.db } 0
534 do_test $tn3.6.$tn2.$tn.7 { expr {$check == [dbfilecksum rbu.db]} } 0
539 #-------------------------------------------------------------------------
540 # Test some error cases:
542 # * A virtual table with no rbu_rowid column.
543 # * A no-PK table with no rbu_rowid column.
544 # * A PK table with an rbu_rowid column.
546 # 6: An update string of the wrong length
549 foreach {tn schema error} {
551 CREATE TABLE t1(a, b);
552 CREATE TABLE rbu.data_t1(a, b, rbu_control);
553 } {SQLITE_ERROR - table data_t1 requires rbu_rowid column}
556 CREATE VIRTUAL TABLE t1 USING fts4(a, b);
557 CREATE TABLE rbu.data_t1(a, b, rbu_control);
558 } {SQLITE_ERROR - table data_t1 requires rbu_rowid column}
561 CREATE TABLE t1(a PRIMARY KEY, b);
562 CREATE TABLE rbu.data_t1(a, b, rbu_rowid, rbu_control);
563 } {SQLITE_ERROR - table data_t1 may not have rbu_rowid column}
566 CREATE TABLE t1(a INTEGER PRIMARY KEY, b);
567 CREATE TABLE rbu.data_t1(a, b, rbu_rowid, rbu_control);
568 } {SQLITE_ERROR - table data_t1 may not have rbu_rowid column}
571 CREATE TABLE t1(a, b PRIMARY KEY) WITHOUT ROWID;
572 CREATE TABLE rbu.data_t1(a, b, rbu_rowid, rbu_control);
573 } {SQLITE_ERROR - table data_t1 may not have rbu_rowid column}
576 CREATE TABLE t1(a, b PRIMARY KEY) WITHOUT ROWID;
577 CREATE TABLE rbu.data_t1(a, b, rbu_control);
578 INSERT INTO rbu.data_t1 VALUES(1, 2, 'x.x');
579 } {SQLITE_ERROR - invalid rbu_control value}
582 CREATE TABLE t1(a, b PRIMARY KEY) WITHOUT ROWID;
583 CREATE TABLE rbu.data_t1(a, b, rbu_control);
584 INSERT INTO rbu.data_t1 VALUES(1, 2, NULL);
585 } {SQLITE_ERROR - invalid rbu_control value}
588 CREATE TABLE t1(a, b PRIMARY KEY) WITHOUT ROWID;
589 CREATE TABLE rbu.data_t1(a, b, rbu_control);
590 INSERT INTO rbu.data_t1 VALUES(1, 2, 4);
591 } {SQLITE_ERROR - invalid rbu_control value}
594 CREATE TABLE t1(a, b PRIMARY KEY) WITHOUT ROWID;
595 CREATE TABLE rbu.data_t1(a, b, rbu_control);
596 INSERT INTO rbu.data_t1 VALUES(1, 2, 3);
597 } {SQLITE_ERROR - invalid rbu_control value}
600 CREATE TABLE t2(a, b);
601 CREATE TABLE rbu.data_t1(a, b, rbu_control);
602 INSERT INTO rbu.data_t1 VALUES(1, 2, 2);
603 } {SQLITE_ERROR - no such table: t1}
606 CREATE TABLE rbu.data_t2(a, b, rbu_control);
607 INSERT INTO rbu.data_t2 VALUES(1, 2, 2);
608 } {SQLITE_ERROR - no such table: t2}
613 execsql { ATTACH 'rbu.db' AS rbu }
617 list [catch { run_rbu test.db rbu.db } msg] $msg
622 # Test that an RBU database containing no input tables is handled
627 list [catch { run_rbu test.db rbu.db } msg] $msg
630 # Test that an RBU database containing only empty data_xxx tables is
631 # also handled correctly.
634 do_execsql_test $tn3.8.2.1 {
635 CREATE TABLE t1(a PRIMARY KEY, b);
636 INSERT INTO t1 VALUES(1, 2);
637 ATTACH 'rbu.db' AS rbu;
638 CREATE TABLE data_t1(a, b, rbu_control);
642 list [catch { run_rbu test.db rbu.db } msg] $msg
645 # Test that RBU can update indexes containing NULL values.
649 do_execsql_test $tn3.9.1 {
650 CREATE TABLE t1(a PRIMARY KEY, b, c);
651 CREATE INDEX i1 ON t1(b, c);
652 INSERT INTO t1 VALUES(1, 1, NULL);
653 INSERT INTO t1 VALUES(2, NULL, 2);
654 INSERT INTO t1 VALUES(3, NULL, NULL);
656 ATTACH 'rbu.db' AS rbu;
657 CREATE TABLE rbu.data_t1(a, b, c, rbu_control);
658 INSERT INTO data_t1 VALUES(1, NULL, NULL, 1);
659 INSERT INTO data_t1 VALUES(3, NULL, NULL, 1);
663 list [catch { run_rbu test.db rbu.db } msg] $msg
666 do_execsql_test $tn3.9.3 {
669 do_execsql_test $tn3.9.4 { PRAGMA integrity_check } {ok}