xref: /sqlite-3.40.0/test/trigger9.test (revision a6c54def)
18f2c54e6Sdanielk1977# 2008 January 1
28f2c54e6Sdanielk1977#
38f2c54e6Sdanielk1977# The author disclaims copyright to this source code.  In place of
48f2c54e6Sdanielk1977# a legal notice, here is a blessing:
58f2c54e6Sdanielk1977#
68f2c54e6Sdanielk1977#    May you do good and not evil.
78f2c54e6Sdanielk1977#    May you find forgiveness for yourself and forgive others.
88f2c54e6Sdanielk1977#    May you share freely, never taking more than you give.
98f2c54e6Sdanielk1977#
108f2c54e6Sdanielk1977#***********************************************************************
118f2c54e6Sdanielk1977# This file implements regression tests for SQLite library. Specifically,
128f2c54e6Sdanielk1977# it tests some compiler optimizations for SQL statements featuring
138f2c54e6Sdanielk1977# triggers:
148f2c54e6Sdanielk1977#
158f2c54e6Sdanielk1977#
168f2c54e6Sdanielk1977#
178f2c54e6Sdanielk1977
188f2c54e6Sdanielk1977# trigger9-1.* -   Test that if there are no references to OLD.* cols, or a
198f2c54e6Sdanielk1977#                  reference to only OLD.rowid, the data is not loaded.
208f2c54e6Sdanielk1977#
218f2c54e6Sdanielk1977# trigger9-2.* -   Test that for NEW.* records populated by UPDATE
228f2c54e6Sdanielk1977#                  statements, unused fields are populated with NULL values.
238f2c54e6Sdanielk1977#
248f2c54e6Sdanielk1977# trigger9-3.* -   Test that the temporary tables used for OLD.* references
258f2c54e6Sdanielk1977#                  in "INSTEAD OF" triggers have NULL values in unused
268f2c54e6Sdanielk1977#                  fields.
278f2c54e6Sdanielk1977#
288f2c54e6Sdanielk1977
298f2c54e6Sdanielk1977set testdir [file dirname $argv0]
308f2c54e6Sdanielk1977source $testdir/tester.tcl
318f2c54e6Sdanielk1977ifcapable {!trigger} {
328f2c54e6Sdanielk1977  finish_test
338f2c54e6Sdanielk1977  return
348f2c54e6Sdanielk1977}
35dd8c4600Sdanset ::testprefix trigger9
368f2c54e6Sdanielk1977
378f2c54e6Sdanielk1977proc has_rowdata {sql} {
388f2c54e6Sdanielk1977  expr {[lsearch [execsql "explain $sql"] RowData]>=0}
398f2c54e6Sdanielk1977}
408f2c54e6Sdanielk1977
418f2c54e6Sdanielk1977do_test trigger9-1.1 {
428f2c54e6Sdanielk1977  execsql {
438f2c54e6Sdanielk1977    PRAGMA page_size = 1024;
448f2c54e6Sdanielk1977    CREATE TABLE t1(x, y, z);
458f2c54e6Sdanielk1977    INSERT INTO t1 VALUES('1', randstr(10000,10000), '2');
468f2c54e6Sdanielk1977    INSERT INTO t1 VALUES('2', randstr(10000,10000), '4');
478f2c54e6Sdanielk1977    INSERT INTO t1 VALUES('3', randstr(10000,10000), '6');
488f2c54e6Sdanielk1977    CREATE TABLE t2(x);
498f2c54e6Sdanielk1977  }
508f2c54e6Sdanielk1977} {}
518f2c54e6Sdanielk1977
528f2c54e6Sdanielk1977do_test trigger9-1.2.1 {
538f2c54e6Sdanielk1977  execsql {
548f2c54e6Sdanielk1977    BEGIN;
558f2c54e6Sdanielk1977      CREATE TRIGGER trig1 BEFORE DELETE ON t1 BEGIN
568f2c54e6Sdanielk1977        INSERT INTO t2 VALUES(old.rowid);
578f2c54e6Sdanielk1977      END;
588f2c54e6Sdanielk1977      DELETE FROM t1;
598f2c54e6Sdanielk1977      SELECT * FROM t2;
608f2c54e6Sdanielk1977  }
618f2c54e6Sdanielk1977} {1 2 3}
628f2c54e6Sdanielk1977do_test trigger9-1.2.3 {
638f2c54e6Sdanielk1977  has_rowdata {DELETE FROM t1}
648f2c54e6Sdanielk1977} 0
658f2c54e6Sdanielk1977do_test trigger9-1.2.4 { execsql { ROLLBACK } } {}
668f2c54e6Sdanielk1977
678f2c54e6Sdanielk1977do_test trigger9-1.3.1 {
688f2c54e6Sdanielk1977  execsql {
698f2c54e6Sdanielk1977    BEGIN;
708f2c54e6Sdanielk1977      CREATE TRIGGER trig1 BEFORE DELETE ON t1 BEGIN
718f2c54e6Sdanielk1977        INSERT INTO t2 VALUES(old.x);
728f2c54e6Sdanielk1977      END;
738f2c54e6Sdanielk1977      DELETE FROM t1;
748f2c54e6Sdanielk1977      SELECT * FROM t2;
758f2c54e6Sdanielk1977  }
768f2c54e6Sdanielk1977} {1 2 3}
778f2c54e6Sdanielk1977do_test trigger9-1.3.2 {
788f2c54e6Sdanielk1977  has_rowdata {DELETE FROM t1}
7976d462eeSdan} 0
808f2c54e6Sdanielk1977do_test trigger9-1.3.3 { execsql { ROLLBACK } } {}
818f2c54e6Sdanielk1977
828f2c54e6Sdanielk1977do_test trigger9-1.4.1 {
838f2c54e6Sdanielk1977  execsql {
848f2c54e6Sdanielk1977    BEGIN;
858f2c54e6Sdanielk1977      CREATE TRIGGER trig1 BEFORE DELETE ON t1 WHEN old.x='1' BEGIN
868f2c54e6Sdanielk1977        INSERT INTO t2 VALUES(old.rowid);
878f2c54e6Sdanielk1977      END;
888f2c54e6Sdanielk1977      DELETE FROM t1;
898f2c54e6Sdanielk1977      SELECT * FROM t2;
908f2c54e6Sdanielk1977  }
918f2c54e6Sdanielk1977} {1}
928f2c54e6Sdanielk1977do_test trigger9-1.4.2 {
938f2c54e6Sdanielk1977  has_rowdata {DELETE FROM t1}
9476d462eeSdan} 0
958f2c54e6Sdanielk1977do_test trigger9-1.4.3 { execsql { ROLLBACK } } {}
968f2c54e6Sdanielk1977
978f2c54e6Sdanielk1977do_test trigger9-1.5.1 {
988f2c54e6Sdanielk1977  execsql {
998f2c54e6Sdanielk1977    BEGIN;
1008f2c54e6Sdanielk1977      CREATE TRIGGER trig1 BEFORE UPDATE ON t1 BEGIN
1018f2c54e6Sdanielk1977        INSERT INTO t2 VALUES(old.rowid);
1028f2c54e6Sdanielk1977      END;
1038f2c54e6Sdanielk1977      UPDATE t1 SET y = '';
1048f2c54e6Sdanielk1977      SELECT * FROM t2;
1058f2c54e6Sdanielk1977  }
1068f2c54e6Sdanielk1977} {1 2 3}
1078f2c54e6Sdanielk1977do_test trigger9-1.5.2 {
1088f2c54e6Sdanielk1977  has_rowdata {UPDATE t1 SET y = ''}
1098f2c54e6Sdanielk1977} 0
1108f2c54e6Sdanielk1977do_test trigger9-1.5.3 { execsql { ROLLBACK } } {}
1118f2c54e6Sdanielk1977
1128f2c54e6Sdanielk1977do_test trigger9-1.6.1 {
1138f2c54e6Sdanielk1977  execsql {
1148f2c54e6Sdanielk1977    BEGIN;
1158f2c54e6Sdanielk1977      CREATE TRIGGER trig1 BEFORE UPDATE ON t1 BEGIN
1168f2c54e6Sdanielk1977        INSERT INTO t2 VALUES(old.x);
1178f2c54e6Sdanielk1977      END;
1188f2c54e6Sdanielk1977      UPDATE t1 SET y = '';
1198f2c54e6Sdanielk1977      SELECT * FROM t2;
1208f2c54e6Sdanielk1977  }
1218f2c54e6Sdanielk1977} {1 2 3}
1228f2c54e6Sdanielk1977do_test trigger9-1.6.2 {
1238f2c54e6Sdanielk1977  has_rowdata {UPDATE t1 SET y = ''}
12476d462eeSdan} 0
1258f2c54e6Sdanielk1977do_test trigger9-1.6.3 { execsql { ROLLBACK } } {}
1268f2c54e6Sdanielk1977
1278f2c54e6Sdanielk1977do_test trigger9-1.7.1 {
1288f2c54e6Sdanielk1977  execsql {
1298f2c54e6Sdanielk1977    BEGIN;
1308f2c54e6Sdanielk1977      CREATE TRIGGER trig1 BEFORE UPDATE ON t1 WHEN old.x>='2' BEGIN
1318f2c54e6Sdanielk1977        INSERT INTO t2 VALUES(old.x);
1328f2c54e6Sdanielk1977      END;
1338f2c54e6Sdanielk1977      UPDATE t1 SET y = '';
1348f2c54e6Sdanielk1977      SELECT * FROM t2;
1358f2c54e6Sdanielk1977  }
1368f2c54e6Sdanielk1977} {2 3}
1378f2c54e6Sdanielk1977do_test trigger9-1.7.2 {
1388f2c54e6Sdanielk1977  has_rowdata {UPDATE t1 SET y = ''}
13976d462eeSdan} 0
1408f2c54e6Sdanielk1977do_test trigger9-1.7.3 { execsql { ROLLBACK } } {}
1418f2c54e6Sdanielk1977
142eb9ae901Sdanielk1977do_test trigger9-3.1 {
143eb9ae901Sdanielk1977  execsql {
144eb9ae901Sdanielk1977    CREATE TABLE t3(a, b);
145eb9ae901Sdanielk1977    INSERT INTO t3 VALUES(1, 'one');
146eb9ae901Sdanielk1977    INSERT INTO t3 VALUES(2, 'two');
147eb9ae901Sdanielk1977    INSERT INTO t3 VALUES(3, 'three');
148eb9ae901Sdanielk1977  }
149eb9ae901Sdanielk1977} {}
150eb9ae901Sdanielk1977do_test trigger9-3.2 {
151eb9ae901Sdanielk1977  execsql {
152eb9ae901Sdanielk1977    BEGIN;
153eb9ae901Sdanielk1977      CREATE VIEW v1 AS SELECT * FROM t3;
154eb9ae901Sdanielk1977      CREATE TRIGGER trig1 INSTEAD OF UPDATE ON v1 BEGIN
155eb9ae901Sdanielk1977        INSERT INTO t2 VALUES(old.a);
156eb9ae901Sdanielk1977      END;
157eb9ae901Sdanielk1977      UPDATE v1 SET b = 'hello';
158eb9ae901Sdanielk1977      SELECT * FROM t2;
159eb9ae901Sdanielk1977    ROLLBACK;
160eb9ae901Sdanielk1977  }
161eb9ae901Sdanielk1977} {1 2 3}
162eb9ae901Sdanielk1977do_test trigger9-3.3 {
163eb9ae901Sdanielk1977  # In this test the 'c' column of the view is not required by
164eb9ae901Sdanielk1977  # the INSTEAD OF trigger, but the expression is reused internally as
165eb9ae901Sdanielk1977  # part of the view's WHERE clause. Check that this does not cause
166eb9ae901Sdanielk1977  # a problem.
167eb9ae901Sdanielk1977  #
168eb9ae901Sdanielk1977  execsql {
169eb9ae901Sdanielk1977    BEGIN;
170eb9ae901Sdanielk1977      CREATE VIEW v1 AS SELECT a, b AS c FROM t3 WHERE c > 'one';
171eb9ae901Sdanielk1977      CREATE TRIGGER trig1 INSTEAD OF UPDATE ON v1 BEGIN
172eb9ae901Sdanielk1977        INSERT INTO t2 VALUES(old.a);
173eb9ae901Sdanielk1977      END;
174eb9ae901Sdanielk1977      UPDATE v1 SET c = 'hello';
175eb9ae901Sdanielk1977      SELECT * FROM t2;
176eb9ae901Sdanielk1977    ROLLBACK;
177eb9ae901Sdanielk1977  }
178eb9ae901Sdanielk1977} {2 3}
179eb9ae901Sdanielk1977do_test trigger9-3.4 {
180eb9ae901Sdanielk1977  execsql {
181eb9ae901Sdanielk1977    BEGIN;
182eb9ae901Sdanielk1977      INSERT INTO t3 VALUES(3, 'three');
183eb9ae901Sdanielk1977      INSERT INTO t3 VALUES(3, 'four');
184eb9ae901Sdanielk1977      CREATE VIEW v1 AS SELECT DISTINCT a, b FROM t3;
185eb9ae901Sdanielk1977      CREATE TRIGGER trig1 INSTEAD OF UPDATE ON v1 BEGIN
186eb9ae901Sdanielk1977        INSERT INTO t2 VALUES(old.a);
187eb9ae901Sdanielk1977      END;
188eb9ae901Sdanielk1977      UPDATE v1 SET b = 'hello';
189eb9ae901Sdanielk1977      SELECT * FROM t2;
190eb9ae901Sdanielk1977    ROLLBACK;
191eb9ae901Sdanielk1977  }
192eb9ae901Sdanielk1977} {1 2 3 3}
193de3e41e3Sdanielk1977
194de3e41e3Sdanielk1977ifcapable compound {
195eb9ae901Sdanielk1977  do_test trigger9-3.5 {
196eb9ae901Sdanielk1977    execsql {
197eb9ae901Sdanielk1977      BEGIN;
198eb9ae901Sdanielk1977        INSERT INTO t3 VALUES(1, 'uno');
199eb9ae901Sdanielk1977        CREATE VIEW v1 AS SELECT a, b FROM t3 EXCEPT SELECT 1, 'one';
200eb9ae901Sdanielk1977        CREATE TRIGGER trig1 INSTEAD OF UPDATE ON v1 BEGIN
201eb9ae901Sdanielk1977          INSERT INTO t2 VALUES(old.a);
202eb9ae901Sdanielk1977        END;
203eb9ae901Sdanielk1977        UPDATE v1 SET b = 'hello';
204eb9ae901Sdanielk1977        SELECT * FROM t2;
205eb9ae901Sdanielk1977      ROLLBACK;
206eb9ae901Sdanielk1977    }
207eb9ae901Sdanielk1977  } {1 2 3}
208eb9ae901Sdanielk1977  do_test trigger9-3.6 {
209eb9ae901Sdanielk1977    execsql {
210eb9ae901Sdanielk1977      BEGIN;
211eb9ae901Sdanielk1977        INSERT INTO t3 VALUES(1, 'zero');
212eb9ae901Sdanielk1977        CREATE VIEW v1 AS
213eb9ae901Sdanielk1977          SELECT sum(a) AS a, max(b) AS b FROM t3 GROUP BY t3.a HAVING b>'two';
214eb9ae901Sdanielk1977        CREATE TRIGGER trig1 INSTEAD OF UPDATE ON v1 BEGIN
215eb9ae901Sdanielk1977          INSERT INTO t2 VALUES(old.a);
216eb9ae901Sdanielk1977        END;
217eb9ae901Sdanielk1977        UPDATE v1 SET b = 'hello';
218eb9ae901Sdanielk1977        SELECT * FROM t2;
219eb9ae901Sdanielk1977      ROLLBACK;
220eb9ae901Sdanielk1977    }
221eb9ae901Sdanielk1977  } {2}
222de3e41e3Sdanielk1977}
223eb9ae901Sdanielk1977
224dd8c4600Sdanreset_db
225dd8c4600Sdando_execsql_test 4.1 {
226dd8c4600Sdan  CREATE TABLE t1(a, b);
227dd8c4600Sdan  CREATE TABLE log(x);
228dd8c4600Sdan  INSERT INTO t1 VALUES(1, 2);
229dd8c4600Sdan  INSERT INTO t1 VALUES(3, 4);
230dd8c4600Sdan  CREATE VIEW v1 AS SELECT a, b FROM t1;
231dd8c4600Sdan
232dd8c4600Sdan  CREATE TRIGGER tr1 INSTEAD OF DELETE ON v1 BEGIN
233dd8c4600Sdan    INSERT INTO log VALUES('delete');
234dd8c4600Sdan  END;
235dd8c4600Sdan
236dd8c4600Sdan  CREATE TRIGGER tr2 INSTEAD OF UPDATE ON v1 BEGIN
237dd8c4600Sdan    INSERT INTO log VALUES('update');
238dd8c4600Sdan  END;
239dd8c4600Sdan
240dd8c4600Sdan  CREATE TRIGGER tr3 INSTEAD OF INSERT ON v1 BEGIN
241dd8c4600Sdan    INSERT INTO log VALUES('insert');
242dd8c4600Sdan  END;
243dd8c4600Sdan}
244dd8c4600Sdan
245*a6c54defSdrhdo_catchsql_test 4.2 {
246dd8c4600Sdan  DELETE FROM v1 WHERE rowid=1;
247*a6c54defSdrh} {1 {no such column: rowid}}
248dd8c4600Sdan
249*a6c54defSdrhdo_catchsql_test 4.3 {
250dd8c4600Sdan  UPDATE v1 SET a=b WHERE rowid=2;
251*a6c54defSdrh} {1 {no such column: rowid}}
252dd8c4600Sdan
2538f2c54e6Sdanielk1977finish_test
254