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# $Id: check.test,v 1.13 2009/06/05 17:09:12 drh Exp $ 15 16set testdir [file dirname $argv0] 17source $testdir/tester.tcl 18set ::testprefix check 19 20# Only run these tests if the build includes support for CHECK constraints 21ifcapable !check { 22 finish_test 23 return 24} 25 26do_test check-1.1 { 27 execsql { 28 CREATE TABLE t1( 29 x INTEGER CHECK( x<5 ), 30 y REAL CHECK( y>x ) 31 ); 32 } 33} {} 34do_test check-1.2 { 35 execsql { 36 INSERT INTO t1 VALUES(3,4); 37 SELECT * FROM t1; 38 } 39} {3 4.0} 40do_test check-1.3 { 41 catchsql { 42 INSERT INTO t1 VALUES(6,7); 43 } 44} {1 {CHECK constraint failed: t1}} 45do_test check-1.4 { 46 execsql { 47 SELECT * FROM t1; 48 } 49} {3 4.0} 50do_test check-1.5 { 51 catchsql { 52 INSERT INTO t1 VALUES(4,3); 53 } 54} {1 {CHECK constraint failed: t1}} 55do_test check-1.6 { 56 execsql { 57 SELECT * FROM t1; 58 } 59} {3 4.0} 60do_test check-1.7 { 61 catchsql { 62 INSERT INTO t1 VALUES(NULL,6); 63 } 64} {0 {}} 65do_test check-1.8 { 66 execsql { 67 SELECT * FROM t1; 68 } 69} {3 4.0 {} 6.0} 70do_test check-1.9 { 71 catchsql { 72 INSERT INTO t1 VALUES(2,NULL); 73 } 74} {0 {}} 75do_test check-1.10 { 76 execsql { 77 SELECT * FROM t1; 78 } 79} {3 4.0 {} 6.0 2 {}} 80do_test check-1.11 { 81 execsql { 82 DELETE FROM t1 WHERE x IS NULL OR x!=3; 83 UPDATE t1 SET x=2 WHERE x==3; 84 SELECT * FROM t1; 85 } 86} {2 4.0} 87do_test check-1.12 { 88 catchsql { 89 UPDATE t1 SET x=7 WHERE x==2 90 } 91} {1 {CHECK constraint failed: t1}} 92do_test check-1.13 { 93 execsql { 94 SELECT * FROM t1; 95 } 96} {2 4.0} 97do_test check-1.14 { 98 catchsql { 99 UPDATE t1 SET x=5 WHERE x==2 100 } 101} {1 {CHECK constraint failed: t1}} 102do_test check-1.15 { 103 execsql { 104 SELECT * FROM t1; 105 } 106} {2 4.0} 107do_test check-1.16 { 108 catchsql { 109 UPDATE t1 SET x=4, y=11 WHERE x==2 110 } 111} {0 {}} 112do_test check-1.17 { 113 execsql { 114 SELECT * FROM t1; 115 } 116} {4 11.0} 117 118do_test check-2.1 { 119 execsql { 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 } 126} {} 127do_test check-2.2 { 128 execsql { 129 INSERT INTO t2 VALUES(1,2.2,'three'); 130 SELECT * FROM t2; 131 } 132} {1 2.2 three} 133db close 134sqlite3 db test.db 135do_test check-2.3 { 136 execsql { 137 INSERT INTO t2 VALUES(NULL, NULL, NULL); 138 SELECT * FROM t2; 139 } 140} {1 2.2 three {} {} {}} 141do_test check-2.4 { 142 catchsql { 143 INSERT INTO t2 VALUES(1.1, NULL, NULL); 144 } 145} {1 {CHECK constraint failed: one}} 146do_test check-2.5 { 147 catchsql { 148 INSERT INTO t2 VALUES(NULL, 5, NULL); 149 } 150} {1 {CHECK constraint failed: two}} 151do_test check-2.6 { 152 catchsql { 153 INSERT INTO t2 VALUES(NULL, NULL, 3.14159); 154 } 155} {1 {CHECK constraint failed: three}} 156 157# Undocumented behavior: The CONSTRAINT name clause can follow a constraint. 158# Such a clause is ignored. But the parser must accept it for backwards 159# compatibility. 160# 161do_test check-2.10 { 162 execsql { 163 CREATE TABLE t2b( 164 x INTEGER CHECK( typeof(coalesce(x,0))=='integer' ) CONSTRAINT one, 165 y TEXT PRIMARY KEY constraint two, 166 z INTEGER, 167 UNIQUE(x,z) constraint three 168 ); 169 } 170} {} 171do_test check-2.11 { 172 catchsql { 173 INSERT INTO t2b VALUES('xyzzy','hi',5); 174 } 175} {1 {CHECK constraint failed: t2b}} 176do_test check-2.12 { 177 execsql { 178 CREATE TABLE t2c( 179 x INTEGER CONSTRAINT x_one CONSTRAINT x_two 180 CHECK( typeof(coalesce(x,0))=='integer' ) 181 CONSTRAINT x_two CONSTRAINT x_three, 182 y INTEGER, z INTEGER, 183 CONSTRAINT u_one UNIQUE(x,y,z) CONSTRAINT u_two 184 ); 185 } 186} {} 187do_test check-2.13 { 188 catchsql { 189 INSERT INTO t2c VALUES('xyzzy',7,8); 190 } 191} {1 {CHECK constraint failed: x_two}} 192do_test check-2.cleanup { 193 execsql { 194 DROP TABLE IF EXISTS t2b; 195 DROP TABLE IF EXISTS t2c; 196 } 197} {} 198 199ifcapable subquery { 200 do_test check-3.1 { 201 catchsql { 202 CREATE TABLE t3( 203 x, y, z, 204 CHECK( x<(SELECT min(x) FROM t1) ) 205 ); 206 } 207 } {1 {subqueries prohibited in CHECK constraints}} 208} 209 210do_test check-3.2 { 211 execsql { 212 SELECT name FROM sqlite_master ORDER BY name 213 } 214} {t1 t2} 215do_test check-3.3 { 216 catchsql { 217 CREATE TABLE t3( 218 x, y, z, 219 CHECK( q<x ) 220 ); 221 } 222} {1 {no such column: q}} 223do_test check-3.4 { 224 execsql { 225 SELECT name FROM sqlite_master ORDER BY name 226 } 227} {t1 t2} 228do_test check-3.5 { 229 catchsql { 230 CREATE TABLE t3( 231 x, y, z, 232 CHECK( t2.x<x ) 233 ); 234 } 235} {1 {no such column: t2.x}} 236do_test check-3.6 { 237 execsql { 238 SELECT name FROM sqlite_master ORDER BY name 239 } 240} {t1 t2} 241do_test check-3.7 { 242 catchsql { 243 CREATE TABLE t3( 244 x, y, z, 245 CHECK( t3.x<25 ) 246 ); 247 } 248} {0 {}} 249do_test check-3.8 { 250 execsql { 251 INSERT INTO t3 VALUES(1,2,3); 252 SELECT * FROM t3; 253 } 254} {1 2 3} 255do_test check-3.9 { 256 catchsql { 257 INSERT INTO t3 VALUES(111,222,333); 258 } 259} {1 {CHECK constraint failed: t3}} 260 261do_test check-4.1 { 262 execsql { 263 CREATE TABLE t4(x, y, 264 CHECK ( 265 x+y==11 266 OR x*y==12 267 OR x/y BETWEEN 5 AND 8 268 OR -x==y+10 269 ) 270 ); 271 } 272} {} 273do_test check-4.2 { 274 execsql { 275 INSERT INTO t4 VALUES(1,10); 276 SELECT * FROM t4 277 } 278} {1 10} 279do_test check-4.3 { 280 execsql { 281 UPDATE t4 SET x=4, y=3; 282 SELECT * FROM t4 283 } 284} {4 3} 285do_test check-4.4 { 286 execsql { 287 UPDATE t4 SET x=12, y=2; 288 SELECT * FROM t4 289 } 290} {12 2} 291do_test check-4.5 { 292 execsql { 293 UPDATE t4 SET x=12, y=-22; 294 SELECT * FROM t4 295 } 296} {12 -22} 297do_test check-4.6 { 298 catchsql { 299 UPDATE t4 SET x=0, y=1; 300 } 301} {1 {CHECK constraint failed: t4}} 302do_test check-4.7 { 303 execsql { 304 SELECT * FROM t4; 305 } 306} {12 -22} 307do_test check-4.8 { 308 execsql { 309 PRAGMA ignore_check_constraints=ON; 310 UPDATE t4 SET x=0, y=1; 311 SELECT * FROM t4; 312 PRAGMA integrity_check; 313 } 314} {0 1 ok} 315do_execsql_test check-4.8.1 { 316 PRAGMA ignore_check_constraints=OFF; 317 PRAGMA integrity_check; 318} {{CHECK constraint failed in t4}} 319do_test check-4.9 { 320 catchsql { 321 UPDATE t4 SET x=0, y=2; 322 } 323} {1 {CHECK constraint failed: t4}} 324ifcapable vacuum { 325 do_test check_4.10 { 326 catchsql { 327 VACUUM 328 } 329 } {0 {}} 330} 331 332do_test check-5.1 { 333 catchsql { 334 CREATE TABLE t5(x, y, 335 CHECK( x*y<:abc ) 336 ); 337 } 338} {1 {parameters prohibited in CHECK constraints}} 339do_test check-5.2 { 340 catchsql { 341 CREATE TABLE t5(x, y, 342 CHECK( x*y<? ) 343 ); 344 } 345} {1 {parameters prohibited in CHECK constraints}} 346 347ifcapable conflict { 348 349do_test check-6.1 { 350 execsql {SELECT * FROM t1} 351} {4 11.0} 352do_test check-6.2 { 353 execsql { 354 UPDATE OR IGNORE t1 SET x=5; 355 SELECT * FROM t1; 356 } 357} {4 11.0} 358do_test check-6.3 { 359 execsql { 360 INSERT OR IGNORE INTO t1 VALUES(5,4.0); 361 SELECT * FROM t1; 362 } 363} {4 11.0} 364do_test check-6.4 { 365 execsql { 366 INSERT OR IGNORE INTO t1 VALUES(2,20.0); 367 SELECT * FROM t1; 368 } 369} {4 11.0 2 20.0} 370do_test check-6.5 { 371 catchsql { 372 UPDATE OR FAIL t1 SET x=7-x, y=y+1; 373 } 374} {1 {CHECK constraint failed: t1}} 375do_test check-6.6 { 376 execsql { 377 SELECT * FROM t1; 378 } 379} {3 12.0 2 20.0} 380do_test check-6.7 { 381 catchsql { 382 BEGIN; 383 INSERT INTO t1 VALUES(1,30.0); 384 INSERT OR ROLLBACK INTO t1 VALUES(8,40.0); 385 } 386} {1 {CHECK constraint failed: t1}} 387do_test check-6.8 { 388 catchsql { 389 COMMIT; 390 } 391} {1 {cannot commit - no transaction is active}} 392do_test check-6.9 { 393 execsql { 394 SELECT * FROM t1 395 } 396} {3 12.0 2 20.0} 397 398do_test check-6.11 { 399 execsql {SELECT * FROM t1} 400} {3 12.0 2 20.0} 401do_test check-6.12 { 402 catchsql { 403 REPLACE INTO t1 VALUES(6,7); 404 } 405} {1 {CHECK constraint failed: t1}} 406do_test check-6.13 { 407 execsql {SELECT * FROM t1} 408} {3 12.0 2 20.0} 409do_test check-6.14 { 410 catchsql { 411 INSERT OR IGNORE INTO t1 VALUES(6,7); 412 } 413} {0 {}} 414do_test check-6.15 { 415 execsql {SELECT * FROM t1} 416} {3 12.0 2 20.0} 417 418 419} 420 421#-------------------------------------------------------------------------- 422# If a connection opens a database that contains a CHECK constraint that 423# uses an unknown UDF, the schema should not be considered malformed. 424# Attempting to modify the table should fail (since the CHECK constraint 425# cannot be tested). 426# 427reset_db 428proc myfunc {x} {expr $x < 10} 429db func myfunc myfunc 430 431do_execsql_test 7.1 { CREATE TABLE t6(a CHECK (myfunc(a))) } 432do_execsql_test 7.2 { INSERT INTO t6 VALUES(9) } 433do_catchsql_test 7.3 { INSERT INTO t6 VALUES(11) } \ 434 {1 {CHECK constraint failed: t6}} 435 436do_test 7.4 { 437 sqlite3 db2 test.db 438 execsql { SELECT * FROM t6 } db2 439} {9} 440 441do_test 7.5 { 442 catchsql { INSERT INTO t6 VALUES(8) } db2 443} {1 {unknown function: myfunc()}} 444 445do_test 7.6 { 446 catchsql { CREATE TABLE t7(a CHECK (myfunc(a))) } db2 447} {1 {no such function: myfunc}} 448 449do_test 7.7 { 450 db2 func myfunc myfunc 451 execsql { INSERT INTO t6 VALUES(8) } db2 452} {} 453 454do_test 7.8 { 455 db2 func myfunc myfunc 456 catchsql { INSERT INTO t6 VALUES(12) } db2 457} {1 {CHECK constraint failed: t6}} 458 459# 2013-08-02: Silently ignore database name qualifiers in CHECK constraints. 460# 461do_execsql_test 8.1 { 462 CREATE TABLE t810(a, CHECK( main.t810.a>0 )); 463 CREATE TABLE t811(b, CHECK( xyzzy.t811.b BETWEEN 5 AND 10 )); 464} {} 465 466# Make sure check constraints involving the ROWID are not ignored 467# 468do_execsql_test 9.1 { 469 CREATE TABLE t1( 470 a INTEGER PRIMARY KEY, 471 b INTEGER NOT NULL CONSTRAINT 'b-check' CHECK( b>a ), 472 c INTEGER NOT NULL CONSTRAINT 'c-check' CHECK( c>rowid*2 ), 473 d INTEGER NOT NULL CONSTRAINT 'd-check' CHECK( d BETWEEN b AND c ) 474 ); 475 INSERT INTO t1(a,b,c,d) VALUES(1,2,4,3),(2,4,6,5),(3,10,30,20); 476} {} 477do_catchsql_test 9.2 { 478 UPDATE t1 SET b=0 WHERE a=1; 479} {1 {CHECK constraint failed: b-check}} 480do_catchsql_test 9.3 { 481 UPDATE t1 SET c=a*2 WHERE a=1; 482} {1 {CHECK constraint failed: c-check}} 483 484# Integrity check on a VIEW with columns. 485# 486db close 487db2 close 488forcedelete test.db 489sqlite3 db test.db 490do_execsql_test 10.1 { 491 CREATE TABLE t1(x); 492 CREATE VIEW v1(y) AS SELECT x FROM t1; 493 PRAGMA integrity_check; 494} {ok} 495 496finish_test 497