xref: /sqlite-3.40.0/test/check.test (revision 4dc330dd)
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
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 {constraint failed}}
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 {constraint failed}}
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 {constraint failed}}
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 {constraint failed}}
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    CREATE TABLE t2(
120      x INTEGER CONSTRAINT one CHECK( typeof(coalesce(x,0))=="integer" ),
121      y REAL CONSTRAINT two CHECK( typeof(coalesce(y,0.1))=='real' ),
122      z TEXT CONSTRAINT three CHECK( typeof(coalesce(z,''))=='text' )
123    );
124  }
125} {}
126do_test check-2.2 {
127  execsql {
128    INSERT INTO t2 VALUES(1,2.2,'three');
129    SELECT * FROM t2;
130  }
131} {1 2.2 three}
132db close
133sqlite3 db test.db
134do_test check-2.3 {
135  execsql {
136    INSERT INTO t2 VALUES(NULL, NULL, NULL);
137    SELECT * FROM t2;
138  }
139} {1 2.2 three {} {} {}}
140do_test check-2.4 {
141  catchsql {
142    INSERT INTO t2 VALUES(1.1, NULL, NULL);
143  }
144} {1 {constraint one failed}}
145do_test check-2.5 {
146  catchsql {
147    INSERT INTO t2 VALUES(NULL, 5, NULL);
148  }
149} {1 {constraint two failed}}
150do_test check-2.6 {
151  catchsql {
152    INSERT INTO t2 VALUES(NULL, NULL, 3.14159);
153  }
154} {1 {constraint three failed}}
155
156# Undocumented behavior:  The CONSTRAINT name clause can follow a constraint.
157# Such a clause is ignored.  But the parser must accept it for backwards
158# compatibility.
159#
160do_test check-2.10 {
161  execsql {
162    CREATE TABLE t2b(
163      x INTEGER CHECK( typeof(coalesce(x,0))=='integer' ) CONSTRAINT one,
164      y TEXT PRIMARY KEY constraint two,
165      z INTEGER,
166      UNIQUE(x,z) constraint three
167    );
168  }
169} {}
170do_test check-2.11 {
171  catchsql {
172    INSERT INTO t2b VALUES('xyzzy','hi',5);
173  }
174} {1 {constraint failed}}
175do_test check-2.12 {
176  execsql {
177    CREATE TABLE t2c(
178      x INTEGER CONSTRAINT x_one CONSTRAINT x_two
179          CHECK( typeof(coalesce(x,0))=='integer' )
180          CONSTRAINT x_two CONSTRAINT x_three,
181      y INTEGER, z INTEGER,
182      CONSTRAINT u_one UNIQUE(x,y,z) CONSTRAINT u_two
183    );
184  }
185} {}
186do_test check-2.13 {
187  catchsql {
188    INSERT INTO t2c VALUES('xyzzy',7,8);
189  }
190} {1 {constraint x_two failed}}
191do_test check-2.cleanup {
192  execsql {
193    DROP TABLE IF EXISTS t2b;
194    DROP TABLE IF EXISTS t2c;
195  }
196} {}
197
198ifcapable subquery {
199  do_test check-3.1 {
200    catchsql {
201      CREATE TABLE t3(
202        x, y, z,
203        CHECK( x<(SELECT min(x) FROM t1) )
204      );
205    }
206  } {1 {subqueries prohibited in CHECK constraints}}
207}
208
209do_test check-3.2 {
210  execsql {
211    SELECT name FROM sqlite_master ORDER BY name
212  }
213} {t1 t2}
214do_test check-3.3 {
215  catchsql {
216    CREATE TABLE t3(
217      x, y, z,
218      CHECK( q<x )
219    );
220  }
221} {1 {no such column: q}}
222do_test check-3.4 {
223  execsql {
224    SELECT name FROM sqlite_master ORDER BY name
225  }
226} {t1 t2}
227do_test check-3.5 {
228  catchsql {
229    CREATE TABLE t3(
230      x, y, z,
231      CHECK( t2.x<x )
232    );
233  }
234} {1 {no such column: t2.x}}
235do_test check-3.6 {
236  execsql {
237    SELECT name FROM sqlite_master ORDER BY name
238  }
239} {t1 t2}
240do_test check-3.7 {
241  catchsql {
242    CREATE TABLE t3(
243      x, y, z,
244      CHECK( t3.x<25 )
245    );
246  }
247} {0 {}}
248do_test check-3.8 {
249  execsql {
250    INSERT INTO t3 VALUES(1,2,3);
251    SELECT * FROM t3;
252  }
253} {1 2 3}
254do_test check-3.9 {
255  catchsql {
256    INSERT INTO t3 VALUES(111,222,333);
257  }
258} {1 {constraint failed}}
259
260do_test check-4.1 {
261  execsql {
262    CREATE TABLE t4(x, y,
263      CHECK (
264           x+y==11
265        OR x*y==12
266        OR x/y BETWEEN 5 AND 8
267        OR -x==y+10
268      )
269    );
270  }
271} {}
272do_test check-4.2 {
273  execsql {
274    INSERT INTO t4 VALUES(1,10);
275    SELECT * FROM t4
276  }
277} {1 10}
278do_test check-4.3 {
279  execsql {
280    UPDATE t4 SET x=4, y=3;
281    SELECT * FROM t4
282  }
283} {4 3}
284do_test check-4.4 {
285  execsql {
286    UPDATE t4 SET x=12, y=2;
287    SELECT * FROM t4
288  }
289} {12 2}
290do_test check-4.5 {
291  execsql {
292    UPDATE t4 SET x=12, y=-22;
293    SELECT * FROM t4
294  }
295} {12 -22}
296do_test check-4.6 {
297  catchsql {
298    UPDATE t4 SET x=0, y=1;
299  }
300} {1 {constraint failed}}
301do_test check-4.7 {
302  execsql {
303    SELECT * FROM t4;
304  }
305} {12 -22}
306do_test check-4.8 {
307  execsql {
308    PRAGMA ignore_check_constraints=ON;
309    UPDATE t4 SET x=0, y=1;
310    SELECT * FROM t4;
311  }
312} {0 1}
313do_test check-4.9 {
314  catchsql {
315    PRAGMA ignore_check_constraints=OFF;
316    UPDATE t4 SET x=0, y=2;
317  }
318} {1 {constraint failed}}
319ifcapable vacuum {
320  do_test check_4.10 {
321    catchsql {
322      VACUUM
323    }
324  } {0 {}}
325}
326
327do_test check-5.1 {
328  catchsql {
329    CREATE TABLE t5(x, y,
330      CHECK( x*y<:abc )
331    );
332  }
333} {1 {parameters prohibited in CHECK constraints}}
334do_test check-5.2 {
335  catchsql {
336    CREATE TABLE t5(x, y,
337      CHECK( x*y<? )
338    );
339  }
340} {1 {parameters prohibited in CHECK constraints}}
341
342ifcapable conflict {
343
344do_test check-6.1 {
345  execsql {SELECT * FROM t1}
346} {4 11.0}
347do_test check-6.2 {
348  execsql {
349    UPDATE OR IGNORE t1 SET x=5;
350    SELECT * FROM t1;
351  }
352} {4 11.0}
353do_test check-6.3 {
354  execsql {
355    INSERT OR IGNORE INTO t1 VALUES(5,4.0);
356    SELECT * FROM t1;
357  }
358} {4 11.0}
359do_test check-6.4 {
360  execsql {
361    INSERT OR IGNORE INTO t1 VALUES(2,20.0);
362    SELECT * FROM t1;
363  }
364} {4 11.0 2 20.0}
365do_test check-6.5 {
366  catchsql {
367    UPDATE OR FAIL t1 SET x=7-x, y=y+1;
368  }
369} {1 {constraint failed}}
370do_test check-6.6 {
371  execsql {
372    SELECT * FROM t1;
373  }
374} {3 12.0 2 20.0}
375do_test check-6.7 {
376  catchsql {
377    BEGIN;
378    INSERT INTO t1 VALUES(1,30.0);
379    INSERT OR ROLLBACK INTO t1 VALUES(8,40.0);
380  }
381} {1 {constraint failed}}
382do_test check-6.8 {
383  catchsql {
384    COMMIT;
385  }
386} {1 {cannot commit - no transaction is active}}
387do_test check-6.9 {
388  execsql {
389    SELECT * FROM t1
390  }
391} {3 12.0 2 20.0}
392
393do_test check-6.11 {
394  execsql {SELECT * FROM t1}
395} {3 12.0 2 20.0}
396do_test check-6.12 {
397  catchsql {
398    REPLACE INTO t1 VALUES(6,7);
399  }
400} {1 {constraint failed}}
401do_test check-6.13 {
402  execsql {SELECT * FROM t1}
403} {3 12.0 2 20.0}
404do_test check-6.14 {
405  catchsql {
406    INSERT OR IGNORE INTO t1 VALUES(6,7);
407  }
408} {0 {}}
409do_test check-6.15 {
410  execsql {SELECT * FROM t1}
411} {3 12.0 2 20.0}
412
413
414}
415
416finish_test
417