File: triggerC.test.lua

package info (click to toggle)
tarantool 2.6.0-1.4
  • links: PTS, VCS
  • area: main
  • in suites: sid, trixie
  • size: 85,412 kB
  • sloc: ansic: 513,775; cpp: 69,493; sh: 25,650; python: 19,190; perl: 14,973; makefile: 4,178; yacc: 1,329; sql: 1,074; pascal: 620; ruby: 190; awk: 18; lisp: 7
file content (987 lines) | stat: -rwxr-xr-x 32,485 bytes parent folder | download | duplicates (3)
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
641
642
643
644
645
646
647
648
649
650
651
652
653
654
655
656
657
658
659
660
661
662
663
664
665
666
667
668
669
670
671
672
673
674
675
676
677
678
679
680
681
682
683
684
685
686
687
688
689
690
691
692
693
694
695
696
697
698
699
700
701
702
703
704
705
706
707
708
709
710
711
712
713
714
715
716
717
718
719
720
721
722
723
724
725
726
727
728
729
730
731
732
733
734
735
736
737
738
739
740
741
742
743
744
745
746
747
748
749
750
751
752
753
754
755
756
757
758
759
760
761
762
763
764
765
766
767
768
769
770
771
772
773
774
775
776
777
778
779
780
781
782
783
784
785
786
787
788
789
790
791
792
793
794
795
796
797
798
799
800
801
802
803
804
805
806
807
808
809
810
811
812
813
814
815
816
817
818
819
820
821
822
823
824
825
826
827
828
829
830
831
832
833
834
835
836
837
838
839
840
841
842
843
844
845
846
847
848
849
850
851
852
853
854
855
856
857
858
859
860
861
862
863
864
865
866
867
868
869
870
871
872
873
874
875
876
877
878
879
880
881
882
883
884
885
886
887
888
889
890
891
892
893
894
895
896
897
898
899
900
901
902
903
904
905
906
907
908
909
910
911
912
913
914
915
916
917
918
919
920
921
922
923
924
925
926
927
928
929
930
931
932
933
934
935
936
937
938
939
940
941
942
943
944
945
946
947
948
949
950
951
952
953
954
955
956
957
958
959
960
961
962
963
964
965
966
967
968
969
970
971
972
973
974
975
976
977
978
979
980
981
982
983
984
985
986
987
#!/usr/bin/env tarantool
test = require("sqltester")
test:plan(43)

--!./tcltestrunner.lua
-- 2009 August 24
--
-- The author disclaims copyright to this source code.  In place of
-- a legal notice', here is a blessing:
--
--    May you do good and not evil.
--    May you find forgiveness for yourself and forgive others.
--    May you share freely, never taking more than you give.
--
-------------------------------------------------------------------------
--
-- ["set","testdir",[["file","dirname",["argv0"]]]]
-- ["source",[["testdir"],"\/tester.tcl"]]
testprefix = "triggerC"


---------------------------------------------------------------------------
-- Test organization:
--
-- triggerC-1.*: Haphazardly designed trigger related tests that were useful
--               during an upgrade of the triggers sub-system.
--
-- triggerC-2.*:
--
-- triggerC-3.*:
--
-- triggerC-4.*:
--
-- triggerC-5.*: Test that when recursive triggers are enabled DELETE
--               triggers are fired when rows are deleted as part of OR
--               REPLACE conflict resolution. And that they are not fired
--               if recursive triggers are not enabled.
--
-- Enable recursive triggers for this file.
--
box.space._session_settings:update('sql_recursive_triggers', {{'=', 2, true}})
---------------------------------------------------------------------------
-- This block of tests, triggerC-1.*, are not aimed at any specific
-- property of the triggers sub-system. They were created to debug
-- specific problems while modifying sql to support recursive
-- triggers. They are left here in case they can help debug the
-- same problems again.
--
test:do_execsql_test(
    "triggerC-1.1",
    [[
        CREATE TABLE t1(id INT PRIMARY KEY AUTOINCREMENT, a TEXT UNIQUE, b TEXT, c TEXT);
        CREATE TABLE log(t TEXT PRIMARY KEY, a1 TEXT, b1 TEXT, c1 TEXT, a2 TEXT, b2 TEXT, c2 TEXT);
        CREATE TRIGGER trig1 BEFORE INSERT ON t1 FOR EACH ROW BEGIN
          INSERT INTO log VALUES('before', NULL, NULL, NULL, new.a, new.b, new.c);
        END;
        CREATE TRIGGER trig2 AFTER INSERT ON t1 FOR EACH ROW BEGIN
          INSERT INTO log VALUES('after', NULL, NULL, NULL, new.a, new.b, new.c);
        END;
        CREATE TRIGGER trig3 BEFORE UPDATE ON t1 FOR EACH ROW BEGIN
          INSERT INTO log VALUES('before', old.a,old.b,old.c, new.a,new.b,new.c);
        END;
        CREATE TRIGGER trig4 AFTER UPDATE ON t1 FOR EACH ROW BEGIN
          INSERT INTO log VALUES('after', old.a,old.b,old.c, new.a,new.b,new.c);
        END;

        CREATE TRIGGER trig5 BEFORE DELETE ON t1 FOR EACH ROW BEGIN
          INSERT INTO log VALUES('before', old.a,old.b,old.c, NULL,NULL,NULL);
        END;
        CREATE TRIGGER trig6 AFTER DELETE ON t1 FOR EACH ROW BEGIN
          INSERT INTO log VALUES('after', old.a,old.b,old.c, NULL,NULL,NULL);
        END;
    ]], {
        -- <triggerC-1.1>

        -- </triggerC-1.1>
    })

