1# 2005 November 2 2# 3# The author disclaims copyright to this source code. In place of 4# a legal notice, here is a blessing: 5# 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. 9# 10#*********************************************************************** 11# This file implements regression tests for SQLite library. The 12# focus of this file is testing CHECK constraints 13# 14 15set testdir [file dirname $argv0] 16source $testdir/tester.tcl 17set ::testprefix check 18 19# Only run these tests if the build includes support for CHECK constraints 20ifcapable !check { 21 finish_test 22 return 23} 24 25do_test check-1.1 { 26 execsql { 27 CREATE TABLE t1( 28 x INTEGER CHECK( x<5 ), 29 y REAL CHECK( y>x ) 30 ); 31 } 32} {} 33do_test check-1.2 { 34 execsql { 35 INSERT INTO t1 VALUES(3,4); 36 SELECT * FROM t1; 37 } 38} {3 4.0} 39do_test check-1.3 { 40 catchsql { 41 INSERT INTO t1 VALUES(6,7); 42 } 43} {1 {CHECK constraint failed: t1}} 44do_test check-1.4 { 45 execsql { 46 SELECT * FROM t1; 47 } 48} {3 4.0} 49do_test check-1.5 { 50 catchsql { 51 INSERT INTO t1 VALUES(4,3); 52 } 53} {1 {CHECK constraint failed: t1}} 54do_test check-1.6 { 55 execsql { 56 SELECT * FROM t1; 57 } 58} {3 4.0} 59do_test check-1.7 { 60 catchsql { 61 INSERT INTO t1 VALUES(NULL,6); 62 } 63} {0 {}} 64do_test check-1.8 { 65 execsql { 66 SELECT * FROM t1; 67 } 68} {3 4.0 {} 6.0} 69do_test check-1.9 { 70 catchsql { 71 INSERT INTO t1 VALUES(2,NULL); 72 } 73} {0 {}} 74do_test check-1.10 { 75 execsql { 76 SELECT * FROM t1; 77 } 78} {3 4.0 {} 6.0 2 {}} 79do_test check-1.11 { 80 execsql { 81 DELETE FROM t1 WHERE x IS NULL OR x!=3; 82 UPDATE t1 SET x=2 WHERE x==3; 83 SELECT * FROM t1; 84 } 85} {2 4.0} 86do_test check-1.12 { 87 catchsql { 88 UPDATE t1 SET x=7 WHERE x==2 89 } 90} {1 {CHECK constraint failed: t1}} 91do_test check-1.13 { 92 execsql { 93 SELECT * FROM t1; 94 } 95} {2 4.0} 96do_test check-1.14 { 97 catchsql { 98 UPDATE t1 SET x=5 WHERE x==2 99 } 100} {1 {CHECK constraint failed: t1}} 101do_test check-1.15 { 102 execsql { 103 SELECT * FROM t1; 104 } 105} {2 4.0} 106do_test check-1.16 { 107 catchsql { 108 UPDATE t1 SET x=4, y=11 WHERE x==2 109 } 110} {0 {}} 111do_test check-1.17 { 112 execsql { 113 SELECT * FROM t1; 114 } 115} {4 11.0} 116 117do_test check-2.1 { 118 execsql { 119 PRAGMA writable_schema = 1; 120 CREATE TABLE t2( 121 x INTEGER CONSTRAINT one CHECK( typeof(coalesce(x,0))=="integer" ), 122 y REAL CONSTRAINT two CHECK( typeof(coalesce(y,0.1))=='real' ), 123 z TEXT CONSTRAINT three CHECK( typeof(coalesce(z,''))=='text' ) 124 ); 125 CREATE TABLE t2n( 126 x INTEGER CONSTRAINT one CHECK( typeof(coalesce(x,0))=="integer" ), 127 y NUMERIC CONSTRAINT two CHECK( typeof(coalesce(y,0.1))=='real' ), 128 z TEXT CONSTRAINT three CHECK( typeof(coalesce(z,''))=='text' ) 129 ); 130 PRAGMA writable_schema = 0; 131 } 132} {} 133do_test check-2.2 { 134 execsql { 135 INSERT INTO t2 VALUES(1,2.2,'three'); 136 SELECT * FROM t2; 137 } 138} {1 2.2 three} 139db close 140sqlite3 db test.db 141do_test check-2.3 { 142 execsql { 143 INSERT INTO t2 VALUES(NULL, NULL, NULL); 144 SELECT * FROM t2; 145 } 146} {1 2.2 three {} {} {}} 147do_test check-2.4 { 148 catchsql { 149 INSERT INTO t2 VALUES(1.1, NULL, NULL); 150 } 151} {1 {CHECK constraint failed: one}} 152do_test check-2.5 { 153 # The 5 gets automatically promoted to 5.0 because the column type is REAL 154 catchsql { 155 INSERT INTO t2 VALUES(NULL, 5, NULL); 156 } 157} {0 {}} 158do_test check-2.5b { 159 # This time the column type is NUMERIC, so not automatic promption to REAL 160 # occurs and the constraint fails. 161 catchsql { 162 INSERT INTO t2n VALUES(NULL, 5, NULL); 163 } 164} {1 {CHECK constraint failed: two}} 165do_test check-2.6 { 166 catchsql { 167 INSERT INTO t2 VALUES(NULL, NULL, 3.14159); 168 } 169} {1 {CHECK constraint failed: three}} 170 171# Undocumented behavior: The CONSTRAINT name clause can follow a constraint. 172# Such a clause is ignored. But the parser must accept it for backwards 173# compatibility. 174# 175do_test check-2.10 { 176 execsql { 177 CREATE TABLE t2b( 178 x INTEGER CHECK( typeof(coalesce(x,0))=='integer' ) CONSTRAINT one, 179 y TEXT PRIMARY KEY constraint two, 180 z INTEGER, 181 UNIQUE(x,z) constraint three 182 ); 183 } 184} {} 185do_test check-2.11 { 186 catchsql { 187 INSERT INTO t2b VALUES('xyzzy','hi',5); 188 } 189} {1 {CHECK constraint failed: t2b}} 190do_test check-2.12 { 191 execsql { 192 CREATE TABLE t2c( 193 x INTEGER CONSTRAINT x_one CONSTRAINT x_two 194 CHECK( typeof(coalesce(x,0))=='integer' ) 195 CONSTRAINT x_two CONSTRAINT x_three, 196 y INTEGER, z INTEGER, 197 CONSTRAINT u_one UNIQUE(x,y,z) CONSTRAINT u_two 198 ); 199 } 200} {} 201do_test check-2.13 { 202 catchsql { 203 INSERT INTO t2c VALUES('xyzzy',7,8); 204 } 205} {1 {CHECK constraint failed: x_two}} 206do_test check-2.cleanup { 207 execsql { 208 DROP TABLE IF EXISTS t2b; 209 DROP TABLE IF EXISTS t2c; 210 DROP TABLE IF EXISTS t2n; 211 } 212} {} 213 214ifcapable subquery { 215 do_test check-3.1 { 216 catchsql { 217 CREATE TABLE t3( 218 x, y, z, 219 CHECK( x<(SELECT min(x) FROM t1) ) 220 ); 221 } 222 } {1 {subqueries prohibited in CHECK constraints}} 223} 224 225do_test check-3.2 { 226 execsql { 227 SELECT name FROM sqlite_master ORDER BY name 228 } 229} {t1 t2} 230do_test check-3.3 { 231 catchsql { 232 CREATE TABLE t3( 233 x, y, z, 234 CHECK( q<x ) 235 ); 236 } 237} {1 {no such column: q}} 238do_test check-3.4 { 239 execsql { 240 SELECT name FROM sqlite_master ORDER BY name 241 } 242} {t1 t2} 243do_test check-3.5 { 244 catchsql { 245 CREATE TABLE t3( 246 x, y, z, 247 CHECK( t2.x<x ) 248 ); 249 } 250} {1 {no such column: t2.x}} 251do_test check-3.6 { 252 execsql { 253 SELECT name FROM sqlite_master ORDER BY name 254 } 255} {t1 t2} 256do_test check-3.7 { 257 catchsql { 258 CREATE TABLE t3( 259 x, y, z, 260 CHECK( t3.x<25 ) 261 ); 262 } 263} {0 {}} 264do_test check-3.8 { 265 execsql { 266 INSERT INTO t3 VALUES(1,2,3); 267 SELECT * FROM t3; 268 } 269} {1 2 3} 270do_test check-3.9 { 271 catchsql { 272 INSERT INTO t3 VALUES(111,222,333); 273 } 274} {1 {CHECK constraint failed: t3}} 275 276do_test check-4.1 { 277 execsql { 278 CREATE TABLE t4(x, y, 279 CHECK ( 280 x+y==11 281 OR x*y==12 282 OR x/y BETWEEN 5 AND 8 283 OR -x==y+10 284 ) 285 ); 286 } 287} {} 288do_test check-4.2 { 289 execsql { 290 INSERT INTO t4 VALUES(1,10); 291 SELECT * FROM t4 292 } 293} {1 10} 294do_test check-4.3 { 295 execsql { 296 UPDATE t4 SET x=4, y=3; 297 SELECT * FROM t4 298 } 299} {4 3} 300do_test check-4.4 { 301 execsql { 302 UPDATE t4 SET x=12, y=2; 303 SELECT * FROM t4 304 } 305} {12 2} 306do_test check-4.5 { 307 execsql { 308 UPDATE t4 SET x=12, y=-22; 309 SELECT * FROM t4 310 } 311} {12 -22} 312do_test check-4.6 { 313 catchsql { 314 UPDATE t4 SET x=0, y=1; 315 } 316} {1 {CHECK constraint failed: t4}} 317do_test check-4.7 { 318 execsql { 319 SELECT * FROM t4; 320 } 321} {12 -22} 322do_test check-4.8 { 323 execsql { 324 PRAGMA ignore_check_constraints=ON; 325 UPDATE t4 SET x=0, y=1; 326 SELECT * FROM t4; 327 PRAGMA integrity_check; 328 } 329} {0 1 ok} 330do_execsql_test check-4.8.1 { 331 PRAGMA ignore_check_constraints=OFF; 332 PRAGMA integrity_check; 333} {{CHECK constraint failed in t4}} 334do_test check-4.9 { 335 catchsql { 336 UPDATE t4 SET x=0, y=2; 337 } 338} {1 {CHECK constraint failed: t4}} 339ifcapable vacuum { 340 do_test check_4.10 { 341 catchsql { 342 VACUUM 343 } 344 } {0 {}} 345} 346 347do_test check-5.1 { 348 catchsql { 349 CREATE TABLE t5(x, y, 350 CHECK( x*y<:abc ) 351 ); 352 } 353} {1 {parameters prohibited in CHECK constraints}} 354do_test check-5.2 { 355 catchsql { 356 CREATE TABLE t5(x, y, 357 CHECK( x*y<? ) 358 ); 359 } 360} {1 {parameters prohibited in CHECK constraints}} 361 362ifcapable conflict { 363 364do_test check-6.1 { 365 execsql {SELECT * FROM t1} 366} {4 11.0} 367do_test check-6.2 { 368 execsql { 369 UPDATE OR IGNORE t1 SET x=5; 370 SELECT * FROM t1; 371 } 372} {4 11.0} 373do_test check-6.3 { 374 execsql { 375 INSERT OR IGNORE INTO t1 VALUES(5,4.0); 376 SELECT * FROM t1; 377 } 378} {4 11.0} 379do_test check-6.4 { 380 execsql { 381 INSERT OR IGNORE INTO t1 VALUES(2,20.0); 382 SELECT * FROM t1; 383 } 384} {4 11.0 2 20.0} 385do_test check-6.5 { 386 catchsql { 387 UPDATE OR FAIL t1 SET x=7-x, y=y+1; 388 } 389} {1 {CHECK constraint failed: t1}} 390do_test check-6.6 { 391 execsql { 392 SELECT * FROM t1; 393 } 394} {3 12.0 2 20.0} 395do_test check-6.7 { 396 catchsql { 397 BEGIN; 398 INSERT INTO t1 VALUES(1,30.0); 399 INSERT OR ROLLBACK INTO t1 VALUES(8,40.0); 400 } 401} {1 {CHECK constraint failed: t1}} 402do_test check-6.8 { 403 catchsql { 404 COMMIT; 405 } 406} {1 {cannot commit - no transaction is active}} 407do_test check-6.9 { 408 execsql { 409 SELECT * FROM t1 410 } 411} {3 12.0 2 20.0} 412 413do_test check-6.11 { 414 execsql {SELECT * FROM t1} 415} {3 12.0 2 20.0} 416do_test check-6.12 { 417 catchsql { 418 REPLACE INTO t1 VALUES(6,7); 419 } 420} {1 {CHECK constraint failed: t1}} 421do_test check-6.13 { 422 execsql {SELECT * FROM t1} 423} {3 12.0 2 20.0} 424do_test check-6.14 { 425 catchsql { 426 INSERT OR IGNORE INTO t1 VALUES(6,7); 427 } 428} {0 {}} 429do_test check-6.15 { 430 execsql {SELECT * FROM t1} 431} {3 12.0 2 20.0} 432 433 434} 435 436#-------------------------------------------------------------------------- 437# If a connection opens a database that contains a CHECK constraint that 438# uses an unknown UDF, the schema should not be considered malformed. 439# Attempting to modify the table should fail (since the CHECK constraint 440# cannot be tested). 441# 442reset_db 443proc myfunc {x} {expr $x < 10} 444db func myfunc -deterministic myfunc 445 446do_execsql_test 7.1 { CREATE TABLE t6(a CHECK (myfunc(a))) } 447do_execsql_test 7.2 { INSERT INTO t6 VALUES(9) } 448do_catchsql_test 7.3 { INSERT INTO t6 VALUES(11) } \ 449 {1 {CHECK constraint failed: t6}} 450 451do_test 7.4 { 452 sqlite3 db2 test.db 453 execsql { SELECT * FROM t6 } db2 454} {9} 455 456do_test 7.5 { 457 catchsql { INSERT INTO t6 VALUES(8) } db2 458} {1 {unknown function: myfunc()}} 459 460do_test 7.6 { 461 catchsql { CREATE TABLE t7(a CHECK (myfunc(a))) } db2 462} {1 {no such function: myfunc}} 463 464do_test 7.7 { 465 db2 func myfunc myfunc 466 execsql { INSERT INTO t6 VALUES(8) } db2 467} {} 468 469do_test 7.8 { 470 db2 func myfunc myfunc 471 catchsql { INSERT INTO t6 VALUES(12) } db2 472} {1 {CHECK constraint failed: t6}} 473 474# 2013-08-02: Silently ignore database name qualifiers in CHECK constraints. 475# 476do_execsql_test 8.1 { 477 CREATE TABLE t810(a, CHECK( main.t810.a>0 )); 478 CREATE TABLE t811(b, CHECK( xyzzy.t811.b BETWEEN 5 AND 10 )); 479} {} 480 481# Make sure check constraints involving the ROWID are not ignored 482# 483do_execsql_test 9.1 { 484 CREATE TABLE t1( 485 a INTEGER PRIMARY KEY, 486 b INTEGER NOT NULL CONSTRAINT 'b-check' CHECK( b>a ), 487 c INTEGER NOT NULL CONSTRAINT 'c-check' CHECK( c>rowid*2 ), 488 d INTEGER NOT NULL CONSTRAINT 'd-check' CHECK( d BETWEEN b AND c ) 489 ); 490 INSERT INTO t1(a,b,c,d) VALUES(1,2,4,3),(2,4,6,5),(3,10,30,20); 491} {} 492do_catchsql_test 9.2 { 493 UPDATE t1 SET b=0 WHERE a=1; 494} {1 {CHECK constraint failed: b-check}} 495do_catchsql_test 9.3 { 496 UPDATE t1 SET c=a*2 WHERE a=1; 497} {1 {CHECK constraint failed: c-check}} 498 499# Integrity check on a VIEW with columns. 500# 501db close 502db2 close 503forcedelete test.db 504sqlite3 db test.db 505do_execsql_test 10.1 { 506 CREATE TABLE t1(x); 507 CREATE VIEW v1(y) AS SELECT x FROM t1; 508 PRAGMA integrity_check; 509} {ok} 510 511#------------------------------------------------------------------------- 512reset_db 513do_execsql_test 11.0 { 514 CREATE TABLE t1 (Col0 CHECK(1 COLLATE BINARY BETWEEN 1 AND 1) ) ; 515} 516do_execsql_test 11.1 { 517 INSERT INTO t1 VALUES (NULL); 518} 519do_execsql_test 11.2 { 520 INSERT INTO t1 VALUES (NULL); 521} 522 523do_execsql_test 11.3 { 524 CREATE TABLE t2(b, a CHECK( 525 CASE 'abc' COLLATE nocase WHEN a THEN 1 ELSE 0 END) 526 ); 527} 528do_execsql_test 11.4 { 529 INSERT INTO t2(a) VALUES('abc'); 530} 531do_execsql_test 11.5 { 532 INSERT INTO t2(b, a) VALUES(1, 'abc'||''); 533} 534do_execsql_test 11.6 { 535 INSERT INTO t2(b, a) VALUES(2, 'abc'); 536} 537 538# 2019-12-24 ticket b383b90278186263 539# 540reset_db 541do_execsql_test 12.10 { 542 CREATE TABLE t1(a TEXT, CHECK(a=+a)); 543 INSERT INTO t1(a) VALUES(NULL),('xyz'),(5),(x'303132'),(4.75); 544 SELECT quote(a) FROM t1 ORDER BY rowid; 545} {NULL 'xyz' '5' X'303132' '4.75'} 546do_execsql_test 12.20 { 547 DROP TABLE t1; 548 CREATE TABLE t1(a TEXT, CHECK(a<>+a)); 549 INSERT INTO t1(a) VALUES(NULL); 550} {} 551do_catchsql_test 12.21 { 552 INSERT INTO t1(a) VALUES('xyz'); 553} {1 {CHECK constraint failed: t1}} 554do_catchsql_test 12.22 { 555 INSERT INTO t1(a) VALUES(123); 556} {1 {CHECK constraint failed: t1}} 557do_execsql_test 12.30 { 558 DROP TABLE t1; 559 CREATE TABLE t1(a TEXT, CHECK(NOT(a=+a))); 560 INSERT INTO t1(a) VALUES(NULL); 561} {} 562do_catchsql_test 12.31 { 563 INSERT INTO t1(a) VALUES('xyz'); 564} {1 {CHECK constraint failed: t1}} 565do_catchsql_test 12.32 { 566 INSERT INTO t1(a) VALUES(123); 567} {1 {CHECK constraint failed: t1}} 568do_execsql_test 12.40 { 569 DROP TABLE t1; 570 CREATE TABLE t1(a TEXT, CHECK(NOT(a<>+a))); 571 INSERT INTO t1(a) VALUES(NULL),('xyz'),(5),(x'303132'),(4.75); 572 SELECT quote(a) FROM t1 ORDER BY rowid; 573} {NULL 'xyz' '5' X'303132' '4.75'} 574do_execsql_test 12.50 { 575 DROP TABLE t1; 576 CREATE TABLE t1(a TEXT, CHECK(a BETWEEN 0 AND +a)); 577 INSERT INTO t1(a) VALUES(NULL),('xyz'),(5),(x'303132'),(4.75); 578 SELECT quote(a) FROM t1 ORDER BY rowid; 579} {NULL 'xyz' '5' X'303132' '4.75'} 580do_execsql_test 12.60 { 581 DROP TABLE t1; 582 CREATE TABLE t1(a TEXT, CHECK(a NOT BETWEEN 0 AND +a)); 583 INSERT INTO t1(a) VALUES(NULL); 584 SELECT quote(a) FROM t1 ORDER BY rowid; 585} {NULL} 586do_catchsql_test 12.61 { 587 INSERT INTO t1(a) VALUES(456); 588} {1 {CHECK constraint failed: t1}} 589do_execsql_test 12.70 { 590 DROP TABLE t1; 591 CREATE TABLE t1(a TEXT, CHECK(a BETWEEN +a AND 999999)); 592 INSERT INTO t1(a) VALUES(NULL),(5); 593 SELECT quote(a) FROM t1 ORDER BY rowid; 594} {NULL '5'} 595do_execsql_test 12.80 { 596 DROP TABLE t1; 597 CREATE TABLE t1(a TEXT, CHECK(a NOT BETWEEN +a AND 999999)); 598 INSERT INTO t1(a) VALUES(NULL); 599 SELECT quote(a) FROM t1 ORDER BY rowid; 600} {NULL} 601do_catchsql_test 12.81 { 602 INSERT INTO t1(a) VALUES(456); 603} {1 {CHECK constraint failed: t1}} 604 605finish_test 606