xref: /sqlite-3.40.0/test/alterdropcol2.test (revision 0ca23aa4)
1d97471e1Sdan# 2021 February 19
2d97471e1Sdan#
3d97471e1Sdan# The author disclaims copyright to this source code.  In place of
4d97471e1Sdan# a legal notice, here is a blessing:
5d97471e1Sdan#
6d97471e1Sdan#    May you do good and not evil.
7d97471e1Sdan#    May you find forgiveness for yourself and forgive others.
8d97471e1Sdan#    May you share freely, never taking more than you give.
9d97471e1Sdan#
10d97471e1Sdan#*************************************************************************
11d97471e1Sdan#
12d97471e1Sdan
13d97471e1Sdanset testdir [file dirname $argv0]
14d97471e1Sdansource $testdir/tester.tcl
15d97471e1Sdanset testprefix alterdropcol2
16d97471e1Sdan
17d97471e1Sdan# If SQLITE_OMIT_ALTERTABLE is defined, omit this file.
18d97471e1Sdanifcapable !altertable {
19d97471e1Sdan  finish_test
20d97471e1Sdan  return
21d97471e1Sdan}
22d97471e1Sdan
23d97471e1Sdan# EVIDENCE-OF: R-58318-35349 The DROP COLUMN syntax is used to remove an
24d97471e1Sdan# existing column from a table.
25d97471e1Sdando_execsql_test 1.0 {
26d97471e1Sdan  CREATE TABLE t1(c, b, a, PRIMARY KEY(b, a)) WITHOUT ROWID;
27d97471e1Sdan  INSERT INTO t1 VALUES(1, 2, 3), (4, 5, 6);
28d97471e1Sdan}
29d97471e1Sdando_execsql_test 1.1 {
30d97471e1Sdan  ALTER TABLE t1 DROP c;
31d97471e1Sdan}
32d97471e1Sdan
33d97471e1Sdan# EVIDENCE-OF: The DROP COLUMN command removes the named column from the table,
34d97471e1Sdan# and also rewrites the entire table to purge the data associated with that
35d97471e1Sdan# column.
36d97471e1Sdando_execsql_test 1.2.1 {
37d97471e1Sdan  SELECT * FROM t1;
38d97471e1Sdan} {2 3   5 6}
39d97471e1Sdan
40d97471e1Sdando_execsql_test 1.2.2 {
41d97471e1Sdan  SELECT sql FROM sqlite_schema;
42d97471e1Sdan} {
43d97471e1Sdan  {CREATE TABLE t1(b, a, PRIMARY KEY(b, a)) WITHOUT ROWID}
44d97471e1Sdan}
45d97471e1Sdan
46d97471e1Sdanproc do_atdc_error_test {tn schema atdc error} {
47d97471e1Sdan  reset_db
48d97471e1Sdan  execsql $schema
49d97471e1Sdan  uplevel [list do_catchsql_test $tn $atdc [list 1 [string trim $error]]]
50d97471e1Sdan}
51d97471e1Sdan
52d97471e1Sdan#-------------------------------------------------------------------------
53d97471e1Sdan# Test cases 2.* attempt to verify the following:
54d97471e1Sdan#
55d97471e1Sdan# EVIDENCE-OF: R-24098-10282 The DROP COLUMN command only works if the column
56d97471e1Sdan# is not referenced by any other parts of the schema and is not a PRIMARY KEY
57d97471e1Sdan# and does not have a UNIQUE constraint.
58d97471e1Sdan#
59d97471e1Sdan
60*0ca23aa4Sdrh# EVIDENCE-OF: R-52436-31752 The column is a PRIMARY KEY or part of one.
61d97471e1Sdan#
62d97471e1Sdando_atdc_error_test 2.1.1 {
63d97471e1Sdan  CREATE TABLE x1(a PRIMARY KEY, b, c);
64d97471e1Sdan} {
65d97471e1Sdan  ALTER TABLE x1 DROP COLUMN a
66d97471e1Sdan} {
67d97471e1Sdan  cannot drop PRIMARY KEY column: "a"
68d97471e1Sdan}
69*0ca23aa4Sdrhdo_atdc_error_test 2.1.2 {
70*0ca23aa4Sdrh  CREATE TABLE x1(a,b,c,d,e, PRIMARY KEY(b,c,d));
71*0ca23aa4Sdrh} {
72*0ca23aa4Sdrh  ALTER TABLE x1 DROP COLUMN c
73*0ca23aa4Sdrh} {
74*0ca23aa4Sdrh  cannot drop PRIMARY KEY column: "c"
75*0ca23aa4Sdrh}
76d97471e1Sdan
77d97471e1Sdan# EVIDENCE-OF: R-43412-16016 The column has a UNIQUE constraint.
78d97471e1Sdan#
79d97471e1Sdando_atdc_error_test 2.2.1 {
80d97471e1Sdan  CREATE TABLE x1(a PRIMARY KEY, b, c UNIQUE);
81d97471e1Sdan} {
82d97471e1Sdan  ALTER TABLE x1 DROP COLUMN c
83d97471e1Sdan} {
84d97471e1Sdan  cannot drop UNIQUE column: "c"
85d97471e1Sdan}
86d97471e1Sdando_atdc_error_test 2.2.2 {
87d97471e1Sdan  CREATE TABLE x1(a PRIMARY KEY, b, c, UNIQUE(b, c));
88d97471e1Sdan} {
89d97471e1Sdan  ALTER TABLE x1 DROP COLUMN c
90d97471e1Sdan} {
91d97471e1Sdan  error in table x1 after drop column: no such column: c
92d97471e1Sdan}
93d97471e1Sdan
94*0ca23aa4Sdrh# EVIDENCE-OF: R-46731-08965 The column is indexed.
95d97471e1Sdan#
96d97471e1Sdando_atdc_error_test 2.3.1 {
97d97471e1Sdan  CREATE TABLE 'one two'('x y', 'z 1', 'a b');
98d97471e1Sdan  CREATE INDEX idx ON 'one two'('z 1');
99d97471e1Sdan} {
100d97471e1Sdan  ALTER TABLE 'one two' DROP COLUMN 'z 1'
101d97471e1Sdan} {
102d97471e1Sdan  error in index idx after drop column: no such column: z 1
103d97471e1Sdan}
104d97471e1Sdando_atdc_error_test 2.3.2 {
105d97471e1Sdan  CREATE TABLE x1(a, b, c);
106d97471e1Sdan  CREATE INDEX idx ON x1(a);
107d97471e1Sdan} {
108d97471e1Sdan  ALTER TABLE x1 DROP COLUMN a;
109d97471e1Sdan} {
110d97471e1Sdan  error in index idx after drop column: no such column: a
111d97471e1Sdan}
112d97471e1Sdan
113*0ca23aa4Sdrh# EVIDENCE-OF: R-46731-08965 The column is indexed.
114d97471e1Sdan#
115d97471e1Sdando_atdc_error_test 2.4.1 {
116d97471e1Sdan  CREATE TABLE x1234(a, b, c PRIMARY KEY) WITHOUT ROWID;
117d97471e1Sdan  CREATE INDEX i1 ON x1234(b) WHERE ((a+5) % 10)==0;
118d97471e1Sdan} {
119d97471e1Sdan  ALTER TABLE x1234 DROP a
120d97471e1Sdan} {
121d97471e1Sdan  error in index i1 after drop column: no such column: a
122d97471e1Sdan}
123d97471e1Sdan
124*0ca23aa4Sdrh# EVIDENCE-OF: R-47838-03249 The column is named in a table or column
125*0ca23aa4Sdrh# CHECK constraint not associated with the column being dropped.
126d97471e1Sdan#
127d97471e1Sdando_atdc_error_test 2.5.1 {
128d97471e1Sdan  CREATE TABLE x1234(a, b, c PRIMARY KEY, CHECK(((a+5)%10)!=0)) WITHOUT ROWID;
129d97471e1Sdan} {
130d97471e1Sdan  ALTER TABLE x1234 DROP a
131d97471e1Sdan} {
132d97471e1Sdan  error in table x1234 after drop column: no such column: a
133d97471e1Sdan}
134d97471e1Sdan
135d97471e1Sdan# EVIDENCE-OF: R-55640-01652 The column is used in a foreign key constraint.
136d97471e1Sdan#
137d97471e1Sdando_atdc_error_test 2.6.1 {
138d97471e1Sdan  CREATE TABLE p1(x, y UNIQUE);
139d97471e1Sdan  CREATE TABLE c1(u, v, FOREIGN KEY (v) REFERENCES p1(y))
140d97471e1Sdan} {
141d97471e1Sdan  ALTER TABLE c1 DROP v
142d97471e1Sdan} {
143d97471e1Sdan  error in table c1 after drop column: unknown column "v" in foreign key definition
144d97471e1Sdan}
145d97471e1Sdan
146d97471e1Sdan# EVIDENCE-OF: R-20795-39479 The column is used in the expression of a
147d97471e1Sdan# generated column.
148d97471e1Sdando_atdc_error_test 2.7.1 {
149d97471e1Sdan  CREATE TABLE c1(u, v, w AS (u+v));
150d97471e1Sdan} {
151d97471e1Sdan  ALTER TABLE c1 DROP v
152d97471e1Sdan} {
153d97471e1Sdan  error in table c1 after drop column: no such column: v
154d97471e1Sdan}
155d97471e1Sdando_atdc_error_test 2.7.2 {
156d97471e1Sdan  CREATE TABLE c1(u, v, w AS (u+v) STORED);
157d97471e1Sdan} {
158d97471e1Sdan  ALTER TABLE c1 DROP u
159d97471e1Sdan} {
160d97471e1Sdan  error in table c1 after drop column: no such column: u
161d97471e1Sdan}
162d97471e1Sdan
163d97471e1Sdan# EVIDENCE-OF: R-01515-49025 The column appears in a trigger or view.
164d97471e1Sdan#
165d97471e1Sdando_atdc_error_test 2.8.1 {
166d97471e1Sdan  CREATE TABLE log(l);
167d97471e1Sdan  CREATE TABLE c1(u, v, w);
168d97471e1Sdan  CREATE TRIGGER tr1 AFTER INSERT ON c1 BEGIN
169d97471e1Sdan    INSERT INTO log VALUES(new.w);
170d97471e1Sdan  END;
171d97471e1Sdan} {
172d97471e1Sdan  ALTER TABLE c1 DROP w
173d97471e1Sdan} {
174d97471e1Sdan  error in trigger tr1 after drop column: no such column: new.w
175d97471e1Sdan}
176d97471e1Sdando_atdc_error_test 2.8.2 {
177d97471e1Sdan  CREATE TABLE c1(u, v, w);
178d97471e1Sdan  CREATE VIEW v1 AS SELECT u, v, w FROM c1;
179d97471e1Sdan} {
180d97471e1Sdan  ALTER TABLE c1 DROP w
181d97471e1Sdan} {
182d97471e1Sdan  error in view v1 after drop column: no such column: w
183d97471e1Sdan}
184d97471e1Sdando_atdc_error_test 2.8.3 {
185d97471e1Sdan  CREATE TABLE c1(u, v, w);
186d97471e1Sdan  CREATE VIEW v1 AS SELECT * FROM c1 WHERE w IS NOT NULL;
187d97471e1Sdan} {
188d97471e1Sdan  ALTER TABLE c1 DROP w
189d97471e1Sdan} {
190d97471e1Sdan  error in view v1 after drop column: no such column: w
191d97471e1Sdan}
192d97471e1Sdan
193d97471e1Sdan#-------------------------------------------------------------------------
194d97471e1Sdan# Verify that a column that is part of a CHECK constraint may be dropped
195d97471e1Sdan# if the CHECK constraint was specified as part of the column definition.
196d97471e1Sdan#
197d97471e1Sdan
198*0ca23aa4Sdrh# STALE-EVIDENCE: R-60924-11170 However, the column being deleted can be used in a
199d97471e1Sdan# column CHECK constraint because the column CHECK constraint is dropped
200d97471e1Sdan# together with the column itself.
201d97471e1Sdando_execsql_test 3.0 {
202d97471e1Sdan  CREATE TABLE yyy(q, w, e CHECK (e > 0), r);
203d97471e1Sdan  INSERT INTO yyy VALUES(1,1,1,1), (2,2,2,2);
204d97471e1Sdan
205d97471e1Sdan  CREATE TABLE zzz(q, w, e, r, CHECK (e > 0));
206d97471e1Sdan  INSERT INTO zzz VALUES(1,1,1,1), (2,2,2,2);
207d97471e1Sdan}
208d97471e1Sdando_catchsql_test 3.1.1 {
209d97471e1Sdan  INSERT INTO yyy VALUES(0,0,0,0);
210d97471e1Sdan} {1 {CHECK constraint failed: e > 0}}
211d97471e1Sdando_catchsql_test 3.1.2 {
212d97471e1Sdan  INSERT INTO yyy VALUES(0,0,0,0);
213d97471e1Sdan} {1 {CHECK constraint failed: e > 0}}
214d97471e1Sdan
215d97471e1Sdando_execsql_test 3.2.1 {
216d97471e1Sdan  ALTER TABLE yyy DROP e;
217d97471e1Sdan}
218d97471e1Sdando_catchsql_test 3.2.2 {
219d97471e1Sdan  ALTER TABLE zzz DROP e;
220d97471e1Sdan} {1 {error in table zzz after drop column: no such column: e}}
221d97471e1Sdan
222d97471e1Sdanfinish_test
223