test:do_execsql_test(
    "triggerC-1.2",
    [[
        INSERT INTO t1 VALUES(1, 'A', 'B', 'C');
        SELECT * FROM log ORDER BY t DESC;
    ]], {
        -- <triggerC-1.2>
        "before", "", "", "", "A", "B", "C", "after", "", "", "", "A", "B", "C"
        -- </triggerC-1.2>
    })

test:do_execsql_test(
    "triggerC-1.3",
    [[
        SELECT * FROM t1
    ]], {
        -- <triggerC-1.3>
        1, "A", "B", "C"
        -- </triggerC-1.3>
    })

test:do_execsql_test(
    "triggerC-1.4",
    [[
        DELETE FROM log;
        UPDATE t1 SET a = 'a';
        SELECT * FROM log ORDER BY t DESC;
    ]], {
        -- <triggerC-1.4>
        "before", "A", "B", "C", "a", "B", "C", "after", "A", "B", "C", "a", "B", "C"
        -- </triggerC-1.4>
    })

test:do_execsql_test(
    "triggerC-1.5",
    [[
        SELECT * FROM t1
    ]], {
        -- <triggerC-1.5>
        1, "a", "B", "C"
        -- </triggerC-1.5>
    })

test:do_execsql_test(
    "triggerC-1.6",
    [[
        DELETE FROM log;
        DELETE FROM t1;
        SELECT * FROM log ORDER BY t DESC;
    ]], {
        -- <triggerC-1.6>
        "before", "a", "B", "C", "", "", "", "after", "a", "B", "C", "", "", ""
        -- </triggerC-1.6>
    })

test:do_execsql_test(
    "triggerC-1.7",
    [[
        SELECT * FROM t1
    ]], {
        -- <triggerC-1.7>

        -- </triggerC-1.7>
    })

-- MUST_WORK_TEST
test:do_execsql_test(
    "triggerC-1.8",
    [[
        CREATE TABLE t4(a INT PRIMARY KEY, b INT);
        CREATE TRIGGER t4t AFTER DELETE ON t4 FOR EACH ROW BEGIN
          SELECT RAISE(ABORT, 'delete is not supported');
        END;
    ]], {
        -- <triggerC-1.8>

        -- </triggerC-1.8>
    })

test:do_test(
    "triggerC-1.9",
    function()
        test:execsql " INSERT INTO t4 VALUES(1, 2) "
        return test:catchsql " DELETE FROM t4 "
    end, {
        -- <triggerC-1.9>
        1, "Failed to execute SQL statement: delete is not supported"
        -- </triggerC-1.9>
    })

test:do_execsql_test(
    "triggerC-1.10",
    [[
        SELECT * FROM t4
    ]], {
        -- <triggerC-1.10>
        1, 2
        -- </triggerC-1.10>
    })

test:do_execsql_test(
    "triggerC-1.11",
    [[
        CREATE TABLE t5 (a INT UNIQUE, b INT PRIMARY KEY, c INT);
        INSERT INTO t5 values (1, 2, 3);
        CREATE TRIGGER au_tbl AFTER UPDATE ON t5 FOR EACH ROW BEGIN
          UPDATE OR IGNORE t5 SET a = new.a, c = 10;
        END;
    ]], {
        -- <triggerC-1.11>

        -- </triggerC-1.11>
    })

test:do_catchsql_test(
    "triggerC-1.12",
    [[
        UPDATE OR REPLACE t5 SET a = 4 WHERE a = 1
    ]], {
        -- <triggerC-1.12>
        1, "Failed to execute SQL statement: too many levels of trigger recursion"
        -- </triggerC-1.12>
    })

test:do_execsql_test(
    "triggerC-1.13",
    [[
        CREATE TABLE t6(a INT UNIQUE, b INT PRIMARY KEY);
        INSERT INTO t6 VALUES(1, 2);
        create trigger r1 after update on t6 for each row begin
          SELECT 1;
        end;
        UPDATE t6 SET a=a;
    ]], {
        -- <triggerC-1.13>

        -- </triggerC-1.13>
    })

test:do_execsql_test(
    "triggerC-1.14",
    [[
        DROP TABLE IF EXISTS t1;
        CREATE TABLE cnt(id INT PRIMARY KEY, n INT UNIQUE);
        INSERT INTO cnt VALUES(0, 0);
        CREATE TABLE t1(a INT UNIQUE, b INT UNIQUE, c INT, d INT, e INT PRIMARY KEY);
        CREATE INDEX t1cd ON t1(c,d);
        CREATE UNIQUE INDEX t1a ON t1(a);
        CREATE TRIGGER t1r1 AFTER UPDATE ON t1 FOR EACH ROW BEGIN UPDATE cnt SET n=n+1; END;
        INSERT INTO t1 VALUES(1,2,3,4,5);
        INSERT INTO t1 VALUES(6,7,8,9,10);
        INSERT INTO t1 VALUES(11,12,13,14,15);
    ]], {
        -- <triggerC-1.14>
        -- </triggerC-1.14>
    })

test:do_catchsql_test(
    "triggerC-1.15",
    [[
        UPDATE OR ROLLBACK t1 SET a=100;
    ]], {
        -- <triggerC-1.15>
        1, "Duplicate key exists in unique index 'unique_unnamed_T1_1' in space 'T1'"
        -- </triggerC-1.15>
    })

---------------------------------------------------------------------------
-- This block of tests, triggerC-2.*, tests that recursive trigger
-- programs (triggers that fire themselves) work. More specifically,
-- this block focuses on recursive INSERT triggers.
--
test:do_execsql_test(
    "triggerC-2.1.0",
    [[
        CREATE TABLE t2(a INT PRIMARY KEY);
    ]], {
        -- <triggerC-2.1.0>

        -- </triggerC-2.1.0>
    })

