trigger2.test 15 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386387388389390391392393394395396397398399400401402403404405406407408409410411412413414415416417418419420421422423424425426427428429430431432433434435436437438439440441442443444445446447448449450451452453454455456457458459460461462463464465466467468469470471472473474475476477478479480481482483484485486487488489490491492493494495496497498499500501502503504505506507508509510511512513514515516517518519520521522523524525526527528529530531532533534535536537538539540541542543544545546547548549550551552553554555556557558559560561562563564565566567568569570571572573574575576577578579580581582583584585586587588589590591592593594595596597598599600
  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. # Regression testing of FOR EACH ROW table triggers
  11. #
  12. # 1. Trigger execution order tests.
  13. # These tests ensure that BEFORE and AFTER triggers are fired at the correct
  14. # times relative to each other and the triggering statement.
  15. #
  16. # trig-1.1.*: ON UPDATE trigger execution model.
  17. # trig-1.2.*: DELETE trigger execution model.
  18. # trig-1.3.*: INSERT trigger execution model.
  19. #
  20. # 2. Trigger program execution tests.
  21. # These tests ensure that trigger programs execute correctly (ie. that a
  22. # trigger program can correctly execute INSERT, UPDATE, DELETE * SELECT
  23. # statements, and combinations thereof).
  24. #
  25. # 3. Selective trigger execution
  26. # This tests that conditional triggers (ie. UPDATE OF triggers and triggers
  27. # with WHEN clauses) are fired only fired when they are supposed to be.
  28. #
  29. # trig-3.1: UPDATE OF triggers
  30. # trig-3.2: WHEN clause
  31. #
  32. # 4. Cascaded trigger execution
  33. # Tests that trigger-programs may cause other triggers to fire. Also that a
  34. # trigger-program is never executed recursively.
  35. #
  36. # trig-4.1: Trivial cascading trigger
  37. # trig-4.2: Trivial recursive trigger handling
  38. #
  39. # 5. Count changes behaviour.
  40. # Verify that rows altered by triggers are not included in the return value
  41. # of the "count changes" interface.
  42. #
  43. # 6. ON CONFLICT clause handling
  44. # trig-6.1[a-f]: INSERT statements
  45. # trig-6.2[a-f]: UPDATE statements
  46. #
  47. # 7. Triggers on views fire correctly.
  48. #
  49. set testdir [file dirname $argv0]
  50. source $testdir/tester.tcl
  51. # 1.
  52. set ii 0
  53. foreach tbl_defn [ list \
  54. {CREATE TABLE tbl (a, b);} \
  55. {CREATE TABLE tbl (a INTEGER PRIMARY KEY, b);} \
  56. {CREATE TABLE tbl (a, b PRIMARY KEY);} \
  57. {CREATE TABLE tbl (a, b); CREATE INDEX tbl_idx ON tbl(b);} ] {
  58. incr ii
  59. catchsql { DROP INDEX tbl_idx; }
  60. catchsql {
  61. DROP TABLE rlog;
  62. DROP TABLE clog;
  63. DROP TABLE tbl;
  64. DROP TABLE other_tbl;
  65. }
  66. execsql $tbl_defn
  67. execsql {
  68. INSERT INTO tbl VALUES(1, 2);
  69. INSERT INTO tbl VALUES(3, 4);
  70. CREATE TABLE rlog (idx, old_a, old_b, db_sum_a, db_sum_b, new_a, new_b);
  71. CREATE TABLE clog (idx, old_a, old_b, db_sum_a, db_sum_b, new_a, new_b);
  72. CREATE TRIGGER before_update_row BEFORE UPDATE ON tbl FOR EACH ROW
  73. BEGIN
  74. INSERT INTO rlog VALUES ( (SELECT coalesce(max(idx),0) + 1 FROM rlog),
  75. old.a, old.b,
  76. (SELECT sum(a) FROM tbl), (SELECT sum(b) FROM tbl),
  77. new.a, new.b);
  78. END;
  79. CREATE TRIGGER after_update_row AFTER UPDATE ON tbl FOR EACH ROW
  80. BEGIN
  81. INSERT INTO rlog VALUES ( (SELECT coalesce(max(idx),0) + 1 FROM rlog),
  82. old.a, old.b,
  83. (SELECT sum(a) FROM tbl), (SELECT sum(b) FROM tbl),
  84. new.a, new.b);
  85. END;
  86. CREATE TRIGGER conditional_update_row AFTER UPDATE ON tbl FOR EACH ROW
  87. WHEN old.a = 1
  88. BEGIN
  89. INSERT INTO clog VALUES ( (SELECT coalesce(max(idx),0) + 1 FROM clog),
  90. old.a, old.b,
  91. (SELECT sum(a) FROM tbl), (SELECT sum(b) FROM tbl),
  92. new.a, new.b);
  93. END;
  94. }
  95. do_test trig-1.1.$ii {
  96. execsql {
  97. UPDATE tbl SET a = a * 10, b = b * 10;
  98. SELECT * FROM rlog ORDER BY idx;
  99. SELECT * FROM clog ORDER BY idx;
  100. }
  101. } [list 1 1 2 4 6 10 20 \
  102. 2 1 2 13 24 10 20 \
  103. 3 3 4 13 24 30 40 \
  104. 4 3 4 40 60 30 40 \
  105. 1 1 2 13 24 10 20 ]
  106. execsql {
  107. DELETE FROM rlog;
  108. DELETE FROM tbl;
  109. INSERT INTO tbl VALUES (100, 100);
  110. INSERT INTO tbl VALUES (300, 200);
  111. CREATE TRIGGER delete_before_row BEFORE DELETE ON tbl FOR EACH ROW
  112. BEGIN
  113. INSERT INTO rlog VALUES ( (SELECT coalesce(max(idx),0) + 1 FROM rlog),
  114. old.a, old.b,
  115. (SELECT sum(a) FROM tbl), (SELECT sum(b) FROM tbl),
  116. 0, 0);
  117. END;
  118. CREATE TRIGGER delete_after_row AFTER DELETE ON tbl FOR EACH ROW
  119. BEGIN
  120. INSERT INTO rlog VALUES ( (SELECT coalesce(max(idx),0) + 1 FROM rlog),
  121. old.a, old.b,
  122. (SELECT sum(a) FROM tbl), (SELECT sum(b) FROM tbl),
  123. 0, 0);
  124. END;
  125. }
  126. do_test trig-1.2.$ii {
  127. execsql {
  128. DELETE FROM tbl;
  129. SELECT * FROM rlog;
  130. }
  131. } [list 1 100 100 400 300 0 0 \
  132. 2 100 100 300 200 0 0 \
  133. 3 300 200 300 200 0 0 \
  134. 4 300 200 0 0 0 0 ]
  135. execsql {
  136. DELETE FROM rlog;
  137. CREATE TRIGGER insert_before_row BEFORE INSERT ON tbl FOR EACH ROW
  138. BEGIN
  139. INSERT INTO rlog VALUES ( (SELECT coalesce(max(idx),0) + 1 FROM rlog),
  140. 0, 0,
  141. (SELECT sum(a) FROM tbl), (SELECT sum(b) FROM tbl),
  142. new.a, new.b);
  143. END;
  144. CREATE TRIGGER insert_after_row AFTER INSERT ON tbl FOR EACH ROW
  145. BEGIN
  146. INSERT INTO rlog VALUES ( (SELECT coalesce(max(idx),0) + 1 FROM rlog),
  147. 0, 0,
  148. (SELECT sum(a) FROM tbl), (SELECT sum(b) FROM tbl),
  149. new.a, new.b);
  150. END;
  151. }
  152. do_test trig-1.3.$ii {
  153. execsql {
  154. CREATE TABLE other_tbl(a, b);
  155. INSERT INTO other_tbl VALUES(1, 2);
  156. INSERT INTO other_tbl VALUES(3, 4);
  157. -- INSERT INTO tbl SELECT * FROM other_tbl;
  158. INSERT INTO tbl VALUES(5, 6);
  159. DROP TABLE other_tbl;
  160. SELECT * FROM rlog;
  161. }
  162. } [list 1 0 0 0 0 5 6 \
  163. 2 0 0 5 6 5 6 ]
  164. }
  165. catchsql {
  166. DROP TABLE rlog;
  167. DROP TABLE clog;
  168. DROP TABLE tbl;
  169. DROP TABLE other_tbl;
  170. }
  171. # 2.
  172. set ii 0
  173. foreach tr_program [ list \
  174. {UPDATE tbl SET b = old.b;} \
  175. {INSERT INTO log VALUES(new.c, 2, 3);} \
  176. {DELETE FROM log WHERE a = 1;} \
  177. {INSERT INTO tbl VALUES(500, new.b * 10, 700);
  178. UPDATE tbl SET c = old.c;
  179. DELETE FROM log;} \
  180. {INSERT INTO log select * from tbl;}
  181. ] \
  182. {
  183. foreach test_varset [ list \
  184. {
  185. set statement {UPDATE tbl SET c = 10 WHERE a = 1;}
  186. set prep {INSERT INTO tbl VALUES(1, 2, 3);}
  187. set newC 10
  188. set newB 2
  189. set newA 1
  190. set oldA 1
  191. set oldB 2
  192. set oldC 3
  193. } \
  194. {
  195. set statement {DELETE FROM tbl WHERE a = 1;}
  196. set prep {INSERT INTO tbl VALUES(1, 2, 3);}
  197. set oldA 1
  198. set oldB 2
  199. set oldC 3
  200. } \
  201. {
  202. set statement {INSERT INTO tbl VALUES(1, 2, 3);}
  203. set newA 1
  204. set newB 2
  205. set newC 3
  206. }
  207. ] \
  208. {
  209. set statement {}
  210. set prep {}
  211. set newA {''}
  212. set newB {''}
  213. set newC {''}
  214. set oldA {''}
  215. set oldB {''}
  216. set oldC {''}
  217. incr ii
  218. eval $test_varset
  219. set statement_type [string range $statement 0 5]
  220. set tr_program_fixed $tr_program
  221. if {$statement_type == "DELETE"} {
  222. regsub -all new\.a $tr_program_fixed {''} tr_program_fixed
  223. regsub -all new\.b $tr_program_fixed {''} tr_program_fixed
  224. regsub -all new\.c $tr_program_fixed {''} tr_program_fixed
  225. }
  226. if {$statement_type == "INSERT"} {
  227. regsub -all old\.a $tr_program_fixed {''} tr_program_fixed
  228. regsub -all old\.b $tr_program_fixed {''} tr_program_fixed
  229. regsub -all old\.c $tr_program_fixed {''} tr_program_fixed
  230. }
  231. set tr_program_cooked $tr_program
  232. regsub -all new\.a $tr_program_cooked $newA tr_program_cooked
  233. regsub -all new\.b $tr_program_cooked $newB tr_program_cooked
  234. regsub -all new\.c $tr_program_cooked $newC tr_program_cooked
  235. regsub -all old\.a $tr_program_cooked $oldA tr_program_cooked
  236. regsub -all old\.b $tr_program_cooked $oldB tr_program_cooked
  237. regsub -all old\.c $tr_program_cooked $oldC tr_program_cooked
  238. catchsql {
  239. DROP TABLE tbl;
  240. DROP TABLE log;
  241. }
  242. execsql {
  243. CREATE TABLE tbl(a PRIMARY KEY, b, c);
  244. CREATE TABLE log(a, b, c);
  245. }
  246. set query {SELECT * FROM tbl; SELECT * FROM log;}
  247. set prep "$prep; INSERT INTO log VALUES(1, 2, 3); INSERT INTO log VALUES(10, 20, 30);"
  248. # Check execution of BEFORE programs:
  249. set before_data [ execsql "$prep $tr_program_cooked $statement $query" ]
  250. execsql "DELETE FROM tbl; DELETE FROM log; $prep";
  251. execsql "CREATE TRIGGER the_trigger BEFORE [string range $statement 0 6] ON tbl BEGIN $tr_program_fixed END;"
  252. do_test trig-2-$ii-before "execsql {$statement $query}" $before_data
  253. execsql "DROP TRIGGER the_trigger;"
  254. execsql "DELETE FROM tbl; DELETE FROM log;"
  255. # Check execution of AFTER programs
  256. set after_data [ execsql "$prep $statement $tr_program_cooked $query" ]
  257. execsql "DELETE FROM tbl; DELETE FROM log; $prep";
  258. execsql "CREATE TRIGGER the_trigger AFTER [string range $statement 0 6] ON tbl BEGIN $tr_program_fixed END;"
  259. do_test trig-2-$ii-after "execsql {$statement $query}" $after_data
  260. execsql "DROP TRIGGER the_trigger;"
  261. }
  262. }
  263. catchsql {
  264. DROP TABLE tbl;
  265. DROP TABLE log;
  266. }
  267. # 3.
  268. # trig-3.1: UPDATE OF triggers
  269. execsql {
  270. CREATE TABLE tbl (a, b, c, d);
  271. CREATE TABLE log (a);
  272. INSERT INTO log VALUES (0);
  273. INSERT INTO tbl VALUES (0, 0, 0, 0);
  274. INSERT INTO tbl VALUES (1, 0, 0, 0);
  275. CREATE TRIGGER tbl_after_update_cd BEFORE UPDATE OF c, d ON tbl
  276. BEGIN
  277. UPDATE log SET a = a + 1;
  278. END;
  279. }
  280. do_test trig-3.1 {
  281. execsql {
  282. UPDATE tbl SET b = 1, c = 10; -- 2
  283. UPDATE tbl SET b = 10; -- 0
  284. UPDATE tbl SET d = 4 WHERE a = 0; --1
  285. UPDATE tbl SET a = 4, b = 10; --0
  286. SELECT * FROM log;
  287. }
  288. } {3}
  289. execsql {
  290. DROP TABLE tbl;
  291. DROP TABLE log;
  292. }
  293. # trig-3.2: WHEN clause
  294. set when_triggers [ list \
  295. {t1 BEFORE INSERT ON tbl WHEN new.a > 20} \
  296. {t2 BEFORE INSERT ON tbl WHEN (SELECT count(*) FROM tbl) = 0} ]
  297. execsql {
  298. CREATE TABLE tbl (a, b, c, d);
  299. CREATE TABLE log (a);
  300. INSERT INTO log VALUES (0);
  301. }
  302. foreach trig $when_triggers {
  303. execsql "CREATE TRIGGER $trig BEGIN UPDATE log set a = a + 1; END;"
  304. }
  305. do_test trig-3.2 {
  306. execsql {
  307. INSERT INTO tbl VALUES(0, 0, 0, 0); -- 1
  308. SELECT * FROM log;
  309. UPDATE log SET a = 0;
  310. INSERT INTO tbl VALUES(0, 0, 0, 0); -- 0
  311. SELECT * FROM log;
  312. UPDATE log SET a = 0;
  313. INSERT INTO tbl VALUES(200, 0, 0, 0); -- 1
  314. SELECT * FROM log;
  315. UPDATE log SET a = 0;
  316. }
  317. } {1 0 1}
  318. execsql {
  319. DROP TABLE tbl;
  320. DROP TABLE log;
  321. }
  322. # Simple cascaded trigger
  323. execsql {
  324. CREATE TABLE tblA(a, b);
  325. CREATE TABLE tblB(a, b);
  326. CREATE TABLE tblC(a, b);
  327. CREATE TRIGGER tr1 BEFORE INSERT ON tblA BEGIN
  328. INSERT INTO tblB values(new.a, new.b);
  329. END;
  330. CREATE TRIGGER tr2 BEFORE INSERT ON tblB BEGIN
  331. INSERT INTO tblC values(new.a, new.b);
  332. END;
  333. }
  334. do_test trig-4.1 {
  335. execsql {
  336. INSERT INTO tblA values(1, 2);
  337. SELECT * FROM tblA;
  338. SELECT * FROM tblB;
  339. SELECT * FROM tblC;
  340. }
  341. } {1 2 1 2 1 2}
  342. execsql {
  343. DROP TABLE tblA;
  344. DROP TABLE tblB;
  345. DROP TABLE tblC;
  346. }
  347. # Simple recursive trigger
  348. execsql {
  349. CREATE TABLE tbl(a, b, c);
  350. CREATE TRIGGER tbl_trig BEFORE INSERT ON tbl
  351. BEGIN
  352. INSERT INTO tbl VALUES (new.a, new.b, new.c);
  353. END;
  354. }
  355. do_test trig-4.2 {
  356. execsql {
  357. INSERT INTO tbl VALUES (1, 2, 3);
  358. select * from tbl;
  359. }
  360. } {1 2 3 1 2 3}
  361. execsql {
  362. DROP TABLE tbl;
  363. }
  364. # 5.
  365. execsql {
  366. CREATE TABLE tbl(a, b, c);
  367. CREATE TRIGGER tbl_trig BEFORE INSERT ON tbl
  368. BEGIN
  369. INSERT INTO tbl VALUES (1, 2, 3);
  370. INSERT INTO tbl VALUES (2, 2, 3);
  371. UPDATE tbl set b = 10 WHERE a = 1;
  372. DELETE FROM tbl WHERE a = 1;
  373. DELETE FROM tbl;
  374. END;
  375. }
  376. do_test trig-5 {
  377. execsql {
  378. INSERT INTO tbl VALUES(100, 200, 300);
  379. }
  380. db changes
  381. } {1}
  382. execsql {
  383. DROP TABLE tbl;
  384. }
  385. # Handling of ON CONFLICT by INSERT statements inside triggers
  386. execsql {
  387. CREATE TABLE tbl (a primary key, b, c);
  388. CREATE TRIGGER ai_tbl AFTER INSERT ON tbl BEGIN
  389. INSERT OR IGNORE INTO tbl values (new.a, 0, 0);
  390. END;
  391. }
  392. do_test trig-6.1a {
  393. execsql {
  394. BEGIN;
  395. INSERT INTO tbl values (1, 2, 3);
  396. SELECT * from tbl;
  397. }
  398. } {1 2 3}
  399. do_test trig-6.1b {
  400. catchsql {
  401. INSERT OR ABORT INTO tbl values (2, 2, 3);
  402. }
  403. } {1 {constraint failed}}
  404. do_test trig-6.1c {
  405. execsql {
  406. SELECT * from tbl;
  407. }
  408. } {1 2 3}
  409. do_test trig-6.1d {
  410. catchsql {
  411. INSERT OR FAIL INTO tbl values (2, 2, 3);
  412. }
  413. } {1 {constraint failed}}
  414. do_test trig-6.1e {
  415. execsql {
  416. SELECT * from tbl;
  417. }
  418. } {1 2 3 2 2 3}
  419. do_test trig-6.1f {
  420. execsql {
  421. INSERT OR REPLACE INTO tbl values (2, 2, 3);
  422. SELECT * from tbl;
  423. }
  424. } {1 2 3 2 0 0}
  425. do_test trig-6.1g {
  426. catchsql {
  427. INSERT OR ROLLBACK INTO tbl values (3, 2, 3);
  428. }
  429. } {1 {constraint failed}}
  430. do_test trig-6.1h {
  431. execsql {
  432. SELECT * from tbl;
  433. }
  434. } {}
  435. # Handling of ON CONFLICT by UPDATE statements inside triggers
  436. execsql {
  437. INSERT INTO tbl values (4, 2, 3);
  438. INSERT INTO tbl values (6, 3, 4);
  439. CREATE TRIGGER au_tbl AFTER UPDATE ON tbl BEGIN
  440. UPDATE OR IGNORE tbl SET a = new.a, c = 10;
  441. END;
  442. }
  443. do_test trig-6.2a {
  444. execsql {
  445. BEGIN;
  446. UPDATE tbl SET a = 1 WHERE a = 4;
  447. SELECT * from tbl;
  448. }
  449. } {1 2 10 6 3 4}
  450. do_test trig-6.2b {
  451. catchsql {
  452. UPDATE OR ABORT tbl SET a = 4 WHERE a = 1;
  453. }
  454. } {1 {constraint failed}}
  455. do_test trig-6.2c {
  456. execsql {
  457. SELECT * from tbl;
  458. }
  459. } {1 2 10 6 3 4}
  460. do_test trig-6.2d {
  461. catchsql {
  462. UPDATE OR FAIL tbl SET a = 4 WHERE a = 1;
  463. }
  464. } {1 {constraint failed}}
  465. do_test trig-6.2e {
  466. execsql {
  467. SELECT * from tbl;
  468. }
  469. } {4 2 10 6 3 4}
  470. do_test trig-6.2f {
  471. execsql {
  472. UPDATE OR REPLACE tbl SET a = 1 WHERE a = 4;
  473. SELECT * from tbl;
  474. }
  475. } {1 3 10}
  476. execsql {
  477. INSERT INTO tbl VALUES (2, 3, 4);
  478. }
  479. do_test trig-6.2g {
  480. catchsql {
  481. UPDATE OR ROLLBACK tbl SET a = 4 WHERE a = 1;
  482. }
  483. } {1 {constraint failed}}
  484. do_test trig-6.2h {
  485. execsql {
  486. SELECT * from tbl;
  487. }
  488. } {4 2 3 6 3 4}
  489. execsql {
  490. DROP TABLE tbl;
  491. }
  492. # 7. Triggers on views
  493. do_test trig-7.1 {
  494. execsql {
  495. CREATE TABLE ab(a, b);
  496. CREATE TABLE cd(c, d);
  497. INSERT INTO ab VALUES (1, 2);
  498. INSERT INTO ab VALUES (0, 0);
  499. INSERT INTO cd VALUES (3, 4);
  500. CREATE TABLE tlog(ii INTEGER PRIMARY KEY,
  501. olda, oldb, oldc, oldd, newa, newb, newc, newd);
  502. CREATE VIEW abcd AS SELECT a, b, c, d FROM ab, cd;
  503. CREATE TRIGGER before_update INSTEAD OF UPDATE ON abcd BEGIN
  504. INSERT INTO tlog VALUES(NULL,
  505. old.a, old.b, old.c, old.d, new.a, new.b, new.c, new.d);
  506. END;
  507. CREATE TRIGGER after_update INSTEAD OF UPDATE ON abcd BEGIN
  508. INSERT INTO tlog VALUES(NULL,
  509. old.a, old.b, old.c, old.d, new.a, new.b, new.c, new.d);
  510. END;
  511. CREATE TRIGGER before_delete INSTEAD OF DELETE ON abcd BEGIN
  512. INSERT INTO tlog VALUES(NULL,
  513. old.a, old.b, old.c, old.d, 0, 0, 0, 0);
  514. END;
  515. CREATE TRIGGER after_delete INSTEAD OF DELETE ON abcd BEGIN
  516. INSERT INTO tlog VALUES(NULL,
  517. old.a, old.b, old.c, old.d, 0, 0, 0, 0);
  518. END;
  519. CREATE TRIGGER before_insert INSTEAD OF INSERT ON abcd BEGIN
  520. INSERT INTO tlog VALUES(NULL,
  521. 0, 0, 0, 0, new.a, new.b, new.c, new.d);
  522. END;
  523. CREATE TRIGGER after_insert INSTEAD OF INSERT ON abcd BEGIN
  524. INSERT INTO tlog VALUES(NULL,
  525. 0, 0, 0, 0, new.a, new.b, new.c, new.d);
  526. END;
  527. }
  528. } {}
  529. do_test trig-7.2 {
  530. execsql {
  531. UPDATE abcd SET a = 100, b = 5*5 WHERE a = 1;
  532. DELETE FROM abcd WHERE a = 1;
  533. INSERT INTO abcd VALUES(10, 20, 30, 40);
  534. SELECT * FROM tlog;
  535. }
  536. } [ list 1 1 2 3 4 100 25 3 4 \
  537. 2 1 2 3 4 100 25 3 4 \
  538. 3 1 2 3 4 0 0 0 0 \
  539. 4 1 2 3 4 0 0 0 0 \
  540. 5 0 0 0 0 10 20 30 40 \
  541. 6 0 0 0 0 10 20 30 40 ]
  542. finish_test