xref: /sqlite-3.40.0/test/upfrom3.test (revision 8210233c)
1be952c11Sdan# 2020 July 14
2be952c11Sdan#
3be952c11Sdan# The author disclaims copyright to this source code.  In place of
4be952c11Sdan# a legal notice, here is a blessing:
5be952c11Sdan#
6be952c11Sdan#    May you do good and not evil.
7be952c11Sdan#    May you find forgiveness for yourself and forgive others.
8be952c11Sdan#    May you share freely, never taking more than you give.
9be952c11Sdan#
10be952c11Sdan#***********************************************************************
11be952c11Sdan#
12be952c11Sdan
13be952c11Sdanset testdir [file dirname $argv0]
14be952c11Sdansource $testdir/tester.tcl
15be952c11Sdanset testprefix upfrom3
16be952c11Sdan
17e7877b2dSdan# Test plan:
18e7877b2dSdan#
19e7877b2dSdan#   1.*: Test UPDATE ... FROM statements that modify IPK fields. And that
20e7877b2dSdan#        modify "INTEGER PRIMARY KEY" fields on WITHOUT ROWID tables.
21e7877b2dSdan#
22e7877b2dSdan#   2.*: Test UPDATE ... FROM statements that modify PK fields of WITHOUT
23e7877b2dSdan#        ROWID tables.
24e7877b2dSdan#
25576d5a86Sdan#   3.*: Test that UPDATE ... FROM statements are not confused if there
26576d5a86Sdan#        are multiple tables of the same name in attached databases.
27576d5a86Sdan#
28e7cf8fddSdan#   4.*: Tests for UPDATE ... FROM statements and foreign keys.
29e7cf8fddSdan#
30e7877b2dSdan
31be952c11Sdanforeach {tn wo} {
32be952c11Sdan  1 ""
33be952c11Sdan  2 "WITHOUT ROWID"
34be952c11Sdan} {
35be952c11Sdan  reset_db
36be952c11Sdan  eval [string map [list %WO% $wo %TN% $tn] {
37be952c11Sdan
38be952c11Sdan  do_execsql_test 1.%TN%.0 {
39be952c11Sdan    CREATE TABLE log(t TEXT);
40be952c11Sdan    CREATE TABLE t1(x INTEGER PRIMARY KEY, y, z UNIQUE) %WO%;
41be952c11Sdan    CREATE INDEX t1y ON t1(y);
42be952c11Sdan
43be952c11Sdan    INSERT INTO t1 VALUES(1, 'i',   'one');
44be952c11Sdan    INSERT INTO t1 VALUES(2, 'ii',  'two');
45be952c11Sdan    INSERT INTO t1 VALUES(3, 'iii', 'three');
46be952c11Sdan    INSERT INTO t1 VALUES(4, 'iv',  'four');
47be952c11Sdan  }
48be952c11Sdan
49be952c11Sdan  do_execsql_test 1.%TN%.1 {
50be952c11Sdan    CREATE TABLE x1(o, n);
51be952c11Sdan    INSERT INTO x1 VALUES(1, 11);
52be952c11Sdan    INSERT INTO x1 VALUES(2, 12);
53be952c11Sdan    INSERT INTO x1 VALUES(3, 13);
54be952c11Sdan    INSERT INTO x1 VALUES(4, 14);
55be952c11Sdan    UPDATE t1 SET x=n FROM x1 WHERE x=o;
56be952c11Sdan    SELECT x, y, z FROM t1 ORDER BY 1;
57be952c11Sdan  } {
58be952c11Sdan    11 i one
59be952c11Sdan    12 ii two
60be952c11Sdan    13 iii three
61be952c11Sdan    14 iv four
62be952c11Sdan  }
63be952c11Sdan
64be952c11Sdan  do_test 1.%TN%.2 { db changes } 4
65be952c11Sdan
66be952c11Sdan  do_execsql_test 1.%TN%.3 {
67be952c11Sdan    INSERT INTO x1 VALUES(11, 21);
68be952c11Sdan    INSERT INTO x1 VALUES(12, 22);
69be952c11Sdan    INSERT INTO x1 VALUES(13, 23);
70be952c11Sdan    INSERT INTO x1 VALUES(14, 24);
71be952c11Sdan
72be952c11Sdan    INSERT INTO x1 VALUES(21, 31);
73be952c11Sdan    INSERT INTO x1 VALUES(22, 32);
74be952c11Sdan    INSERT INTO x1 VALUES(23, 33);
75be952c11Sdan    INSERT INTO x1 VALUES(24, 34);
76be952c11Sdan    UPDATE t1 SET x=n FROM x1 WHERE x=o;
77be952c11Sdan    SELECT x, y, z FROM t1 ORDER BY 1;
78be952c11Sdan  } {
79be952c11Sdan    21 i one
80be952c11Sdan    22 ii two
81be952c11Sdan    23 iii three
82be952c11Sdan    24 iv four
83be952c11Sdan  }
84be952c11Sdan
85be952c11Sdan  do_execsql_test 1.%TN%.4 {
86be952c11Sdan    UPDATE t1 SET x=n FROM x1 WHERE x=o;
87be952c11Sdan    SELECT x, y, z FROM t1 ORDER BY 1;
88be952c11Sdan  } {
89be952c11Sdan    31 i one
90be952c11Sdan    32 ii two
91be952c11Sdan    33 iii three
92be952c11Sdan    34 iv four
93be952c11Sdan  }
94be952c11Sdan
95be952c11Sdan  do_execsql_test 1.%TN%.5 {
96be952c11Sdan    INSERT INTO x1 VALUES(31, 32);
97be952c11Sdan    INSERT INTO x1 VALUES(33, 34);
98be952c11Sdan    UPDATE OR REPLACE t1 SET x=n FROM x1 WHERE x=o;
99be952c11Sdan    SELECT x, y, z FROM t1 ORDER BY 1;
100be952c11Sdan  } {
101be952c11Sdan    32 i one
102be952c11Sdan    34 iii three
103be952c11Sdan  }
104be952c11Sdan
105be952c11Sdan  do_execsql_test 1.%TN%.6 {
106be952c11Sdan    INSERT INTO t1 VALUES(33, 'ii', 'two');
107be952c11Sdan    INSERT INTO t1 VALUES(35, 'iv', 'four');
108be952c11Sdan  }
109be952c11Sdan
110be952c11Sdan  do_execsql_test 1.%TN%.7 {
111be952c11Sdan    CREATE TABLE x2(o, n, zz);
112be952c11Sdan    INSERT INTO x2 VALUES(32, 41, 'four');
113be952c11Sdan    INSERT INTO x2 VALUES(33, 42, 'three');
114be952c11Sdan    UPDATE OR IGNORE t1 SET x=n, z=zz FROM x2 WHERE x=o;
115be952c11Sdan    SELECT x, y, z FROM t1 ORDER BY 1;
116be952c11Sdan  } {
117be952c11Sdan    32 i one
118be952c11Sdan    33 ii two
119be952c11Sdan    34 iii three
120be952c11Sdan    35 iv four
121be952c11Sdan  }
122be952c11Sdan
123be952c11Sdan  do_execsql_test 1.%TN%.8 {
124be952c11Sdan    UPDATE OR REPLACE t1 SET x=n, z=zz FROM x2 WHERE x=o;
125be952c11Sdan    SELECT x, y, z FROM t1 ORDER BY 1;
126be952c11Sdan  } {
127be952c11Sdan    41 i four
128be952c11Sdan    42 ii three
129be952c11Sdan  }
130be952c11Sdan
131be952c11Sdan  }]
132be952c11Sdan}
133be952c11Sdan
134be952c11Sdando_execsql_test 2.1.1 {
135be952c11Sdan  CREATE TABLE u1(a, b, c, PRIMARY KEY(b, c)) WITHOUT ROWID;
136be952c11Sdan  INSERT INTO u1 VALUES(0, 0, 0);
137be952c11Sdan  INSERT INTO u1 VALUES(1, 0, 1);
138be952c11Sdan  INSERT INTO u1 VALUES(2, 1, 0);
139be952c11Sdan  INSERT INTO u1 VALUES(3, 1, 1);
140be952c11Sdan}
141be952c11Sdan
142be952c11Sdando_execsql_test 2.1.2 {
143be952c11Sdan  CREATE TABLE map(f, t);
144be952c11Sdan  INSERT INTO map VALUES(0, 10);
145be952c11Sdan  INSERT INTO map VALUES(1, 11);
146be952c11Sdan  UPDATE u1 SET c=t FROM map WHERE c=f;
147be952c11Sdan  SELECT * FROM u1 ORDER BY a;
148be952c11Sdan} {
149be952c11Sdan  0 0 10
150be952c11Sdan  1 0 11
151be952c11Sdan  2 1 10
152be952c11Sdan  3 1 11
153be952c11Sdan}
154be952c11Sdan
155be952c11Sdando_execsql_test 2.1.3 {
156be952c11Sdan  UPDATE u1 SET b=t FROM map WHERE b=f;
157be952c11Sdan  SELECT * FROM u1 ORDER BY a;
158be952c11Sdan} {
159be952c11Sdan  0 10 10
160be952c11Sdan  1 10 11
161be952c11Sdan  2 11 10
162be952c11Sdan  3 11 11
163be952c11Sdan}
164be952c11Sdan
165be952c11Sdando_execsql_test 2.1.4 {
166be952c11Sdan  CREATE TABLE map2(o1, o2, n1, n2);
167be952c11Sdan  INSERT INTO map2 VALUES
168be952c11Sdan    (10, 10, 50, 50), (10, 11, 50, 60),
169be952c11Sdan    (11, 10, 60, 50), (11, 11, 60, 60);
170be952c11Sdan  UPDATE u1 SET b=n1, c=n2 FROM map2 WHERE b=o1 AND c=o2;
171be952c11Sdan  SELECT * FROM u1 ORDER BY a;
172be952c11Sdan} {
173be952c11Sdan  0 50 50
174be952c11Sdan  1 50 60
175be952c11Sdan  2 60 50
176be952c11Sdan  3 60 60
177be952c11Sdan}
178be952c11Sdan
179576d5a86Sdan#-------------------------------------------------------------------------
180576d5a86Sdanforeach {tn wo} {
181576d5a86Sdan  1 ""
182576d5a86Sdan  2 "WITHOUT ROWID"
183576d5a86Sdan} {
184576d5a86Sdan  reset_db
185576d5a86Sdan  forcedelete test.db2
186576d5a86Sdan  eval [string map [list %WO% $wo %TN% $tn] {
187576d5a86Sdan    do_execsql_test 3.$tn.1 {
188576d5a86Sdan      CREATE TABLE g1(a, b, c, PRIMARY KEY(a, b)) %WO%;
189576d5a86Sdan      INSERT INTO g1 VALUES(1, 1, 1);
190576d5a86Sdan
191576d5a86Sdan      ATTACH 'test.db2' AS aux;
192576d5a86Sdan      CREATE TABLE aux.g1(a, b, c, PRIMARY KEY(a, b)) %WO%;
193576d5a86Sdan      INSERT INTO aux.g1 VALUES(10, 1, 10);
194576d5a86Sdan      INSERT INTO aux.g1 VALUES(20, 2, 20);
195576d5a86Sdan      INSERT INTO aux.g1 VALUES(30, 3, 30);
196576d5a86Sdan    }
197576d5a86Sdan
198576d5a86Sdan    do_execsql_test 3.$tn.2 {
199576d5a86Sdan      UPDATE aux.g1 SET c=101 FROM main.g1;
200576d5a86Sdan    }
201576d5a86Sdan    do_execsql_test 3.$tn.3 {
202576d5a86Sdan      SELECT * FROM aux.g1;
203576d5a86Sdan    } {10 1 101  20 2 101  30 3 101}
204576d5a86Sdan
205576d5a86Sdan    do_execsql_test 3.$tn.4 {
206*07ca7d61Sdan      UPDATE g1 SET c=101 FROM g1 AS g2;
207576d5a86Sdan    }
208576d5a86Sdan    do_execsql_test 3.$tn.5 {
209576d5a86Sdan      SELECT * FROM g1;
210576d5a86Sdan    } {1 1 101}
211576d5a86Sdan  }]
212576d5a86Sdan}
213576d5a86Sdan
214e7cf8fddSdan#-------------------------------------------------------------------------
215e7cf8fddSdanreset_db
216e7cf8fddSdanforeach {tn wo} {
217e7cf8fddSdan  1 ""
218e7cf8fddSdan  2 "WITHOUT ROWID"
219e7cf8fddSdan} {
220e7cf8fddSdan  reset_db
221e7cf8fddSdan  forcedelete test.db2
222e7cf8fddSdan  eval [string map [list %WO% $wo %TN% $tn] {
223e7cf8fddSdan
224e7cf8fddSdan    do_execsql_test 4.$tn.1 {
225e7cf8fddSdan      CREATE TABLE p1(a INTEGER PRIMARY KEY, b) %WO%;
226e7cf8fddSdan      CREATE TABLE c1(x PRIMARY KEY, y REFERENCES p1 ON UPDATE CASCADE) %WO%;
227e7cf8fddSdan      PRAGMA foreign_keys = 1;
228e7cf8fddSdan
229e7cf8fddSdan      INSERT INTO p1 VALUES(1, 'one');
230e7cf8fddSdan      INSERT INTO p1 VALUES(11, 'eleven');
231e7cf8fddSdan      INSERT INTO p1 VALUES(111, 'eleventyone');
232e7cf8fddSdan
233e7cf8fddSdan      INSERT INTO c1 VALUES('a', 1);
234e7cf8fddSdan      INSERT INTO c1 VALUES('b', 11);
235e7cf8fddSdan      INSERT INTO c1 VALUES('c', 111);
236e7cf8fddSdan    }
237e7cf8fddSdan
238e7cf8fddSdan    do_execsql_test 4.$tn.2 {
239e7cf8fddSdan      CREATE TABLE map(f, t);
240e7cf8fddSdan      INSERT INTO map VALUES('a', 111);
241e7cf8fddSdan      INSERT INTO map VALUES('c', 112);
242e7cf8fddSdan    }
243e7cf8fddSdan
244e7cf8fddSdan    do_catchsql_test 4.$tn.3 {
245e7cf8fddSdan      UPDATE c1 SET y=t FROM map WHERE x=f;
246e7cf8fddSdan    } {1 {FOREIGN KEY constraint failed}}
247e7cf8fddSdan
248e7cf8fddSdan    do_execsql_test 4.$tn.4 {
249e7cf8fddSdan      INSERT INTO map VALUES('eleven', 12);
250e7cf8fddSdan      INSERT INTO map VALUES('eleventyone', 112);
251e7cf8fddSdan      UPDATE p1 SET a=t FROM map WHERE b=f;
252e7cf8fddSdan    }
253e7cf8fddSdan
254e7cf8fddSdan    do_execsql_test 4.$tn.5 {
255e7cf8fddSdan      SELECT * FROM c1
256e7cf8fddSdan    } {a 1  b 12  c 112}
257e7cf8fddSdan
258e7cf8fddSdan  }]
259e7cf8fddSdan}
260e7cf8fddSdan
261be952c11Sdanfinish_test
262