-- MUST_WORK_TEST
-- for _ in X(0, "X!foreach", [=[["n tdefn rc","\n  1 {\n    CREATE TRIGGER t2_trig AFTER INSERT ON t2 WHEN (new.a>0) BEGIN\n      INSERT INTO t2 VALUES(new.a - 1);\n    END;\n  } {0 {10 9 8 7 6 5 4 3 2 1 0}}\n\n  2 {\n    CREATE TRIGGER t2_trig AFTER INSERT ON t2 BEGIN\n      SELECT CASE WHEN new.a==2 THEN RAISE(IGNORE) ELSE NULL END;\n      INSERT INTO t2 VALUES(new.a - 1);\n    END;\n  } {0 {10 9 8 7 6 5 4 3 2}}\n\n  3 {\n    CREATE TRIGGER t2_trig BEFORE INSERT ON t2 WHEN (new.a>0) BEGIN\n      INSERT INTO t2 VALUES(new.a - 1);\n    END;\n  } {0 {0 1 2 3 4 5 6 7 8 9 10}}\n\n  4 {\n    CREATE TRIGGER t2_trig BEFORE INSERT ON t2 BEGIN\n      SELECT CASE WHEN new.a==2 THEN RAISE(IGNORE) ELSE NULL END;\n      INSERT INTO t2 VALUES(new.a - 1);\n    END;\n  } {0 {3 4 5 6 7 8 9 10}}\n\n  5 {\n    CREATE TRIGGER t2_trig BEFORE INSERT ON t2 BEGIN\n      INSERT INTO t2 VALUES(new.a - 1);\n    END;\n  } {1 {too many levels of trigger recursion}}\n\n  6 {\n    CREATE TRIGGER t2_trig AFTER INSERT ON t2 WHEN (new.a>0) BEGIN\n      INSERT OR IGNORE INTO t2 VALUES(new.a);\n    END;\n  } {0 10}\n\n  7 {\n    CREATE TRIGGER t2_trig BEFORE INSERT ON t2 WHEN (new.a>0) BEGIN\n      INSERT OR IGNORE INTO t2 VALUES(new.a);\n    END;\n  } {1 {too many levels of trigger recursion}}\n"]]=]) do

local
tests =   { {[[ CREATE TRIGGER t2_trig AFTER INSERT ON t2 FOR EACH ROW WHEN (new.a>0) BEGIN
                  INSERT INTO t2 VALUES(new.a - 1);
                END;]], {0, {10, 9, 8, 7, 6, 5, 4, 3, 2, 1, 0}}},

            {[[ CREATE TRIGGER t2_trig AFTER INSERT ON t2 FOR EACH ROW BEGIN
                  SELECT CASE WHEN new.a==2 THEN RAISE(IGNORE) ELSE NULL END;
                  INSERT INTO t2 VALUES(new.a - 1);
                END;]], {0, {10, 9, 8, 7, 6, 5, 4, 3, 2}}},

            {[[ CREATE TRIGGER t2_trig BEFORE INSERT ON t2 FOR EACH ROW WHEN (new.a>0) BEGIN
                  INSERT INTO t2 VALUES(new.a - 1);
                END;]], {0, {10, 9, 8, 7, 6, 5, 4, 3, 2, 1, 0}}},

            {[[ CREATE TRIGGER t2_trig BEFORE INSERT ON t2 FOR EACH ROW BEGIN
                  SELECT CASE WHEN new.a==2 THEN RAISE(IGNORE) ELSE NULL END;
                  INSERT INTO t2 VALUES(new.a - 1);
                END;]], {0, {10, 9, 8, 7, 6, 5, 4, 3}}},

            {[[ CREATE TRIGGER t2_trig BEFORE INSERT ON t2 FOR EACH ROW BEGIN
                  INSERT INTO t2 VALUES(new.a - 1);
                END;]], {1, "Failed to execute SQL statement: too many levels of trigger recursion"}},

            {[[ CREATE TRIGGER t2_trig AFTER INSERT ON t2 FOR EACH ROW WHEN (new.a>0) BEGIN
                  INSERT OR IGNORE INTO t2 VALUES(new.a);
                END;]], {0, {10}}},

            {[[  CREATE TRIGGER t2_trig BEFORE INSERT ON t2 FOR EACH ROW WHEN (new.a>0) BEGIN
                   INSERT OR IGNORE INTO t2 VALUES(new.a);
                 END;]], {1, "Failed to execute SQL statement: too many levels of trigger recursion"}}}

for n, v in ipairs(tests) do
    test:do_test(
        "triggerC-2.1."..n,
        function()
            test:catchsql " DROP TRIGGER t2_trig "
            test:execsql " DELETE FROM t2 "
            test:execsql(v[1])
            return test:catchsql [[
                INSERT INTO t2 VALUES(10);
                SELECT * FROM t2 ORDER BY a DESC;
            ]]
        end,
        v[2])
end

-- test:do_execsql_test(
--     "triggerC-2.2",
-- string.format([[
--         CREATE TABLE t22(x PRIMARY KEY);

--         CREATE TRIGGER t22a AFTER INSERT ON t22 FOR EACH ROW BEGIN
--           INSERT INTO t22 SELECT x + (SELECT max(x) FROM t22) FROM t22;
--         END;
--         CREATE TRIGGER t22b BEFORE INSERT ON t22 FOR EACH ROW BEGIN
--           SELECT CASE WHEN (SELECT count(*) FROM t22) >= %s
--                       THEN RAISE(IGNORE)
--                       ELSE NULL END;
--         END;

--         INSERT INTO t22 VALUES(1);
--         SELECT count(*) FROM t22;
--     ]], (sql_MAX_TRIGGER_DEPTH / 2)), {
--         -- <triggerC-2.2>
--         (sql_MAX_TRIGGER_DEPTH / 2)
--         -- </triggerC-2.2>
--     })

