1# The author disclaims copyright to this source code.  In place of
2# a legal notice, here is a blessing:
3#
4#    May you do good and not evil.
5#    May you find forgiveness for yourself and forgive others.
6#    May you share freely, never taking more than you give.
7#
8#***********************************************************************
9#
10# Tests to make sure that values returned by changes() and total_changes()
11# are updated properly, especially inside triggers
12#
13# Note 1: changes() remains constant within a statement and only updates
14#         once the statement is finished (triggers count as part of
15#         statement).
16# Note 2: changes() is changed within the context of a trigger much like
17#         last_insert_rowid() (see lastinsert.test), but is restored once
18#         the trigger exits.
19# Note 3: changes() is not changed by a change to a view (since everything
20#         is done within instead of trigger context).
21#
22
23set testdir [file dirname $argv0]
24source $testdir/tester.tcl
25
26# ----------------------------------------------------------------------------
27# 1.x - basic tests (no triggers)
28
29# changes() set properly after insert
30do_test laststmtchanges-1.1 {
31    catchsql {
32        create table t0 (x);
33        insert into t0 values (1);
34        insert into t0 values (1);
35        insert into t0 values (2);
36        insert into t0 values (2);
37        insert into t0 values (1);
38        insert into t0 values (1);
39        insert into t0 values (1);
40        insert into t0 values (2);
41        select changes(), total_changes();
42    }
43} {0 {1 8}}
44
45# changes() set properly after update
46do_test laststmtchanges-1.2 {
47    catchsql {
48        update t0 set x=3 where x=1;
49        select changes(), total_changes();
50    }
51} {0 {5 13}}
52
53# There was some goofy change-counting logic in sqlite3_exec() that
54# appears to have been left over from SQLite version 2.  This test
55# makes sure it has been removed.
56#
57do_test laststmtchanges-1.2.1 {
58    db cache flush
59    sqlite3_exec_printf db {update t0 set x=4 where x=3; select 1;} {}
60    execsql {select changes()}
61} {5}
62
63# changes() unchanged within an update statement
64do_test laststmtchanges-1.3 {
65    execsql {update t0 set x=3 where x=4}
66    catchsql {
67        update t0 set x=x+changes() where x=3;
68        select count() from t0 where x=8;
69    }
70} {0 5}
71
72# changes() set properly after update on table where no rows changed
73do_test laststmtchanges-1.4 {
74    catchsql {
75        update t0 set x=77 where x=88;
76        select changes();
77    }
78} {0 0}
79
80# changes() set properly after delete from table
81do_test laststmtchanges-1.5 {
82    catchsql {
83        delete from t0 where x=2;
84        select changes();
85    }
86} {0 3}
87
88# All remaining tests involve triggers.  Skip them if triggers are not
89# supported in this build.
90#
91ifcapable {!trigger} {
92  finish_test
93  return
94}
95
96
97# ----------------------------------------------------------------------------
98# 2.x - tests with after insert trigger
99
100# changes() changed properly after insert into table containing after trigger
101do_test laststmtchanges-2.1 {
102    set ::tc [db total_changes]
103    catchsql {
104        create table t1 (k integer primary key);
105        create table t2 (k integer primary key, v1, v2);
106        create trigger r1 after insert on t1 for each row begin
107            insert into t2 values (NULL, changes(), NULL);
108            update t0 set x=x;
109            update t2 set v2=changes();
110        end;
111        insert into t1 values (77);
112        select changes();
113    }
114} {0 1}
115
116# changes() unchanged upon entry into after insert trigger
117do_test laststmtchanges-2.2 {
118    catchsql {
119        select v1 from t2;
120    }
121} {0 3}
122
123# changes() changed properly by update within context of after insert trigger
124do_test laststmtchanges-2.3 {
125    catchsql {
126        select v2 from t2;
127    }
128} {0 5}
129
130# Total changes caused by firing the trigger above:
131#
132#   1 from "insert into t1 values(77)" +
133#   1 from "insert into t2 values (NULL, changes(), NULL);" +
134#   5 from "update t0 set x=x;" +
135#   1 from "update t2 set v2=changes();"
136#
137do_test laststmtchanges-2.4 {
138  expr [db total_changes] - $::tc
139} {8}
140
141# ----------------------------------------------------------------------------
142# 3.x - tests with after update trigger
143
144# changes() changed properly after update into table containing after trigger
145do_test laststmtchanges-3.1 {
146    catchsql {
147        drop trigger r1;
148        delete from t2; delete from t2;
149        create trigger r1 after update on t1 for each row begin
150            insert into t2 values (NULL, changes(), NULL);
151            delete from t0 where oid=1 or oid=2;
152            update t2 set v2=changes();
153        end;
154        update t1 set k=k;
155        select changes();
156    }
157} {0 1}
158
159# changes() unchanged upon entry into after update trigger
160do_test laststmtchanges-3.2 {
161    catchsql {
162        select v1 from t2;
163    }
164} {0 0}
165
166# changes() changed properly by delete within context of after update trigger
167do_test laststmtchanges-3.3 {
168    catchsql {
169        select v2 from t2;
170    }
171} {0 2}
172
173# ----------------------------------------------------------------------------
174# 4.x - tests with before delete trigger
175
176# changes() changed properly on delete from table containing before trigger
177do_test laststmtchanges-4.1 {
178    catchsql {
179        drop trigger r1;
180        delete from t2; delete from t2;
181        create trigger r1 before delete on t1 for each row begin
182            insert into t2 values (NULL, changes(), NULL);
183            insert into t0 values (5);
184            update t2 set v2=changes();
185        end;
186        delete from t1;
187        select changes();
188    }
189} {0 1}
190
191# changes() unchanged upon entry into before delete trigger
192do_test laststmtchanges-4.2 {
193    catchsql {
194        select v1 from t2;
195    }
196} {0 0}
197
198# changes() changed properly by insert within context of before delete trigger
199do_test laststmtchanges-4.3 {
200    catchsql {
201        select v2 from t2;
202    }
203} {0 1}
204
205# ----------------------------------------------------------------------------
206# 5.x - complex tests with temporary tables and nested instead of triggers
207# These tests cannot run if the library does not have view support enabled.
208
209ifcapable view&&tempdb {
210
211do_test laststmtchanges-5.1 {
212    catchsql {
213        drop table t0; drop table t1; drop table t2;
214        create temp table t0(x);
215        create temp table t1 (k integer primary key);
216        create temp table t2 (k integer primary key);
217        create temp view v1 as select * from t1;
218        create temp view v2 as select * from t2;
219        create temp table n1 (k integer primary key, n);
220        create temp table n2 (k integer primary key, n);
221        insert into t0 values (1);
222        insert into t0 values (2);
223        insert into t0 values (1);
224        insert into t0 values (1);
225        insert into t0 values (1);
226        insert into t0 values (2);
227        insert into t0 values (2);
228        insert into t0 values (1);
229        create temp trigger r1 instead of insert on v1 for each row begin
230            insert into n1 values (NULL, changes());
231            update t0 set x=x*10 where x=1;
232            insert into n1 values (NULL, changes());
233            insert into t1 values (NEW.k);
234            insert into n1 values (NULL, changes());
235            update t0 set x=x*10 where x=0;
236            insert into v2 values (100+NEW.k);
237            insert into n1 values (NULL, changes());
238        end;
239        create temp trigger r2 instead of insert on v2 for each row begin
240            insert into n2 values (NULL, changes());
241            insert into t2 values (1000+NEW.k);
242            insert into n2 values (NULL, changes());
243            update t0 set x=x*100 where x=0;
244            insert into n2 values (NULL, changes());
245            delete from t0 where x=2;
246            insert into n2 values (NULL, changes());
247        end;
248        insert into t1 values (77);
249        select changes();
250    }
251} {0 1}
252
253do_test laststmtchanges-5.2 {
254    catchsql {
255        delete from t1 where k=88;
256        select changes();
257    }
258} {0 0}
259
260do_test laststmtchanges-5.3 {
261    catchsql {
262        insert into v1 values (5);
263        select changes();
264    }
265} {0 0}
266
267do_test laststmtchanges-5.4 {
268    catchsql {
269        select n from n1;
270    }
271} {0 {0 5 1 0}}
272
273do_test laststmtchanges-5.5 {
274    catchsql {
275        select n from n2;
276    }
277} {0 {0 1 0 3}}
278
279} ;# ifcapable view
280
281finish_test
282