xref: /sqlite-3.40.0/test/altertab2.test (revision 62fc069e)
134566c44Sdan# 2018 September 30
234566c44Sdan#
334566c44Sdan# The author disclaims copyright to this source code.  In place of
434566c44Sdan# a legal notice, here is a blessing:
534566c44Sdan#
634566c44Sdan#    May you do good and not evil.
734566c44Sdan#    May you find forgiveness for yourself and forgive others.
834566c44Sdan#    May you share freely, never taking more than you give.
934566c44Sdan#
1034566c44Sdan#*************************************************************************
1134566c44Sdan#
1234566c44Sdan
1334566c44Sdanset testdir [file dirname $argv0]
1434566c44Sdansource $testdir/tester.tcl
15ea41251eSdanset testprefix altertab2
1634566c44Sdan
1734566c44Sdan# If SQLITE_OMIT_ALTERTABLE is defined, omit this file.
1834566c44Sdanifcapable !altertable {
1934566c44Sdan  finish_test
2034566c44Sdan  return
2134566c44Sdan}
2234566c44Sdan
2334566c44Sdanifcapable fts5 {
2434566c44Sdan  do_execsql_test 1.0 {
2534566c44Sdan    CREATE TABLE rr(a, b);
2634566c44Sdan    CREATE VIRTUAL TABLE ff USING fts5(a, b);
2734566c44Sdan    CREATE TRIGGER tr1 AFTER INSERT ON rr BEGIN
2834566c44Sdan      INSERT INTO ff VALUES(new.a, new.b);
2934566c44Sdan    END;
3034566c44Sdan    INSERT INTO rr VALUES('hello', 'world');
3134566c44Sdan    SELECT * FROM ff;
3234566c44Sdan  } {hello world}
3334566c44Sdan
3434566c44Sdan  do_execsql_test 1.1 {
3534566c44Sdan    ALTER TABLE ff RENAME TO ffff;
3634566c44Sdan  }
3734566c44Sdan
3834566c44Sdan  do_execsql_test 1.2 {
3934566c44Sdan    INSERT INTO rr VALUES('in', 'tcl');
4034566c44Sdan    SELECT * FROM ffff;
4134566c44Sdan  } {hello world in tcl}
4234566c44Sdan}
4334566c44Sdan
44b4307018Sdan#-------------------------------------------------------------------------
45b4307018Sdan# Check that table names that appear in REFERENCES clauses are updated
46b4307018Sdan# when a table is renamed unless:
47b4307018Sdan#
48b4307018Sdan#   a) "PRAGMA legacy_alter_table" is true, and
49b4307018Sdan#   b) "PRAGMA foreign_keys" is false.
50b4307018Sdan#
51b4307018Sdando_execsql_test 2.0 {
52b4307018Sdan  CREATE TABLE p1(a PRIMARY KEY, b);
53b4307018Sdan  CREATE TABLE c1(x REFERENCES p1);
54b4307018Sdan  CREATE TABLE c2(x, FOREIGN KEY (x) REFERENCES p1);
55b4307018Sdan  CREATE TABLE c3(x, FOREIGN KEY (x) REFERENCES p1(a));
56b4307018Sdan}
57b4307018Sdan
58b4307018Sdando_execsql_test 2.1 {
59b4307018Sdan  ALTER TABLE p1 RENAME TO p2;
60b4307018Sdan  SELECT sql FROM sqlite_master WHERE name LIKE 'c%';
61b4307018Sdan} {
62b4307018Sdan  {CREATE TABLE c1(x REFERENCES "p2")}
63b4307018Sdan  {CREATE TABLE c2(x, FOREIGN KEY (x) REFERENCES "p2")}
64b4307018Sdan  {CREATE TABLE c3(x, FOREIGN KEY (x) REFERENCES "p2"(a))}
65b4307018Sdan}
66b4307018Sdan
67b4307018Sdando_execsql_test 2.2 {
68b4307018Sdan  PRAGMA legacy_alter_table = 1;
69b4307018Sdan  ALTER TABLE p2 RENAME TO p3;
70b4307018Sdan  SELECT sql FROM sqlite_master WHERE name LIKE 'c%';
71b4307018Sdan} {
72b4307018Sdan  {CREATE TABLE c1(x REFERENCES "p2")}
73b4307018Sdan  {CREATE TABLE c2(x, FOREIGN KEY (x) REFERENCES "p2")}
74b4307018Sdan  {CREATE TABLE c3(x, FOREIGN KEY (x) REFERENCES "p2"(a))}
75b4307018Sdan}
76b4307018Sdan
77b4307018Sdando_execsql_test 2.3 {
78b4307018Sdan  ALTER TABLE p3 RENAME TO p2;
79b4307018Sdan  PRAGMA foreign_keys = 1;
80b4307018Sdan  ALTER TABLE p2 RENAME TO p3;
81b4307018Sdan  SELECT sql FROM sqlite_master WHERE name LIKE 'c%';
82b4307018Sdan} {
83b4307018Sdan  {CREATE TABLE c1(x REFERENCES "p3")}
84b4307018Sdan  {CREATE TABLE c2(x, FOREIGN KEY (x) REFERENCES "p3")}
85b4307018Sdan  {CREATE TABLE c3(x, FOREIGN KEY (x) REFERENCES "p3"(a))}
86b4307018Sdan}
87b4307018Sdan
88ea41251eSdan#-------------------------------------------------------------------------
89ea41251eSdan# Table name in WITH clauses that are part of views or triggers.
90ea41251eSdan#
91ea41251eSdanforeach {tn schema} {
92ea41251eSdan  1 {
93ea41251eSdan    CREATE TABLE log_entry(col1, y);
94ea41251eSdan    CREATE INDEX i1 ON log_entry(col1);
95ea41251eSdan  }
96ea41251eSdan
97ea41251eSdan  2 {
98ea41251eSdan    CREATE TABLE t1(a, b, c);
99ea41251eSdan    CREATE TABLE t2(x);
100ea41251eSdan    CREATE TABLE log_entry(col1);
101ea41251eSdan    CREATE TRIGGER tr1 AFTER INSERT ON t1 BEGIN
102ea41251eSdan      INSERT INTO t2 SELECT col1 FROM log_entry;
103ea41251eSdan    END;
104ea41251eSdan  }
105ea41251eSdan
106ea41251eSdan  3 {
107ea41251eSdan    CREATE TABLE t1(a, b, c);
108ea41251eSdan    CREATE TABLE t2(x);
109ea41251eSdan    CREATE TABLE log_entry(col1);
110ea41251eSdan    CREATE TRIGGER tr1 AFTER INSERT ON t1 BEGIN
111ea41251eSdan      INSERT INTO t2
112ea41251eSdan        WITH xyz(x) AS (SELECT col1 FROM log_entry)
113ea41251eSdan        SELECT x FROM xyz;
114ea41251eSdan    END;
115ea41251eSdan  }
116ea41251eSdan
117ea41251eSdan  4 {
118ea41251eSdan    CREATE TABLE log_entry(col1);
119ea41251eSdan    CREATE VIEW ttt AS
120ea41251eSdan        WITH xyz(x) AS (SELECT col1 FROM log_entry)
121ea41251eSdan        SELECT x FROM xyz;
122ea41251eSdan  }
123ea41251eSdan} {
124ea41251eSdan  reset_db
125ea41251eSdan  do_execsql_test 3.$tn.1 $schema
126ea41251eSdan  set expect [db eval "SELECT sql FROM sqlite_master"]
127ea41251eSdan  set expect [string map {log_entry {"newname"}} $expect]
128ea41251eSdan
129ea41251eSdan  do_execsql_test 3.$tn.2 {
130ea41251eSdan    ALTER TABLE log_entry RENAME TO newname;
131ea41251eSdan    SELECT sql FROM sqlite_master;
132ea41251eSdan  } $expect
133ea41251eSdan
134ea41251eSdan  reset_db
135ea41251eSdan  do_execsql_test 3.$tn.3 $schema
136ea41251eSdan  set expect [db eval "SELECT sql FROM sqlite_master"]
137ea41251eSdan  set expect [string map {col1 newname} $expect]
138ea41251eSdan
139ea41251eSdan  do_execsql_test 3.$tn.4 {
140ea41251eSdan    ALTER TABLE log_entry RENAME col1 TO newname;
141ea41251eSdan    SELECT sql FROM sqlite_master;
142ea41251eSdan  } $expect
143ea41251eSdan}
14434566c44Sdan
145dfb5c963Sdan#-------------------------------------------------------------------------
146dfb5c963Sdanreset_db
147dfb5c963Sdando_execsql_test 4.0 {
148dfb5c963Sdan  CREATE TABLE t1(a,b,c,d,e,f);
149dfb5c963Sdan  CREATE TRIGGER r1 AFTER INSERT ON t1 WHEN new.a NOT NULL BEGIN
150dfb5c963Sdan    UPDATE t1 SET (c,d)=(a,b);
151dfb5c963Sdan  END;
152dfb5c963Sdan}
153dfb5c963Sdan
154dfb5c963Sdando_execsql_test 4.1 {
155dfb5c963Sdan  ALTER TABLE t1 RENAME TO t1x;
156dfb5c963Sdan  SELECT sql FROM sqlite_master WHERE type = 'trigger';
157dfb5c963Sdan} {
158dfb5c963Sdan{CREATE TRIGGER r1 AFTER INSERT ON "t1x" WHEN new.a NOT NULL BEGIN
159dfb5c963Sdan    UPDATE "t1x" SET (c,d)=(a,b);
160dfb5c963Sdan  END}
161dfb5c963Sdan}
162dfb5c963Sdan
163dfb5c963Sdando_execsql_test 4.2 {
164dfb5c963Sdan  ALTER TABLE t1x RENAME a TO aaa;
165dfb5c963Sdan  SELECT sql FROM sqlite_master WHERE type = 'trigger';
166dfb5c963Sdan} {
167dfb5c963Sdan{CREATE TRIGGER r1 AFTER INSERT ON "t1x" WHEN new.aaa NOT NULL BEGIN
168dfb5c963Sdan    UPDATE "t1x" SET (c,d)=(aaa,b);
169dfb5c963Sdan  END}
170dfb5c963Sdan}
171dfb5c963Sdan
172dfb5c963Sdando_execsql_test 4.3 {
173dfb5c963Sdan  ALTER TABLE t1x RENAME d TO ddd;
174dfb5c963Sdan  SELECT sql FROM sqlite_master WHERE type = 'trigger';
175dfb5c963Sdan} {
176dfb5c963Sdan{CREATE TRIGGER r1 AFTER INSERT ON "t1x" WHEN new.aaa NOT NULL BEGIN
177dfb5c963Sdan    UPDATE "t1x" SET (c,ddd)=(aaa,b);
178dfb5c963Sdan  END}
179dfb5c963Sdan}
180dfb5c963Sdan
181fb8ac325Sdan#-------------------------------------------------------------------------
1828cd2e4aeSdanifcapable windowfunc {
183fb8ac325Sdando_execsql_test 5.0 {
184fb8ac325Sdan  CREATE TABLE t2(a);
185fb8ac325Sdan  CREATE TRIGGER r2 AFTER INSERT ON t2 WHEN new.a NOT NULL BEGIN
186d9995031Sdan    SELECT a, sum(a) OVER w1 FROM t2
187fb8ac325Sdan      WINDOW w1 AS (
188d9995031Sdan        PARTITION BY a ORDER BY a
189d9995031Sdan        ROWS BETWEEN 2 PRECEDING AND 3 FOLLOWING
190fb8ac325Sdan      ),
191fb8ac325Sdan      w2 AS (
192d9995031Sdan        PARTITION BY a
193d9995031Sdan        ORDER BY rowid ROWS BETWEEN CURRENT ROW AND UNBOUNDED FOLLOWING
194fb8ac325Sdan      );
195fb8ac325Sdan  END;
196fb8ac325Sdan} {}
197fb8ac325Sdan
198d9995031Sdando_execsql_test 5.0.1 {
199fb8ac325Sdan  INSERT INTO t2 VALUES(1);
200d9995031Sdan} {}
201fb8ac325Sdan
202fb8ac325Sdando_execsql_test 5.1 {
203fb8ac325Sdan  ALTER TABLE t2 RENAME TO t2x;
204fb8ac325Sdan  SELECT sql FROM sqlite_master WHERE name = 'r2';
205fb8ac325Sdan} {
206fb8ac325Sdan  {CREATE TRIGGER r2 AFTER INSERT ON "t2x" WHEN new.a NOT NULL BEGIN
207d9995031Sdan    SELECT a, sum(a) OVER w1 FROM "t2x"
208fb8ac325Sdan      WINDOW w1 AS (
209d9995031Sdan        PARTITION BY a ORDER BY a
210d9995031Sdan        ROWS BETWEEN 2 PRECEDING AND 3 FOLLOWING
211fb8ac325Sdan      ),
212fb8ac325Sdan      w2 AS (
213d9995031Sdan        PARTITION BY a
214d9995031Sdan        ORDER BY rowid ROWS BETWEEN CURRENT ROW AND UNBOUNDED FOLLOWING
215fb8ac325Sdan      );
216fb8ac325Sdan  END}
217fb8ac325Sdan}
218fb8ac325Sdan
219fb8ac325Sdando_execsql_test 5.2 {
220fb8ac325Sdan  ALTER TABLE t2x RENAME a TO aaaa;
221fb8ac325Sdan  SELECT sql FROM sqlite_master WHERE name = 'r2';
222fb8ac325Sdan} {
223fb8ac325Sdan  {CREATE TRIGGER r2 AFTER INSERT ON "t2x" WHEN new.aaaa NOT NULL BEGIN
224d9995031Sdan    SELECT aaaa, sum(aaaa) OVER w1 FROM "t2x"
225fb8ac325Sdan      WINDOW w1 AS (
226d9995031Sdan        PARTITION BY aaaa ORDER BY aaaa
227d9995031Sdan        ROWS BETWEEN 2 PRECEDING AND 3 FOLLOWING
228fb8ac325Sdan      ),
229fb8ac325Sdan      w2 AS (
230d9995031Sdan        PARTITION BY aaaa
231d9995031Sdan        ORDER BY rowid ROWS BETWEEN CURRENT ROW AND UNBOUNDED FOLLOWING
232fb8ac325Sdan      );
233fb8ac325Sdan  END}
234fb8ac325Sdan}
235fb8ac325Sdan
236d9995031Sdando_execsql_test 5.3 {
237fb8ac325Sdan  INSERT INTO t2x VALUES(1);
238d9995031Sdan} {}
2398cd2e4aeSdan} ;# windowfunc
240fb8ac325Sdan
2415e970a8fSdan#-------------------------------------------------------------------------
2425e970a8fSdan
2435e970a8fSdando_execsql_test 6.0 {
2445e970a8fSdan  CREATE TABLE t3(a,b,c,d);
2455e970a8fSdan  CREATE TRIGGER r3 AFTER INSERT ON t3 WHEN new.a NOT NULL BEGIN
2465e970a8fSdan    SELECT a,b,c FROM t3 EXCEPT SELECT a,b,c FROM t3 ORDER BY a;
2475e970a8fSdan    SELECT rowid, * FROM t3;
2485e970a8fSdan  END;
2495e970a8fSdan} {}
2505e970a8fSdan
2515e970a8fSdando_execsql_test 6.1 {
2525e970a8fSdan  ALTER TABLE t3 RENAME TO t3x;
2535e970a8fSdan  SELECT sql FROM sqlite_master WHERE name = 'r3';
2545e970a8fSdan} {
2555e970a8fSdan  {CREATE TRIGGER r3 AFTER INSERT ON "t3x" WHEN new.a NOT NULL BEGIN
2565e970a8fSdan    SELECT a,b,c FROM "t3x" EXCEPT SELECT a,b,c FROM "t3x" ORDER BY a;
2575e970a8fSdan    SELECT rowid, * FROM "t3x";
2585e970a8fSdan  END}
2595e970a8fSdan}
2605e970a8fSdan
2615e970a8fSdando_execsql_test 6.2 {
2625e970a8fSdan  ALTER TABLE t3x RENAME a TO abcd;
2635e970a8fSdan  SELECT sql FROM sqlite_master WHERE name = 'r3';
2645e970a8fSdan} {
2655e970a8fSdan  {CREATE TRIGGER r3 AFTER INSERT ON "t3x" WHEN new.abcd NOT NULL BEGIN
2665e970a8fSdan    SELECT abcd,b,c FROM "t3x" EXCEPT SELECT abcd,b,c FROM "t3x" ORDER BY abcd;
2675e970a8fSdan    SELECT rowid, * FROM "t3x";
2685e970a8fSdan  END}
2695e970a8fSdan}
2705e970a8fSdan
2718b20e4a3Sdan#-------------------------------------------------------------------------
2728b20e4a3Sdanreset_db
2738b20e4a3Sdan
2748b20e4a3Sdando_execsql_test 7.0 {
2758b20e4a3Sdan  CREATE TABLE t1(a,b,c,d,e,f);
2768b20e4a3Sdan  INSERT INTO t1 VALUES(1,2,3,4,5,6);
2778b20e4a3Sdan  CREATE TABLE t2(x,y,z);
2788b20e4a3Sdan}
2798b20e4a3Sdan
2808b20e4a3Sdando_execsql_test 7.1 {
2818b20e4a3Sdan  SELECT a,b,c FROM t1 UNION SELECT d,e,f FROM t1 ORDER BY b,c;
2828b20e4a3Sdan} {1 2 3 4 5 6}
2838b20e4a3Sdan
2848b20e4a3Sdando_execsql_test 7.2 {
2858b20e4a3Sdan  CREATE TRIGGER r1 AFTER INSERT ON t1 BEGIN
2868b20e4a3Sdan    INSERT INTO t2
2878b20e4a3Sdan    SELECT a,b,c FROM t1 UNION SELECT d,e,f FROM t1 ORDER BY b,c;
2888b20e4a3Sdan  END;
2898b20e4a3Sdan  INSERT INTO t1 VALUES(2,3,4,5,6,7);
2908b20e4a3Sdan  SELECT * FROM t2;
2918b20e4a3Sdan} {1 2 3  2 3 4  4 5 6  5 6 7}
2928b20e4a3Sdan
2938b20e4a3Sdando_execsql_test 7.3 {
2948b20e4a3Sdan  ALTER TABLE t1 RENAME TO xyzzy;
2958b20e4a3Sdan  SELECT sql FROM sqlite_master WHERE name='r1'
2968b20e4a3Sdan} {
2978b20e4a3Sdan  {CREATE TRIGGER r1 AFTER INSERT ON "xyzzy" BEGIN
2988b20e4a3Sdan    INSERT INTO t2
2998b20e4a3Sdan    SELECT a,b,c FROM "xyzzy" UNION SELECT d,e,f FROM "xyzzy" ORDER BY b,c;
3008b20e4a3Sdan  END}
3018b20e4a3Sdan}
3028b20e4a3Sdan
3038b20e4a3Sdando_execsql_test 7.3 {
3048b20e4a3Sdan  ALTER TABLE xyzzy RENAME c TO ccc;
3058b20e4a3Sdan  SELECT sql FROM sqlite_master WHERE name='r1'
3068b20e4a3Sdan} {
3078b20e4a3Sdan  {CREATE TRIGGER r1 AFTER INSERT ON "xyzzy" BEGIN
3088b20e4a3Sdan    INSERT INTO t2
3098b20e4a3Sdan    SELECT a,b,ccc FROM "xyzzy" UNION SELECT d,e,f FROM "xyzzy" ORDER BY b,ccc;
3108b20e4a3Sdan  END}
3118b20e4a3Sdan}
3128b20e4a3Sdan
3130e14e987Sdan#-------------------------------------------------------------------------
3140e14e987Sdanreset_db
3150e14e987Sdando_execsql_test 8.0 {
3160e14e987Sdan  CREATE TABLE t1(a, b, c);
3170e14e987Sdan  CREATE TABLE t2(a, b, c);
3180e14e987Sdan  CREATE TABLE t3(d, e, f);
3190e14e987Sdan  CREATE VIEW v1 AS SELECT * FROM t1;
3200e14e987Sdan  CREATE TRIGGER tr AFTER INSERT ON t3 BEGIN
3210e14e987Sdan    UPDATE t2 SET a = new.d;
3220e14e987Sdan    SELECT a, b, c FROM v1;
3230e14e987Sdan  END;
3240e14e987Sdan}
3250e14e987Sdan
3260e14e987Sdando_execsql_test 8.1 {
3270e14e987Sdan  INSERT INTO t3 VALUES(1, 2, 3);
3280e14e987Sdan}
3290e14e987Sdan
3300e14e987Sdan# The following ALTER TABLE fails as if column "t1.a" is renamed the "a"
3310e14e987Sdan# in the "SELECT a, b, c FROM v1" within the trigger can no longer be
3320e14e987Sdan# resolved. But at one point there was a bug allowing the ALTER TABLE
3330e14e987Sdan# succeed. Which meant the subsequent INSERT statement would fail.
3340e14e987Sdando_catchsql_test 8.2 {
3350e14e987Sdan  ALTER TABLE t1 RENAME a TO aaa;
3360e14e987Sdan} {1 {error in trigger tr after rename: no such column: a}}
3370e14e987Sdando_execsql_test 8.3 {
3380e14e987Sdan  INSERT INTO t3 VALUES(4, 5, 6);
3390e14e987Sdan}
3408b20e4a3Sdan
341a753d400Sdrhdo_execsql_test 8.4 {
34293b6c166Sdan  CREATE TABLE t4(a, b);
34393b6c166Sdan  CREATE VIEW v4 AS SELECT * FROM t4 WHERE (a=1 AND 0) OR b=2;
34493b6c166Sdan}
345b854b767Sdrh
3462b6e670fSdan# Branches of an expression tree that are optimized out by the AND
3472b6e670fSdan# optimization are renamed.
348b854b767Sdrh#
349a753d400Sdrhdo_execsql_test 8.5 {
35093b6c166Sdan  ALTER TABLE t4 RENAME a TO c;
35193b6c166Sdan  SELECT sql FROM sqlite_master WHERE name = 'v4'
3522b6e670fSdan} {{CREATE VIEW v4 AS SELECT * FROM t4 WHERE (c=1 AND 0) OR b=2}}
353b854b767Sdrh
354b854b767Sdrh# 2019-06-10 https://www.sqlite.org/src/info/533010b8cacebe82
355b854b767Sdrhreset_db
3562b6e670fSdando_catchsql_test 8.6 {
357b854b767Sdrh  CREATE TABLE t0(c0);
358*62fc069eSdrh  CREATE INDEX i0 ON t0(likelihood(1,2) AND 0);
359b854b767Sdrh  ALTER TABLE t0 RENAME TO t1;
360b854b767Sdrh  SELECT sql FROM sqlite_master WHERE name='i0';
3612b6e670fSdan} {1 {error in index i0: second argument to likelihood() must be a constant between 0.0 and 1.0}}
36293b6c166Sdan
36334566c44Sdanfinish_test
364