-- test:do_execsql_test(
--     "triggerC-2.3",
-- string.format([[
--         CREATE TABLE t23(x PRIMARY KEY);

--         CREATE TRIGGER t23a AFTER INSERT ON t23 FOR EACH ROW BEGIN
--           INSERT INTO t23 VALUES(new.x + 1);
--         END;

--         CREATE TRIGGER t23b BEFORE INSERT ON t23 FOR EACH ROW BEGIN
--           SELECT CASE WHEN new.x>%s
--                       THEN RAISE(IGNORE)
--                       ELSE NULL END;
--         END;

--         INSERT INTO t23 VALUES(1);
--         SELECT count(*) FROM t23;
--     ]], (sql_MAX_TRIGGER_DEPTH / 2)), {
--         -- <triggerC-2.3>
--         (sql_MAX_TRIGGER_DEPTH / 2)
--         -- </triggerC-2.3>
--     })

-------------------------------------------------------------------------
-- This block of tests, triggerC-3.*, test that sql throws an exception
-- when it detects excessive recursion.
--
test:do_execsql_test(
    "triggerC-3.1.1",
    [[
        CREATE TABLE t3(a INT PRIMARY KEY, b INT);
        CREATE TRIGGER t3i AFTER INSERT ON t3 FOR EACH ROW BEGIN
          DELETE FROM t3 WHERE a = new.a;
        END;
        CREATE TRIGGER t3d AFTER DELETE ON t3 FOR EACH ROW BEGIN
          INSERT INTO t3 VALUES(old.a, old.b);
        END;
    ]], {
        -- <triggerC-3.1.1>

        -- </triggerC-3.1.1>
    })

-- MUST_WORK_TEST
test:do_catchsql_test(
    "triggerC-3.1.2",
    [[
        INSERT INTO t3 VALUES(0,0)
    ]], {
        -- <triggerC-3.1.2>
        1, "Failed to execute SQL statement: too many levels of trigger recursion"
        -- </triggerC-3.1.2>
    })

test:do_execsql_test(
    "triggerC-3.1.3",
    [[
        SELECT * FROM t3
    ]], {
        -- <triggerC-3.1.3>
        -- </triggerC-3.1.3>
    })

test:do_execsql_test(
    "triggerC-3.2.1",
    [[
        CREATE TABLE t3b(x INT PRIMARY KEY);
        CREATE TRIGGER t3bi AFTER INSERT ON t3b FOR EACH ROW BEGIN INSERT INTO t3b VALUES(new.x+1); END;
    ]], {
        -- <triggerC-3.2.1>
        -- </triggerC-3.2.1>
    })

test:do_catchsql_test(
    "triggerC-3.2.2",
    [[
        INSERT INTO t3b VALUES(1);
    ]], {
        -- <triggerC-3.1.3>
        1, "Failed to execute SQL statement: too many levels of trigger recursion"
        -- </triggerC-3.1.3>
    })

test:do_execsql_test(
    "triggerC-3.2.3",
    [[
        SELECT * FROM t3b;
    ]], {
        -- <triggerC-3.2.3>
        -- </triggerC-3.2.3>
    })

--------------------------------------------------------------------------
-- This block of tests, triggerC-5.*, test that DELETE triggers are fired
-- if a row is deleted as a result of OR REPLACE conflict resolution.
--
test:do_execsql_test(
    "triggerC-5.1.0",
    [[
        DROP TABLE IF EXISTS t5;
        CREATE TABLE t5(a INTEGER PRIMARY KEY, b TEXT);
        CREATE UNIQUE INDEX t5i ON t5(b);
        INSERT INTO t5 VALUES(1, 'a');
        INSERT INTO t5 VALUES(2, 'b');
        INSERT INTO t5 VALUES(3, 'c');

        CREATE TABLE t5g(a INT PRIMARY KEY, b TEXT, c INT);
        CREATE TRIGGER t5t BEFORE DELETE ON t5 FOR EACH ROW BEGIN
          INSERT INTO t5g VALUES(old.a, old.b, (SELECT count(*) FROM t5));
        END;
    ]], {
        -- <triggerC-5.1.0>

        -- </triggerC-5.1.0>
    })

-- MUST_WORK_TEST
-- foreach {n dml t5g t5} {
--   1 "DELETE FROM t5 WHERE a=2"                        {2 b 3} {1 a 3 c}
--   2 "INSERT OR REPLACE INTO t5 VALUES(2, 'd')"        {2 b 3} {1 a 2 d 3 c}
--   3 "UPDATE OR REPLACE t5 SET a = 2 WHERE a = 3"      {2 b 3} {1 a 2 c}
--   4 "INSERT OR REPLACE INTO t5 VALUES(4, 'b')"        {2 b 3} {1 a 3 c 4 b}
--   5 "UPDATE OR REPLACE t5 SET b = 'b' WHERE b = 'c'"  {2 b 3} {1 a 3 b}
--   6 "INSERT OR REPLACE INTO t5 VALUES(2, 'c')"        {2 b 3 3 c 2} {1 a 2 c}
--   7 "UPDATE OR REPLACE t5 SET a=1, b='b' WHERE a = 3" {1 a 3 2 b 2} {1 b}
-- } {
--   do_test triggerC-5.1.$n {
--     execsql "
--       BEGIN;
--         $dml ;
--         SELECT * FROM t5g ORDER BY rowid;
--         SELECT * FROM t5 ORDER BY rowid;
--       ROLLBACK;
--     "
--   } [concat $t5g $t5]
-- }
test:do_execsql_test(
    "triggerC-5.2.0",
    [[
        DROP TRIGGER t5t;
        CREATE TRIGGER t5t AFTER DELETE ON t5 FOR EACH ROW BEGIN
          INSERT INTO t5g VALUES(old.a, old.b, (SELECT count(*) FROM t5));
        END;
    ]], {
        -- <triggerC-5.2.0>

        -- </triggerC-5.2.0>
    })

