xref: /sqlite-3.40.0/test/unique.test (revision f9c8ce3c)
1adbca9cfSdrh# 2001 September 27
2adbca9cfSdrh#
3adbca9cfSdrh# The author disclaims copyright to this source code.  In place of
4adbca9cfSdrh# a legal notice, here is a blessing:
5adbca9cfSdrh#
6adbca9cfSdrh#    May you do good and not evil.
7adbca9cfSdrh#    May you find forgiveness for yourself and forgive others.
8adbca9cfSdrh#    May you share freely, never taking more than you give.
9adbca9cfSdrh#
10adbca9cfSdrh#***********************************************************************
11adbca9cfSdrh# This file implements regression tests for SQLite library.  The
12adbca9cfSdrh# focus of this file is testing the CREATE UNIQUE INDEX statement,
13adbca9cfSdrh# and primary keys, and the UNIQUE constraint on table columns
14adbca9cfSdrh#
15098d1684Sdrh# $Id: unique.test,v 1.9 2009/05/02 15:46:47 drh Exp $
16adbca9cfSdrh
17adbca9cfSdrhset testdir [file dirname $argv0]
18adbca9cfSdrhsource $testdir/tester.tcl
19adbca9cfSdrh
20adbca9cfSdrh# Try to create a table with two primary keys.
21adbca9cfSdrh# (This is allowed in SQLite even that it is not valid SQL)
22adbca9cfSdrh#
23adbca9cfSdrhdo_test unique-1.1 {
24adbca9cfSdrh  catchsql {
25adbca9cfSdrh    CREATE TABLE t1(
26adbca9cfSdrh       a int PRIMARY KEY,
27adbca9cfSdrh       b int PRIMARY KEY,
28adbca9cfSdrh       c text
29adbca9cfSdrh    );
30adbca9cfSdrh  }
314a32431cSdrh} {1 {table "t1" has more than one primary key}}
324a32431cSdrhdo_test unique-1.1b {
334a32431cSdrh  catchsql {
344a32431cSdrh    CREATE TABLE t1(
354a32431cSdrh       a int PRIMARY KEY,
364a32431cSdrh       b int UNIQUE,
374a32431cSdrh       c text
384a32431cSdrh    );
394a32431cSdrh  }
40adbca9cfSdrh} {0 {}}
41743daaafSdrhdo_test unique-1.2 {
42743daaafSdrh  catchsql {
43743daaafSdrh    INSERT INTO t1(a,b,c) VALUES(1,2,3)
44743daaafSdrh  }
45743daaafSdrh} {0 {}}
46743daaafSdrhdo_test unique-1.3 {
47743daaafSdrh  catchsql {
48743daaafSdrh    INSERT INTO t1(a,b,c) VALUES(1,3,4)
49743daaafSdrh  }
50*f9c8ce3cSdrh} {1 {UNIQUE constraint failed: t1.a}}
5100012df4Sdrhverify_ex_errcode unique-1.3b SQLITE_CONSTRAINT_PRIMARYKEY
52743daaafSdrhdo_test unique-1.4 {
53743daaafSdrh  execsql {
54743daaafSdrh    SELECT * FROM t1 ORDER BY a;
55743daaafSdrh  }
56743daaafSdrh} {1 2 3}
57743daaafSdrhdo_test unique-1.5 {
58743daaafSdrh  catchsql {
59743daaafSdrh    INSERT INTO t1(a,b,c) VALUES(3,2,4)
60743daaafSdrh  }
61*f9c8ce3cSdrh} {1 {UNIQUE constraint failed: t1.b}}
62433dccfbSdrhverify_ex_errcode unique-1.5b SQLITE_CONSTRAINT_UNIQUE
63743daaafSdrhdo_test unique-1.6 {
64743daaafSdrh  execsql {
65743daaafSdrh    SELECT * FROM t1 ORDER BY a;
66743daaafSdrh  }
67743daaafSdrh} {1 2 3}
68743daaafSdrhdo_test unique-1.7 {
69743daaafSdrh  catchsql {
70743daaafSdrh    INSERT INTO t1(a,b,c) VALUES(3,4,5)
71743daaafSdrh  }
72743daaafSdrh} {0 {}}
73743daaafSdrhdo_test unique-1.8 {
74743daaafSdrh  execsql {
75743daaafSdrh    SELECT * FROM t1 ORDER BY a;
76743daaafSdrh  }
77743daaafSdrh} {1 2 3 3 4 5}
78ed717fe3Sdrhintegrity_check unique-1.9
79743daaafSdrh
80743daaafSdrhdo_test unique-2.0 {
81743daaafSdrh  execsql {
82743daaafSdrh    DROP TABLE t1;
83743daaafSdrh    CREATE TABLE t2(a int, b int);
84743daaafSdrh    INSERT INTO t2(a,b) VALUES(1,2);
85743daaafSdrh    INSERT INTO t2(a,b) VALUES(3,4);
86743daaafSdrh    SELECT * FROM t2 ORDER BY a;
87743daaafSdrh  }
88743daaafSdrh} {1 2 3 4}
89743daaafSdrhdo_test unique-2.1 {
90743daaafSdrh  catchsql {
91743daaafSdrh    CREATE UNIQUE INDEX i2 ON t2(a)
92743daaafSdrh  }
93743daaafSdrh} {0 {}}
94743daaafSdrhdo_test unique-2.2 {
95743daaafSdrh  catchsql {
96743daaafSdrh    SELECT * FROM t2 ORDER BY a
97743daaafSdrh  }
98743daaafSdrh} {0 {1 2 3 4}}
99743daaafSdrhdo_test unique-2.3 {
100743daaafSdrh  catchsql {
101743daaafSdrh    INSERT INTO t2 VALUES(1,5);
102743daaafSdrh  }
103*f9c8ce3cSdrh} {1 {UNIQUE constraint failed: t2.a}}
104433dccfbSdrhverify_ex_errcode unique-2.3b SQLITE_CONSTRAINT_UNIQUE
105743daaafSdrhdo_test unique-2.4 {
106743daaafSdrh  catchsql {
107743daaafSdrh    SELECT * FROM t2 ORDER BY a
108743daaafSdrh  }
109743daaafSdrh} {0 {1 2 3 4}}
110743daaafSdrhdo_test unique-2.5 {
111743daaafSdrh  catchsql {
112743daaafSdrh    DROP INDEX i2;
113743daaafSdrh    SELECT * FROM t2 ORDER BY a;
114743daaafSdrh  }
115743daaafSdrh} {0 {1 2 3 4}}
116743daaafSdrhdo_test unique-2.6 {
117743daaafSdrh  catchsql {
118743daaafSdrh    INSERT INTO t2 VALUES(1,5)
119743daaafSdrh  }
120743daaafSdrh} {0 {}}
121743daaafSdrhdo_test unique-2.7 {
122743daaafSdrh  catchsql {
123743daaafSdrh    SELECT * FROM t2 ORDER BY a, b;
124743daaafSdrh  }
125743daaafSdrh} {0 {1 2 1 5 3 4}}
126743daaafSdrhdo_test unique-2.8 {
127743daaafSdrh  catchsql {
128743daaafSdrh    CREATE UNIQUE INDEX i2 ON t2(a);
129743daaafSdrh  }
130*f9c8ce3cSdrh} {1 {UNIQUE constraint failed: t2.a}}
131433dccfbSdrhverify_ex_errcode unique-2.8b SQLITE_CONSTRAINT_UNIQUE
132743daaafSdrhdo_test unique-2.9 {
133743daaafSdrh  catchsql {
134743daaafSdrh    CREATE INDEX i2 ON t2(a);
135743daaafSdrh  }
136743daaafSdrh} {0 {}}
137ed717fe3Sdrhintegrity_check unique-2.10
138743daaafSdrh
139743daaafSdrh# Test the UNIQUE keyword as used on two or more fields.
140743daaafSdrh#
141743daaafSdrhdo_test unique-3.1 {
142743daaafSdrh  catchsql {
143743daaafSdrh    CREATE TABLE t3(
144743daaafSdrh       a int,
145743daaafSdrh       b int,
146743daaafSdrh       c int,
147743daaafSdrh       d int,
148743daaafSdrh       unique(a,c,d)
149743daaafSdrh     );
150743daaafSdrh  }
151743daaafSdrh} {0 {}}
152743daaafSdrhdo_test unique-3.2 {
153743daaafSdrh  catchsql {
154743daaafSdrh    INSERT INTO t3(a,b,c,d) VALUES(1,2,3,4);
155743daaafSdrh    SELECT * FROM t3 ORDER BY a,b,c,d;
156743daaafSdrh  }
157743daaafSdrh} {0 {1 2 3 4}}
158743daaafSdrhdo_test unique-3.3 {
159743daaafSdrh  catchsql {
160743daaafSdrh    INSERT INTO t3(a,b,c,d) VALUES(1,2,3,5);
161743daaafSdrh    SELECT * FROM t3 ORDER BY a,b,c,d;
162743daaafSdrh  }
163743daaafSdrh} {0 {1 2 3 4 1 2 3 5}}
164743daaafSdrhdo_test unique-3.4 {
165743daaafSdrh  catchsql {
166743daaafSdrh    INSERT INTO t3(a,b,c,d) VALUES(1,4,3,5);
167743daaafSdrh    SELECT * FROM t3 ORDER BY a,b,c,d;
168743daaafSdrh  }
169*f9c8ce3cSdrh} {1 {UNIQUE constraint failed: t3.a, t3.c, t3.d}}
170433dccfbSdrhverify_ex_errcode unique-3.4b SQLITE_CONSTRAINT_UNIQUE
171ed717fe3Sdrhintegrity_check unique-3.5
172adbca9cfSdrh
173f5905aa7Sdrh# Make sure NULLs are distinct as far as the UNIQUE tests are
174f5905aa7Sdrh# concerned.
175f5905aa7Sdrh#
176f5905aa7Sdrhdo_test unique-4.1 {
177f5905aa7Sdrh  execsql {
178f5905aa7Sdrh    CREATE TABLE t4(a UNIQUE, b, c, UNIQUE(b,c));
179f5905aa7Sdrh    INSERT INTO t4 VALUES(1,2,3);
180f5905aa7Sdrh    INSERT INTO t4 VALUES(NULL, 2, NULL);
181f5905aa7Sdrh    SELECT * FROM t4;
182f5905aa7Sdrh  }
183f5905aa7Sdrh} {1 2 3 {} 2 {}}
184f5905aa7Sdrhdo_test unique-4.2 {
185f5905aa7Sdrh  catchsql {
186f5905aa7Sdrh    INSERT INTO t4 VALUES(NULL, 3, 4);
187f5905aa7Sdrh  }
188f5905aa7Sdrh} {0 {}}
189f5905aa7Sdrhdo_test unique-4.3 {
190f5905aa7Sdrh  execsql {
191f5905aa7Sdrh    SELECT * FROM t4
192f5905aa7Sdrh  }
193f5905aa7Sdrh} {1 2 3 {} 2 {} {} 3 4}
194f5905aa7Sdrhdo_test unique-4.4 {
195f5905aa7Sdrh  catchsql {
196f5905aa7Sdrh    INSERT INTO t4 VALUES(2, 2, NULL);
197f5905aa7Sdrh  }
198f5905aa7Sdrh} {0 {}}
199f5905aa7Sdrhdo_test unique-4.5 {
200f5905aa7Sdrh  execsql {
201f5905aa7Sdrh    SELECT * FROM t4
202f5905aa7Sdrh  }
203f5905aa7Sdrh} {1 2 3 {} 2 {} {} 3 4 2 2 {}}
2047f057c91Sdrh
2057f057c91Sdrh# Ticket #1301.  Any NULL value in a set of unique columns should
2067f057c91Sdrh# cause the rows to be distinct.
2077f057c91Sdrh#
2087f057c91Sdrhdo_test unique-4.6 {
2097f057c91Sdrh  catchsql {
2107f057c91Sdrh    INSERT INTO t4 VALUES(NULL, 2, NULL);
2117f057c91Sdrh  }
2127f057c91Sdrh} {0 {}}
2137f057c91Sdrhdo_test unique-4.7 {
2147f057c91Sdrh  execsql {SELECT * FROM t4}
2157f057c91Sdrh} {1 2 3 {} 2 {} {} 3 4 2 2 {} {} 2 {}}
2167f057c91Sdrhdo_test unique-4.8 {
2177f057c91Sdrh  catchsql {CREATE UNIQUE INDEX i4a ON t4(a,b)}
2187f057c91Sdrh} {0 {}}
2197f057c91Sdrhdo_test unique-4.9 {
2207f057c91Sdrh  catchsql {CREATE UNIQUE INDEX i4b ON t4(a,b,c)}
2217f057c91Sdrh} {0 {}}
2227f057c91Sdrhdo_test unique-4.10 {
2237f057c91Sdrh  catchsql {CREATE UNIQUE INDEX i4c ON t4(b)}
224*f9c8ce3cSdrh} {1 {UNIQUE constraint failed: t4.b}}
225433dccfbSdrhverify_ex_errcode unique-4.10b SQLITE_CONSTRAINT_UNIQUE
2267f057c91Sdrhintegrity_check unique-4.99
227f5905aa7Sdrh
22837ed48edSdrh# Test the error message generation logic.  In particular, make sure we
22937ed48edSdrh# do not overflow the static buffer used to generate the error message.
23037ed48edSdrh#
23137ed48edSdrhdo_test unique-5.1 {
23237ed48edSdrh  execsql {
23337ed48edSdrh    CREATE TABLE t5(
23437ed48edSdrh      first_column_with_long_name,
23537ed48edSdrh      second_column_with_long_name,
23637ed48edSdrh      third_column_with_long_name,
23737ed48edSdrh      fourth_column_with_long_name,
23837ed48edSdrh      fifth_column_with_long_name,
23937ed48edSdrh      sixth_column_with_long_name,
24037ed48edSdrh      UNIQUE(
24137ed48edSdrh        first_column_with_long_name,
24237ed48edSdrh        second_column_with_long_name,
24337ed48edSdrh        third_column_with_long_name,
24437ed48edSdrh        fourth_column_with_long_name,
24537ed48edSdrh        fifth_column_with_long_name,
24637ed48edSdrh        sixth_column_with_long_name
24737ed48edSdrh      )
24837ed48edSdrh    );
24937ed48edSdrh    INSERT INTO t5 VALUES(1,2,3,4,5,6);
25037ed48edSdrh    SELECT * FROM t5;
25137ed48edSdrh  }
25237ed48edSdrh} {1 2 3 4 5 6}
25337ed48edSdrhdo_test unique-5.2 {
25437ed48edSdrh  catchsql {
25537ed48edSdrh    INSERT INTO t5 VALUES(1,2,3,4,5,6);
25637ed48edSdrh  }
257*f9c8ce3cSdrh} {1 {UNIQUE constraint failed: t5.first_column_with_long_name, t5.second_column_with_long_name, t5.third_column_with_long_name, t5.fourth_column_with_long_name, t5.fifth_column_with_long_name, t5.sixth_column_with_long_name}}
258433dccfbSdrhverify_ex_errcode unique-5.2b SQLITE_CONSTRAINT_UNIQUE
259433dccfbSdrh
26037ed48edSdrh
261adbca9cfSdrhfinish_test
262