-- MUST_WORK_TEST
-- foreach {n dml t5g t5} {
--   1 "DELETE FROM t5 WHERE a=2"                        {2 b 2} {1 a 3 c}
--   2 "INSERT OR REPLACE INTO t5 VALUES(2, 'd')"        {2 b 2} {1 a 2 d 3 c}
--   3 "UPDATE OR REPLACE t5 SET a = 2 WHERE a = 3"      {2 b 2} {1 a 2 c}
--   4 "INSERT OR REPLACE INTO t5 VALUES(4, 'b')"        {2 b 2} {1 a 3 c 4 b}
--   5 "UPDATE OR REPLACE t5 SET b = 'b' WHERE b = 'c'"  {2 b 2} {1 a 3 b}
--   6 "INSERT OR REPLACE INTO t5 VALUES(2, 'c')"        {2 b 2 3 c 1} {1 a 2 c}
--   7 "UPDATE OR REPLACE t5 SET a=1, b='b' WHERE a = 3" {1 a 2 2 b 1} {1 b}
-- } {
--   do_test triggerC-5.2.$n {
--     execsql "
--       BEGIN;
--         $dml ;
--         SELECT * FROM t5g ORDER BY rowid;
--         SELECT * FROM t5 ORDER BY rowid;
--       ROLLBACK;
--     "
--   } [concat $t5g $t5]
-- }

-- MUST_WORK_TEST
-- foreach {n dml t5g t5} {
--   1 "DELETE FROM t5 WHERE a=2"                        {2 b 2} {1 a 3 c}
--   2 "INSERT OR REPLACE INTO t5 VALUES(2, 'd')"        {} {1 a 2 d 3 c}
--   3 "UPDATE OR REPLACE t5 SET a = 2 WHERE a = 3"      {} {1 a 2 c}
--   4 "INSERT OR REPLACE INTO t5 VALUES(4, 'b')"        {} {1 a 3 c 4 b}
--   5 "UPDATE OR REPLACE t5 SET b = 'b' WHERE b = 'c'"  {} {1 a 3 b}
--   6 "INSERT OR REPLACE INTO t5 VALUES(2, 'c')"        {} {1 a 2 c}
--   7 "UPDATE OR REPLACE t5 SET a=1, b='b' WHERE a = 3" {} {1 b}
-- } {
--   do_test triggerC-5.3.$n {
--     execsql "
--       BEGIN;
--         $dml ;
--         SELECT * FROM t5g ORDER BY rowid;
--         SELECT * FROM t5 ORDER BY rowid;
--       ROLLBACK;
--     "
--   } [concat $t5g $t5]
-- }

-- MUST_WORK_TEST
-- #-------------------------------------------------------------------------
-- # Test some of the "undefined behaviour" associated with triggers. The
-- # undefined behaviour occurs when a row being updated or deleted is
-- # manipulated by a BEFORE trigger.
-- #
-- do_test triggerC-7.1 {
--   execsql {
--     CREATE TABLE t8(x);
--     CREATE TABLE t7(a, b);
--     INSERT INTO t7 VALUES(1, 2);
--     INSERT INTO t7 VALUES(3, 4);
--     INSERT INTO t7 VALUES(5, 6);
--     CREATE TRIGGER t7t BEFORE UPDATE ON t7 FOR EACH ROW BEGIN
--       DELETE FROM t7 WHERE a = 1;
--     END;
--     CREATE TRIGGER t7ta AFTER UPDATE ON t7 FOR EACH ROW BEGIN
--       INSERT INTO t8 VALUES('after fired ' || old.rowid || '->' || new.rowid);
--     END;
--   }
-- } {}
-- do_test triggerC-7.2 {
--   execsql {
--     BEGIN;
--       UPDATE t7 SET b=7 WHERE a = 5;
--       SELECT * FROM t7;
--       SELECT * FROM t8;
--     ROLLBACK;
--   }
-- } {3 4 5 7 {after fired 3->3}}
-- do_test triggerC-7.3 {
--   execsql {
--     BEGIN;
--       UPDATE t7 SET b=7 WHERE a = 1;
--       SELECT * FROM t7;
--       SELECT * FROM t8;
--     ROLLBACK;
--   }
-- } {3 4 5 6}
-- do_test triggerC-7.4 {
--   execsql {
--     DROP TRIGGER t7t;
--     CREATE TRIGGER t7t BEFORE UPDATE ON t7 FOR EACH ROW WHEN (old.rowid!=1 OR new.rowid!=8)
--     BEGIN
--       UPDATE t7 set rowid = 8 WHERE rowid=1;
--     END;
--   }
-- } {}
-- do_test triggerC-7.5 {
--   execsql {
--     BEGIN;
--       UPDATE t7 SET b=7 WHERE a = 5;
--       SELECT rowid, * FROM t7;
--       SELECT * FROM t8;
--     ROLLBACK;
--   }
-- } {2 3 4 3 5 7 8 1 2 {after fired 1->8} {after fired 3->3}}
-- do_test triggerC-7.6 {
--   execsql {
--     BEGIN;
--       UPDATE t7 SET b=7 WHERE a = 1;
--       SELECT rowid, * FROM t7;
--       SELECT * FROM t8;
--     ROLLBACK;
--   }
-- } {2 3 4 3 5 6 8 1 2 {after fired 1->8}}
-- do_test triggerC-7.7 {
--   execsql {
--     DROP TRIGGER t7t;
--     DROP TRIGGER t7ta;
--     CREATE TRIGGER t7t BEFORE DELETE ON t7 FOR EACH ROW BEGIN
--       UPDATE t7 set rowid = 8 WHERE rowid=1;
--     END;
--     CREATE TRIGGER t7ta AFTER DELETE ON t7 FOR EACH ROW BEGIN
--       INSERT INTO t8 VALUES('after fired ' || old.rowid);
--     END;
--   }
-- } {}
-- do_test triggerC-7.8 {
--   execsql {
--     BEGIN;
--       DELETE FROM t7 WHERE a = 3;
--       SELECT rowid, * FROM t7;
--       SELECT * FROM t8;
--     ROLLBACK;
--   }
-- } {3 5 6 8 1 2 {after fired 2}}
-- do_test triggerC-7.9 {
--   execsql {
--     BEGIN;
--       DELETE FROM t7 WHERE a = 1;
--       SELECT rowid, * FROM t7;
--       SELECT * FROM t8;
--     ROLLBACK;
--   }
-- } {2 3 4 3 5 6 8 1 2}
-- # Ticket [e25d9ea771febc9c311928c1c01c3163dcb26643]
-- #
-- do_test triggerC-9.1 {
--   execsql {
--     CREATE TABLE t9(a,b);
--     CREATE INDEX t9b ON t9(b);
--     INSERT INTO t9 VALUES(1,0);
--     INSERT INTO t9 VALUES(2,1);
--     INSERT INTO t9 VALUES(3,2);
--     INSERT INTO t9 SELECT a+3, a+2 FROM t9;
--     INSERT INTO t9 SELECT a+6, a+5 FROM t9;
--     SELECT a FROM t9 ORDER BY a;
--   }
-- } {1 2 3 4 5 6 7 8 9 10 11 12}
-- do_test triggerC-9.2 {
--   execsql {
--     CREATE TRIGGER t9r1 AFTER DELETE ON t9 FOR EACH ROW BEGIN
--       DELETE FROM t9 WHERE b=old.a;
--     END;
--     DELETE FROM t9 WHERE b=4;
--     SELECT a FROM t9 ORDER BY a;
--   }
-- } {1 2 3 4}
-- At one point (between versions 3.6.18 and 3.6.20 inclusive), an UPDATE
-- that fired a BEFORE trigger that itself updated the same row as the
-- statement causing it to fire was causing a strange side-effect: The
-- values updated by the statement within the trigger were being overwritten
-- by the values in the new.* array, even if those values were not
-- themselves written by the parent UPDATE statement.
--
-- Technically speaking this was not a bug. The sql documentation says
-- that if a BEFORE UPDATE or BEFORE DELETE trigger modifies or deletes the
-- row that the parent statement is operating on the results are undefined.
-- But as of 3.6.21 behaviour is restored to the way it was in versions
-- 3.6.17 and earlier to avoid causing unnecessary difficulties.
--
test:do_test(
    "triggerC-10.1",
    function()
        test:execsql [[
            CREATE TABLE t10(id INT PRIMARY KEY, a TEXT, updatecnt INT DEFAULT 0);
            CREATE UNIQUE INDEX t10i1 ON t10(a);
            CREATE TRIGGER t10_bu BEFORE UPDATE OF a ON t10 FOR EACH ROW BEGIN
              UPDATE t10 SET updatecnt = updatecnt+1 WHERE a = old.a;
            END;
            INSERT INTO t10 VALUES(0, 'hello', 0);
        ]]
        -- Before the problem was fixed, table t10 would contain the tuple
        -- (world, 0) after running the following script (because the value
        -- 1 written to column "updatecnt" was clobbered by the old value 0).
        --
        return test:execsql [[
            UPDATE t10 SET a = 'world';
            SELECT * FROM t10;
        ]]
    end, {
        -- <triggerC-10.1>
        0, "world", 1
        -- </triggerC-10.1>
    })

test:do_execsql_test(
    "triggerC-10.2",
    [[
        UPDATE t10 SET a = 'tcl', updatecnt = 5;
        SELECT * FROM t10;
    ]], {
        -- <triggerC-10.2>
        0, "tcl", 5
        -- </triggerC-10.2>
    })

test:do_test(
    "triggerC-10.3",
    function()
        test:execsql [[
            CREATE TABLE t11(
              c0 INT PRIMARY KEY, c1 INT UNIQUE,   c2 INT,  c3 INT,  c4 INT,  c5 INT,  c6 INT,  c7 INT,
              c8 INT,  c9 INT, c10 INT, c11 INT, c12 INT, c13 INT, c14 INT, c15 INT, c16 INT,
              c17 INT, c18 INT, c19 INT, c20 INT, c21 INT, c22 INT, c23 INT, c24 INT, c25 INT,
              c26 INT, c27 INT, c28 INT, c29 INT, c30 INT, c31 INT, c32 INT, c33 INT, c34 INT,
              c35 INT, c36 INT, c37 INT, c38 INT, c39 INT, c40 INT
            );

            CREATE TRIGGER t11_bu BEFORE UPDATE OF c1 ON t11 FOR EACH ROW BEGIN
              UPDATE t11 SET c31 = c31+1, c32=c32+1 WHERE c2 = old.c2;
            END;

            INSERT INTO t11 VALUES(
              0, 1,   2,  3,  4,  5,  6,  7,  8,  9, 10,
              11, 12, 13, 14, 15, 16, 17, 18, 19, 20,
              21, 22, 23, 24, 25, 26, 27, 28, 29, 30,
              31, 32, 33, 34, 35, 36, 37, 38, 39, 40
            );
        ]]
        -- Before the problem was fixed, table t10 would contain the tuple
        -- (world, 0) after running the following script (because the value
        -- 1 written to column "updatecnt" was clobbered by the old value 0).
        --
        return test:execsql [[
            UPDATE t11 SET c4=35, c33=22, c1=5;
            SELECT * FROM t11;
        ]]
    end, {
        -- <triggerC-10.3>
        0, 5, 2, 3, 35, 5, 6, 7, 8, 9, 10, 11, 12, 13, 14, 15, 16, 17, 18, 19, 20, 21, 22, 23, 24, 25, 26, 27, 28, 29, 30, 32, 33, 22, 34, 35, 36, 37, 38, 39, 40
        -- </triggerC-10.3>
    })

-- #-------------------------------------------------------------------------
-- # Test that bug [371bab5d65] has been fixed. BEFORE INSERT and INSTEAD OF
-- # INSERT triggers with the DEFAULT VALUES INSERT syntax.
-- #
test:do_test(
    "triggerC-11.0",
    function()
        test:catchsql " DROP TABLE IF EXISTS log "
        return test:execsql " CREATE TABLE log(id INTEGER PRIMARY KEY, a INT, b TEXT) "
    end, {
        -- <triggerC-11.0>

        -- </triggerC-11.0>
    })

-- MUST_WORK_TEST
local
tests11 = {-- {"CREATE TABLE t1(a PRIMARY KEY, b)",                         {{}, {}}},
           {"CREATE TABLE t1(a INT PRIMARY KEY DEFAULT 1, b TEXT DEFAULT 'abc')", {1, "abc"}}}

--for _ in X(0, "X!foreach", [=[["testno tbl defaults","\n  1 \"CREATE TABLE t1(a PRIMARY KEY, b)\"                          {{} {}}\n  2 \"CREATE TABLE t1(a PRIMARY KEY DEFAULT 1, b DEFAULT 'abc')\"  {1 abc}\n  3 \"CREATE TABLE t1(a PRIMARY KEY, b DEFAULT 4.5)\"              {{} 4.5}\n"]]=]) do
for testno, v in ipairs(tests11) do
    test:do_test(
        "triggerC-11."..testno..".1",
        function()
            test:catchsql " DROP TABLE t1 "
            test:execsql " DELETE FROM log "
            test:execsql(v[1])
            return test:execsql [[
                CREATE TRIGGER tt1 BEFORE INSERT ON t1 FOR EACH ROW BEGIN
                  INSERT INTO log VALUES((SELECT coalesce(max(id),0) + 1 FROM log),
                                         new.a, new.b);
                END;
                INSERT INTO t1 DEFAULT VALUES;
                SELECT a,b FROM log;
            ]]
        end, v[2])

    -- Tarantool: we're unable to do double insert of default vals
    -- (PK will be not unique). Comment so far
    -- test:do_test(
    --     "triggerC-11."..testno..".2",
    --     function()
    --         test:execsql " DELETE FROM log "
    --         return test:execsql [[
    --             CREATE TRIGGER tt2 AFTER INSERT ON t1 FOR EACH ROW BEGIN
    --               INSERT INTO log VALUES(new.a, new.b);
    --             END;
    --             INSERT INTO t1 DEFAULT VALUES;
    --             SELECT * FROM log;
    --         ]]
    --     end, {
    --         -- X(891, "X!cmd", [=[["concat",["defaults"],["defaults"]]]=])
    --     })

    test:do_test(
        "triggerC-11."..testno..".3",
        function()
            test:execsql " DROP TRIGGER tt1 "
            test:execsql " DELETE FROM t1"
            test:execsql " DELETE FROM log "
            return test:execsql [[
                INSERT INTO t1 DEFAULT VALUES;
                SELECT a,b FROM log;
            ]]
        end, {
            defaults
        })

    --
end
test:do_test(
    "triggerC-11.4",
    function()
        test:catchsql " DROP TABLE t2 "
        return test:execsql [[
            DELETE FROM log;
            CREATE TABLE t2(a INT PRIMARY KEY, b INT);
            CREATE VIEW v2 AS SELECT * FROM t2;
            CREATE TRIGGER tv2 INSTEAD OF INSERT ON v2 FOR EACH ROW BEGIN
              INSERT INTO log VALUES((SELECT coalesce(max(id),0) + 1 FROM log),
                                     new.a, new.b);
            END;
            INSERT INTO v2 DEFAULT VALUES;
            SELECT a, b, a IS NULL, b IS NULL FROM log;
        ]]
    end, {
        -- <triggerC-11.4>
        "", "", true, true
        -- </triggerC-11.4>
    })

-- do_test triggerC-12.1 {
--   db close
--   forcedelete test.db
--   sql db test.db
test:execsql(
    [[
    DROP TABLE t1;
    CREATE TABLE t1(id INTEGER PRIMARY KEY, a INT, b INT);
    INSERT INTO t1 VALUES(1, 1, 2);
    INSERT INTO t1 VALUES(2, 3, 4);
    INSERT INTO t1 VALUES(3, 5, 6);
    CREATE TRIGGER tr1 AFTER INSERT ON t1 FOR EACH ROW BEGIN SELECT 1 ; END ;]])

test:do_execsql_test(
    "triggerC-13.1",
    [[
        UPDATE "_session_settings" SET "value" = true WHERE "name" = 'sql_recursive_triggers';
        CREATE TABLE t12(id INTEGER PRIMARY KEY, a INT, b INT);
        INSERT INTO t12 VALUES(1, 1, 2);
        CREATE TRIGGER tr12 AFTER UPDATE ON t12 FOR EACH ROW BEGIN
          UPDATE t12 SET a=new.a+1, b=new.b+1;
        END;
    ]], {
        -- <triggerC-13.1>

        -- </triggerC-13.1>
    })

test:do_catchsql_test(
    "triggerC-13.2",
    [[
        UPDATE t12 SET a=a+1, b=b+1;
    ]], {
        -- <triggerC-13.2>
        1, "Failed to execute SQL statement: too many levels of trigger recursion"
        -- </triggerC-13.2>
    })

---------------------------------------------------------------------------
-- The following tests seek to verify that constant values (i.e. literals)
-- are not factored out of loops within trigger programs. sql does
-- not factor constants out of loops within trigger programs as it may only
-- do so in code generated before the first table or index is opened. And
-- by the time a trigger program is coded, at least one table or index has
-- always been opened.
--
-- At one point, due to a bug allowing constant factoring within triggers,
-- the following SQL would produce the wrong result.
--
SQL = [[
  DROP TABLE IF EXISTS t1;
  DROP VIEW v2;
  DROP TABLE IF EXISTS t2;
  DROP TABLE IF EXISTS t4;
  DROP TABLE IF EXISTS t5;
  CREATE TABLE t1(a INT PRIMARY KEY, b INT, c INT);
  CREATE INDEX i1 ON t1(a, c);
  CREATE INDEX i2 ON t1(b, c);
  INSERT INTO t1 VALUES(1, 2, 3);

  CREATE TABLE t2(e INT PRIMARY KEY, f INT);
  CREATE INDEX i3 ON t2(e);
  INSERT INTO t2 VALUES(1234567, 3);

  CREATE TABLE empty(x INT PRIMARY KEY);
  CREATE TABLE not_empty(x INT PRIMARY KEY);
  INSERT INTO not_empty VALUES(2);

  CREATE TABLE t4(x INT PRIMARY KEY);
  CREATE TABLE t5(g INT PRIMARY KEY, h INT, i INT);

  CREATE TRIGGER trig BEFORE INSERT ON t4 FOR EACH ROW BEGIN
    INSERT INTO t5 SELECT * FROM t1 WHERE
        (a IN (SELECT x FROM empty) OR b IN (SELECT x FROM not_empty))
        AND c IN (SELECT f FROM t2 WHERE e=1234567);
  END;

  INSERT INTO t4 VALUES(0);
  SELECT * FROM t5;
]]
-- reset_db
test:do_execsql_test(
    "triggerC-14.1",
    SQL, {
        -- <triggerC-14.1>
        1, 2, 3
        -- </triggerC-14.1>
    })

-- reset_db
-- optimization_control db factor-constants 0
-- do_execsql_test triggerC-14.2 $SQL {1 2 3}
-- MUST_WORK_TEST
---------------------------------------------------------------------------
-- Check that table names used by trigger programs are dequoted exactly
-- once.
--
test:do_execsql_test(
    "triggerC-15.1.1",
    [[
        UPDATE "_session_settings" SET "value" = true WHERE "name" = 'sql_recursive_triggers';
        CREATE TABLE node(
            id int not null primary key,
            pid int not null default 0,
            key TEXT not null,
            path TEXT default '',
            unique(pid, key)
            );
        CREATE TRIGGER node_delete_referencing AFTER DELETE ON node
          FOR EACH ROW
          BEGIN
          DELETE FROM node WHERE pid = old.id;
        END;
    ]])

test:do_execsql_test(
    "triggerC-15.1.2",
    [[
        INSERT INTO node(id, pid, key) VALUES(9, 0, 'test');
        INSERT INTO node(id, pid, key) VALUES(90, 9, 'test1');
        INSERT INTO node(id, pid, key) VALUES(900, 90, 'test2');
        DELETE FROM node WHERE id=9;
        SELECT * FROM node;
    ]])

-- Tarantool: such indentifiers are not working
-- Comment so far
-- test:do_execsql_test(
--     "15.2.1",
--     [[
--         CREATE TABLE   x1  (x PRIMARY KEY);

--         CREATE TABLE '"x2"'(a PRIMARY KEY, b);

--         INSERT INTO x2 VALUES(1, 2);
--         INSERT INTO x2 VALUES(3, 4);
--         INSERT INTO '"x2"' SELECT * FROM x2;

--         CREATE TRIGGER x1ai AFTER INSERT ON x1 FOR EACH ROW BEGIN
--           INSERT INTO """x2""" VALUES('x', 'y');
--           DELETE FROM """x2""" WHERE a=1;
--           UPDATE """x2""" SET b = 11 WHERE a = 3;
--         END;

--         INSERT INTO x1 VALUES('go!');
--     ]])

-- test:do_execsql_test(
--     "15.2.2",
--     [[
--         SELECT * FROM x2;
--     ]], {
--         -- <15.2.2>
--         1, 2, 3, 4
--         -- </15.2.2>
--     })

-- test:do_execsql_test(
--     "15.2.3",
--     [[
--         SELECT * FROM """x2""";
--     ]], {
--         -- <15.2.3>
--         3, 11, "x", "y"
--         -- </15.2.3>
--     })

test:finish_test()