summaryrefslogtreecommitdiffstats
path: root/src/test/regress/sql/rules.sql
blob: b7ac6407b0dde8381f1e8337a8a6c5047801c605 (plain)
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
988
989
990
991
992
993
994
995
996
997
998
999
1000
1001
1002
1003
1004
1005
1006
1007
1008
1009
1010
1011
1012
1013
1014
1015
1016
1017
1018
1019
1020
1021
1022
1023
1024
1025
1026
1027
1028
1029
1030
1031
1032
1033
1034
1035
1036
1037
1038
1039
1040
1041
1042
1043
1044
1045
1046
1047
1048
1049
1050
1051
1052
1053
1054
1055
1056
1057
1058
1059
1060
1061
1062
1063
1064
1065
1066
1067
1068
1069
1070
1071
1072
1073
1074
1075
1076
1077
1078
1079
1080
1081
1082
1083
1084
1085
1086
1087
1088
1089
1090
1091
1092
1093
1094
1095
1096
1097
1098
1099
1100
1101
1102
1103
1104
1105
1106
1107
1108
1109
1110
1111
1112
1113
1114
1115
1116
1117
1118
1119
1120
1121
1122
1123
1124
1125
1126
1127
1128
1129
1130
1131
1132
1133
1134
1135
1136
1137
1138
1139
1140
1141
1142
1143
1144
1145
1146
1147
1148
1149
1150
1151
1152
1153
1154
1155
1156
1157
1158
1159
1160
1161
1162
1163
1164
1165
1166
1167
1168
1169
1170
1171
1172
1173
1174
1175
1176
1177
1178
1179
1180
1181
1182
1183
1184
1185
1186
1187
1188
1189
1190
1191
1192
1193
1194
1195
1196
1197
1198
1199
1200
1201
1202
1203
1204
1205
1206
1207
1208
1209
1210
1211
1212
1213
1214
1215
1216
1217
1218
1219
1220
1221
1222
1223
1224
1225
1226
1227
1228
1229
1230
1231
1232
1233
1234
1235
1236
1237
1238
1239
1240
1241
1242
1243
1244
1245
1246
1247
1248
1249
1250
1251
1252
1253
1254
1255
1256
1257
1258
1259
1260
1261
1262
1263
1264
1265
1266
1267
1268
1269
1270
1271
1272
1273
1274
1275
1276
1277
1278
1279
1280
1281
1282
1283
1284
1285
1286
1287
1288
1289
1290
1291
1292
1293
1294
1295
1296
1297
1298
1299
1300
1301
1302
1303
1304
1305
1306
1307
1308
1309
1310
1311
1312
1313
1314
1315
1316
1317
1318
1319
1320
1321
1322
1323
1324
1325
1326
1327
1328
1329
1330
1331
1332
1333
1334
1335
1336
1337
1338
1339
1340
1341
1342
1343
1344
1345
1346
1347
1348
1349
1350
1351
1352
1353
1354
1355
1356
1357
1358
1359
1360
1361
1362
1363
1364
1365
1366
1367
1368
1369
1370
1371
1372
1373
1374
1375
1376
1377
1378
1379
1380
1381
1382
1383
1384
1385
1386
1387
1388
1389
1390
1391
1392
1393
1394
1395
1396
1397
1398
1399
1400
--
-- RULES
-- From Jan's original setup_ruletest.sql and run_ruletest.sql
-- - thomas 1998-09-13
--

--
-- Tables and rules for the view test
--
create table rtest_t1 (a int4, b int4);
create table rtest_t2 (a int4, b int4);
create table rtest_t3 (a int4, b int4);

create view rtest_v1 as select * from rtest_t1;
create rule rtest_v1_ins as on insert to rtest_v1 do instead
	insert into rtest_t1 values (new.a, new.b);
create rule rtest_v1_upd as on update to rtest_v1 do instead
	update rtest_t1 set a = new.a, b = new.b
	where a = old.a;
create rule rtest_v1_del as on delete to rtest_v1 do instead
	delete from rtest_t1 where a = old.a;
-- Test comments
COMMENT ON RULE rtest_v1_bad ON rtest_v1 IS 'bad rule';
COMMENT ON RULE rtest_v1_del ON rtest_v1 IS 'delete rule';
COMMENT ON RULE rtest_v1_del ON rtest_v1 IS NULL;
--
-- Tables and rules for the constraint update/delete test
--
-- Note:
-- 	Now that we have multiple action rule support, we check
-- 	both possible syntaxes to define them (The last action
--  can but must not have a semicolon at the end).
--
create table rtest_system (sysname text, sysdesc text);
create table rtest_interface (sysname text, ifname text);
create table rtest_person (pname text, pdesc text);
create table rtest_admin (pname text, sysname text);

create rule rtest_sys_upd as on update to rtest_system do also (
	update rtest_interface set sysname = new.sysname
		where sysname = old.sysname;
	update rtest_admin set sysname = new.sysname
		where sysname = old.sysname
	);

create rule rtest_sys_del as on delete to rtest_system do also (
	delete from rtest_interface where sysname = old.sysname;
	delete from rtest_admin where sysname = old.sysname;
	);

create rule rtest_pers_upd as on update to rtest_person do also
	update rtest_admin set pname = new.pname where pname = old.pname;

create rule rtest_pers_del as on delete to rtest_person do also
	delete from rtest_admin where pname = old.pname;

--
-- Tables and rules for the logging test
--
create table rtest_emp (ename char(20), salary money);
create table rtest_emplog (ename char(20), who name, action char(10), newsal money, oldsal money);
create table rtest_empmass (ename char(20), salary money);

create rule rtest_emp_ins as on insert to rtest_emp do
	insert into rtest_emplog values (new.ename, current_user,
			'hired', new.salary, '0.00');

create rule rtest_emp_upd as on update to rtest_emp where new.salary != old.salary do
	insert into rtest_emplog values (new.ename, current_user,
			'honored', new.salary, old.salary);

create rule rtest_emp_del as on delete to rtest_emp do
	insert into rtest_emplog values (old.ename, current_user,
			'fired', '0.00', old.salary);

--
-- Tables and rules for the multiple cascaded qualified instead
-- rule test
--
create table rtest_t4 (a int4, b text);
create table rtest_t5 (a int4, b text);
create table rtest_t6 (a int4, b text);
create table rtest_t7 (a int4, b text);
create table rtest_t8 (a int4, b text);
create table rtest_t9 (a int4, b text);

create rule rtest_t4_ins1 as on insert to rtest_t4
		where new.a >= 10 and new.a < 20 do instead
	insert into rtest_t5 values (new.a, new.b);

create rule rtest_t4_ins2 as on insert to rtest_t4
		where new.a >= 20 and new.a < 30 do
	insert into rtest_t6 values (new.a, new.b);

create rule rtest_t5_ins as on insert to rtest_t5
		where new.a > 15 do
	insert into rtest_t7 values (new.a, new.b);

create rule rtest_t6_ins as on insert to rtest_t6
		where new.a > 25 do instead
	insert into rtest_t8 values (new.a, new.b);

--
-- Tables and rules for the rule fire order test
--
-- As of PG 7.3, the rules should fire in order by name, regardless
-- of INSTEAD attributes or creation order.
--
create table rtest_order1 (a int4);
create table rtest_order2 (a int4, b int4, c text);

create sequence rtest_seq;

create rule rtest_order_r3 as on insert to rtest_order1 do instead
	insert into rtest_order2 values (new.a, nextval('rtest_seq'),
		'rule 3 - this should run 3rd');

create rule rtest_order_r4 as on insert to rtest_order1
		where a < 100 do instead
	insert into rtest_order2 values (new.a, nextval('rtest_seq'),
		'rule 4 - this should run 4th');

create rule rtest_order_r2 as on insert to rtest_order1 do
	insert into rtest_order2 values (new.a, nextval('rtest_seq'),
		'rule 2 - this should run 2nd');

create rule rtest_order_r1 as on insert to rtest_order1 do instead
	insert into rtest_order2 values (new.a, nextval('rtest_seq'),
		'rule 1 - this should run 1st');

--
-- Tables and rules for the instead nothing test
--
create table rtest_nothn1 (a int4, b text);
create table rtest_nothn2 (a int4, b text);
create table rtest_nothn3 (a int4, b text);
create table rtest_nothn4 (a int4, b text);

create rule rtest_nothn_r1 as on insert to rtest_nothn1
	where new.a >= 10 and new.a < 20 do instead nothing;

create rule rtest_nothn_r2 as on insert to rtest_nothn1
	where new.a >= 30 and new.a < 40 do instead nothing;

create rule rtest_nothn_r3 as on insert to rtest_nothn2
	where new.a >= 100 do instead
	insert into rtest_nothn3 values (new.a, new.b);

create rule rtest_nothn_r4 as on insert to rtest_nothn2
	do instead nothing;

--
-- Tests on a view that is select * of a table
-- and has insert/update/delete instead rules to
-- behave close like the real table.
--

--
-- We need test date later
--
insert into rtest_t2 values (1, 21);
insert into rtest_t2 values (2, 22);
insert into rtest_t2 values (3, 23);

insert into rtest_t3 values (1, 31);
insert into rtest_t3 values (2, 32);
insert into rtest_t3 values (3, 33);
insert into rtest_t3 values (4, 34);
insert into rtest_t3 values (5, 35);

-- insert values
insert into rtest_v1 values (1, 11);
insert into rtest_v1 values (2, 12);
select * from rtest_v1;

-- delete with constant expression
delete from rtest_v1 where a = 1;
select * from rtest_v1;
insert into rtest_v1 values (1, 11);
delete from rtest_v1 where b = 12;
select * from rtest_v1;
insert into rtest_v1 values (2, 12);
insert into rtest_v1 values (2, 13);
select * from rtest_v1;
** Remember the delete rule on rtest_v1: It says
** DO INSTEAD DELETE FROM rtest_t1 WHERE a = old.a
** So this time both rows with a = 2 must get deleted
\p
\r
delete from rtest_v1 where b = 12;
select * from rtest_v1;
delete from rtest_v1;

-- insert select
insert into rtest_v1 select * from rtest_t2;
select * from rtest_v1;
delete from rtest_v1;

-- same with swapped targetlist
insert into rtest_v1 (b, a) select b, a from rtest_t2;
select * from rtest_v1;

-- now with only one target attribute
insert into rtest_v1 (a) select a from rtest_t3;
select * from rtest_v1;
select * from rtest_v1 where b isnull;

-- let attribute a differ (must be done on rtest_t1 - see above)
update rtest_t1 set a = a + 10 where b isnull;
delete from rtest_v1 where b isnull;
select * from rtest_v1;

-- now updates with constant expression
update rtest_v1 set b = 42 where a = 2;
select * from rtest_v1;
update rtest_v1 set b = 99 where b = 42;
select * from rtest_v1;
update rtest_v1 set b = 88 where b < 50;
select * from rtest_v1;
delete from rtest_v1;
insert into rtest_v1 select rtest_t2.a, rtest_t3.b
    from rtest_t2, rtest_t3
    where rtest_t2.a = rtest_t3.a;
select * from rtest_v1;

-- updates in a mergejoin
update rtest_v1 set b = rtest_t2.b from rtest_t2 where rtest_v1.a = rtest_t2.a;
select * from rtest_v1;
insert into rtest_v1 select * from rtest_t3;
select * from rtest_v1;
update rtest_t1 set a = a + 10 where b > 30;
select * from rtest_v1;
update rtest_v1 set a = rtest_t3.a + 20 from rtest_t3 where rtest_v1.b = rtest_t3.b;
select * from rtest_v1;

--
-- Test for constraint updates/deletes
--
insert into rtest_system values ('orion', 'Linux Jan Wieck');
insert into rtest_system values ('notjw', 'WinNT Jan Wieck (notebook)');
insert into rtest_system values ('neptun', 'Fileserver');

insert into rtest_interface values ('orion', 'eth0');
insert into rtest_interface values ('orion', 'eth1');
insert into rtest_interface values ('notjw', 'eth0');
insert into rtest_interface values ('neptun', 'eth0');

insert into rtest_person values ('jw', 'Jan Wieck');
insert into rtest_person values ('bm', 'Bruce Momjian');

insert into rtest_admin values ('jw', 'orion');
insert into rtest_admin values ('jw', 'notjw');
insert into rtest_admin values ('bm', 'neptun');

update rtest_system set sysname = 'pluto' where sysname = 'neptun';

select * from rtest_interface;
select * from rtest_admin;

update rtest_person set pname = 'jwieck' where pdesc = 'Jan Wieck';

-- Note: use ORDER BY here to ensure consistent output across all systems.
-- The above UPDATE affects two rows with equal keys, so they could be
-- updated in either order depending on the whim of the local qsort().

select * from rtest_admin order by pname, sysname;

delete from rtest_system where sysname = 'orion';

select * from rtest_interface;
select * from rtest_admin;

--
-- Rule qualification test
--
insert into rtest_emp values ('wiecc', '5000.00');
insert into rtest_emp values ('gates', '80000.00');
update rtest_emp set ename = 'wiecx' where ename = 'wiecc';
update rtest_emp set ename = 'wieck', salary = '6000.00' where ename = 'wiecx';
update rtest_emp set salary = '7000.00' where ename = 'wieck';
delete from rtest_emp where ename = 'gates';

select ename, who = current_user as "matches user", action, newsal, oldsal from rtest_emplog order by ename, action, newsal;
insert into rtest_empmass values ('meyer', '4000.00');
insert into rtest_empmass values ('maier', '5000.00');
insert into rtest_empmass values ('mayr', '6000.00');
insert into rtest_emp select * from rtest_empmass;
select ename, who = current_user as "matches user", action, newsal, oldsal from rtest_emplog order by ename, action, newsal;
update rtest_empmass set salary = salary + '1000.00';
update rtest_emp set salary = rtest_empmass.salary from rtest_empmass where rtest_emp.ename = rtest_empmass.ename;
select ename, who = current_user as "matches user", action, newsal, oldsal from rtest_emplog order by ename, action, newsal;
delete from rtest_emp using rtest_empmass where rtest_emp.ename = rtest_empmass.ename;
select ename, who = current_user as "matches user", action, newsal, oldsal from rtest_emplog order by ename, action, newsal;

--
-- Multiple cascaded qualified instead rule test
--
insert into rtest_t4 values (1, 'Record should go to rtest_t4');
insert into rtest_t4 values (2, 'Record should go to rtest_t4');
insert into rtest_t4 values (10, 'Record should go to rtest_t5');
insert into rtest_t4 values (15, 'Record should go to rtest_t5');
insert into rtest_t4 values (19, 'Record should go to rtest_t5 and t7');
insert into rtest_t4 values (20, 'Record should go to rtest_t4 and t6');
insert into rtest_t4 values (26, 'Record should go to rtest_t4 and t8');
insert into rtest_t4 values (28, 'Record should go to rtest_t4 and t8');
insert into rtest_t4 values (30, 'Record should go to rtest_t4');
insert into rtest_t4 values (40, 'Record should go to rtest_t4');

select * from rtest_t4;
select * from rtest_t5;
select * from rtest_t6;
select * from rtest_t7;
select * from rtest_t8;

delete from rtest_t4;
delete from rtest_t5;
delete from rtest_t6;
delete from rtest_t7;
delete from rtest_t8;

insert into rtest_t9 values (1, 'Record should go to rtest_t4');
insert into rtest_t9 values (2, 'Record should go to rtest_t4');
insert into rtest_t9 values (10, 'Record should go to rtest_t5');
insert into rtest_t9 values (15, 'Record should go to rtest_t5');
insert into rtest_t9 values (19, 'Record should go to rtest_t5 and t7');
insert into rtest_t9 values (20, 'Record should go to rtest_t4 and t6');
insert into rtest_t9 values (26, 'Record should go to rtest_t4 and t8');
insert into rtest_t9 values (28, 'Record should go to rtest_t4 and t8');
insert into rtest_t9 values (30, 'Record should go to rtest_t4');
insert into rtest_t9 values (40, 'Record should go to rtest_t4');

insert into rtest_t4 select * from rtest_t9 where a < 20;

select * from rtest_t4;
select * from rtest_t5;
select * from rtest_t6;
select * from rtest_t7;
select * from rtest_t8;

insert into rtest_t4 select * from rtest_t9 where b ~ 'and t8';

select * from rtest_t4;
select * from rtest_t5;
select * from rtest_t6;
select * from rtest_t7;
select * from rtest_t8;

insert into rtest_t4 select a + 1, b from rtest_t9 where a in (20, 30, 40);

select * from rtest_t4;
select * from rtest_t5;
select * from rtest_t6;
select * from rtest_t7;
select * from rtest_t8;

--
-- Check that the ordering of rules fired is correct
--
insert into rtest_order1 values (1);
select * from rtest_order2;

--
-- Check if instead nothing w/without qualification works
--
insert into rtest_nothn1 values (1, 'want this');
insert into rtest_nothn1 values (2, 'want this');
insert into rtest_nothn1 values (10, 'don''t want this');
insert into rtest_nothn1 values (19, 'don''t want this');
insert into rtest_nothn1 values (20, 'want this');
insert into rtest_nothn1 values (29, 'want this');
insert into rtest_nothn1 values (30, 'don''t want this');
insert into rtest_nothn1 values (39, 'don''t want this');
insert into rtest_nothn1 values (40, 'want this');
insert into rtest_nothn1 values (50, 'want this');
insert into rtest_nothn1 values (60, 'want this');

select * from rtest_nothn1;

insert into rtest_nothn2 values (10, 'too small');
insert into rtest_nothn2 values (50, 'too small');
insert into rtest_nothn2 values (100, 'OK');
insert into rtest_nothn2 values (200, 'OK');

select * from rtest_nothn2;
select * from rtest_nothn3;

delete from rtest_nothn1;
delete from rtest_nothn2;
delete from rtest_nothn3;

insert into rtest_nothn4 values (1, 'want this');
insert into rtest_nothn4 values (2, 'want this');
insert into rtest_nothn4 values (10, 'don''t want this');
insert into rtest_nothn4 values (19, 'don''t want this');
insert into rtest_nothn4 values (20, 'want this');
insert into rtest_nothn4 values (29, 'want this');
insert into rtest_nothn4 values (30, 'don''t want this');
insert into rtest_nothn4 values (39, 'don''t want this');
insert into rtest_nothn4 values (40, 'want this');
insert into rtest_nothn4 values (50, 'want this');
insert into rtest_nothn4 values (60, 'want this');

insert into rtest_nothn1 select * from rtest_nothn4;

select * from rtest_nothn1;

delete from rtest_nothn4;

insert into rtest_nothn4 values (10, 'too small');
insert into rtest_nothn4 values (50, 'too small');
insert into rtest_nothn4 values (100, 'OK');
insert into rtest_nothn4 values (200, 'OK');

insert into rtest_nothn2 select * from rtest_nothn4;

select * from rtest_nothn2;
select * from rtest_nothn3;

create table rtest_view1 (a int4, b text, v bool);
create table rtest_view2 (a int4);
create table rtest_view3 (a int4, b text);
create table rtest_view4 (a int4, b text, c int4);
create view rtest_vview1 as select a, b from rtest_view1 X
	where 0 < (select count(*) from rtest_view2 Y where Y.a = X.a);
create view rtest_vview2 as select a, b from rtest_view1 where v;
create view rtest_vview3 as select a, b from rtest_vview2 X
	where 0 < (select count(*) from rtest_view2 Y where Y.a = X.a);
create view rtest_vview4 as select X.a, X.b, count(Y.a) as refcount
	from rtest_view1 X, rtest_view2 Y
	where X.a = Y.a
	group by X.a, X.b;
create function rtest_viewfunc1(int4) returns int4 as
	'select count(*)::int4 from rtest_view2 where a = $1'
	language sql;
create view rtest_vview5 as select a, b, rtest_viewfunc1(a) as refcount
	from rtest_view1;

insert into rtest_view1 values (1, 'item 1', 't');
insert into rtest_view1 values (2, 'item 2', 't');
insert into rtest_view1 values (3, 'item 3', 't');
insert into rtest_view1 values (4, 'item 4', 'f');
insert into rtest_view1 values (5, 'item 5', 't');
insert into rtest_view1 values (6, 'item 6', 'f');
insert into rtest_view1 values (7, 'item 7', 't');
insert into rtest_view1 values (8, 'item 8', 't');

insert into rtest_view2 values (2);
insert into rtest_view2 values (2);
insert into rtest_view2 values (4);
insert into rtest_view2 values (5);
insert into rtest_view2 values (7);
insert into rtest_view2 values (7);
insert into rtest_view2 values (7);
insert into rtest_view2 values (7);

select * from rtest_vview1;
select * from rtest_vview2;
select * from rtest_vview3;
select * from rtest_vview4 order by a, b;
select * from rtest_vview5;

insert into rtest_view3 select * from rtest_vview1 where a < 7;
select * from rtest_view3;
delete from rtest_view3;

insert into rtest_view3 select * from rtest_vview2 where a != 5 and b !~ '2';
select * from rtest_view3;
delete from rtest_view3;

insert into rtest_view3 select * from rtest_vview3;
select * from rtest_view3;
delete from rtest_view3;

insert into rtest_view4 select * from rtest_vview4 where 3 > refcount;
select * from rtest_view4 order by a, b;
delete from rtest_view4;

insert into rtest_view4 select * from rtest_vview5 where a > 2 and refcount = 0;
select * from rtest_view4;
delete from rtest_view4;
--
-- Test for computations in views
--
create table rtest_comp (
	part	text,
	unit	char(4),
	size	float
);


create table rtest_unitfact (
	unit	char(4),
	factor	float
);

create view rtest_vcomp as
	select X.part, (X.size * Y.factor) as size_in_cm
			from rtest_comp X, rtest_unitfact Y
			where X.unit = Y.unit;


insert into rtest_unitfact values ('m', 100.0);
insert into rtest_unitfact values ('cm', 1.0);
insert into rtest_unitfact values ('inch', 2.54);

insert into rtest_comp values ('p1', 'm', 5.0);
insert into rtest_comp values ('p2', 'm', 3.0);
insert into rtest_comp values ('p3', 'cm', 5.0);
insert into rtest_comp values ('p4', 'cm', 15.0);
insert into rtest_comp values ('p5', 'inch', 7.0);
insert into rtest_comp values ('p6', 'inch', 4.4);

select * from rtest_vcomp order by part;

select * from rtest_vcomp where size_in_cm > 10.0 order by size_in_cm using >;

--
-- In addition run the (slightly modified) queries from the
-- programmers manual section on the rule system.
--
CREATE TABLE shoe_data (
	shoename   char(10),      -- primary key
	sh_avail   integer,       -- available # of pairs
	slcolor    char(10),      -- preferred shoelace color
	slminlen   float,         -- minimum shoelace length
	slmaxlen   float,         -- maximum shoelace length
	slunit     char(8)        -- length unit
);

CREATE TABLE shoelace_data (
	sl_name    char(10),      -- primary key
	sl_avail   integer,       -- available # of pairs
	sl_color   char(10),      -- shoelace color
	sl_len     float,         -- shoelace length
	sl_unit    char(8)        -- length unit
);

CREATE TABLE unit (
	un_name    char(8),       -- the primary key
	un_fact    float          -- factor to transform to cm
);

CREATE VIEW shoe AS
	SELECT sh.shoename,
		   sh.sh_avail,
		   sh.slcolor,
		   sh.slminlen,
		   sh.slminlen * un.un_fact AS slminlen_cm,
		   sh.slmaxlen,
		   sh.slmaxlen * un.un_fact AS slmaxlen_cm,
		   sh.slunit
	  FROM shoe_data sh, unit un
	 WHERE sh.slunit = un.un_name;

CREATE VIEW shoelace AS
	SELECT s.sl_name,
		   s.sl_avail,
		   s.sl_color,
		   s.sl_len,
		   s.sl_unit,
		   s.sl_len * u.un_fact AS sl_len_cm
	  FROM shoelace_data s, unit u
	 WHERE s.sl_unit = u.un_name;

CREATE VIEW shoe_ready AS
	SELECT rsh.shoename,
		   rsh.sh_avail,
		   rsl.sl_name,
		   rsl.sl_avail,
		   int4smaller(rsh.sh_avail, rsl.sl_avail) AS total_avail
	  FROM shoe rsh, shoelace rsl
	 WHERE rsl.sl_color = rsh.slcolor
	   AND rsl.sl_len_cm >= rsh.slminlen_cm
	   AND rsl.sl_len_cm <= rsh.slmaxlen_cm;

INSERT INTO unit VALUES ('cm', 1.0);
INSERT INTO unit VALUES ('m', 100.0);
INSERT INTO unit VALUES ('inch', 2.54);

INSERT INTO shoe_data VALUES ('sh1', 2, 'black', 70.0, 90.0, 'cm');
INSERT INTO shoe_data VALUES ('sh2', 0, 'black', 30.0, 40.0, 'inch');
INSERT INTO shoe_data VALUES ('sh3', 4, 'brown', 50.0, 65.0, 'cm');
INSERT INTO shoe_data VALUES ('sh4', 3, 'brown', 40.0, 50.0, 'inch');

INSERT INTO shoelace_data VALUES ('sl1', 5, 'black', 80.0, 'cm');
INSERT INTO shoelace_data VALUES ('sl2', 6, 'black', 100.0, 'cm');
INSERT INTO shoelace_data VALUES ('sl3', 0, 'black', 35.0 , 'inch');
INSERT INTO shoelace_data VALUES ('sl4', 8, 'black', 40.0 , 'inch');
INSERT INTO shoelace_data VALUES ('sl5', 4, 'brown', 1.0 , 'm');
INSERT INTO shoelace_data VALUES ('sl6', 0, 'brown', 0.9 , 'm');
INSERT INTO shoelace_data VALUES ('sl7', 7, 'brown', 60 , 'cm');
INSERT INTO shoelace_data VALUES ('sl8', 1, 'brown', 40 , 'inch');

-- SELECTs in doc
SELECT * FROM shoelace ORDER BY sl_name;
SELECT * FROM shoe_ready WHERE total_avail >= 2 ORDER BY 1;

    CREATE TABLE shoelace_log (
        sl_name    char(10),      -- shoelace changed
        sl_avail   integer,       -- new available value
        log_who    name,          -- who did it
        log_when   timestamp      -- when
    );

-- Want "log_who" to be CURRENT_USER,
-- but that is non-portable for the regression test
-- - thomas 1999-02-21

    CREATE RULE log_shoelace AS ON UPDATE TO shoelace_data
        WHERE NEW.sl_avail != OLD.sl_avail
        DO INSERT INTO shoelace_log VALUES (
                                        NEW.sl_name,
                                        NEW.sl_avail,
                                        'Al Bundy',
                                        'epoch'
                                    );

UPDATE shoelace_data SET sl_avail = 6 WHERE  sl_name = 'sl7';

SELECT * FROM shoelace_log;

    CREATE RULE shoelace_ins AS ON INSERT TO shoelace
        DO INSTEAD
        INSERT INTO shoelace_data VALUES (
               NEW.sl_name,
               NEW.sl_avail,
               NEW.sl_color,
               NEW.sl_len,
               NEW.sl_unit);

    CREATE RULE shoelace_upd AS ON UPDATE TO shoelace
        DO INSTEAD
        UPDATE shoelace_data SET
               sl_name = NEW.sl_name,
               sl_avail = NEW.sl_avail,
               sl_color = NEW.sl_color,
               sl_len = NEW.sl_len,
               sl_unit = NEW.sl_unit
         WHERE sl_name = OLD.sl_name;

    CREATE RULE shoelace_del AS ON DELETE TO shoelace
        DO INSTEAD
        DELETE FROM shoelace_data
         WHERE sl_name = OLD.sl_name;

    CREATE TABLE shoelace_arrive (
        arr_name    char(10),
        arr_quant   integer
    );

    CREATE TABLE shoelace_ok (
        ok_name     char(10),
        ok_quant    integer
    );

    CREATE RULE shoelace_ok_ins AS ON INSERT TO shoelace_ok
        DO INSTEAD
        UPDATE shoelace SET
               sl_avail = sl_avail + NEW.ok_quant
         WHERE sl_name = NEW.ok_name;

INSERT INTO shoelace_arrive VALUES ('sl3', 10);
INSERT INTO shoelace_arrive VALUES ('sl6', 20);
INSERT INTO shoelace_arrive VALUES ('sl8', 20);

SELECT * FROM shoelace ORDER BY sl_name;

insert into shoelace_ok select * from shoelace_arrive;

SELECT * FROM shoelace ORDER BY sl_name;

SELECT * FROM shoelace_log ORDER BY sl_name;

    CREATE VIEW shoelace_obsolete AS
	SELECT * FROM shoelace WHERE NOT EXISTS
	    (SELECT shoename FROM shoe WHERE slcolor = sl_color);

    CREATE VIEW shoelace_candelete AS
	SELECT * FROM shoelace_obsolete WHERE sl_avail = 0;

insert into shoelace values ('sl9', 0, 'pink', 35.0, 'inch', 0.0);
insert into shoelace values ('sl10', 1000, 'magenta', 40.0, 'inch', 0.0);
-- Unsupported (even though a similar updatable view construct is)
insert into shoelace values ('sl10', 1000, 'magenta', 40.0, 'inch', 0.0)
  on conflict do nothing;

SELECT * FROM shoelace_obsolete ORDER BY sl_len_cm;
SELECT * FROM shoelace_candelete;

DELETE FROM shoelace WHERE EXISTS
    (SELECT * FROM shoelace_candelete
             WHERE sl_name = shoelace.sl_name);

SELECT * FROM shoelace ORDER BY sl_name;

SELECT * FROM shoe ORDER BY shoename;
SELECT count(*) FROM shoe;


--
-- Simple test of qualified ON INSERT ... this did not work in 7.0 ...
--
create table rules_foo (f1 int);
create table rules_foo2 (f1 int);

create rule rules_foorule as on insert to rules_foo where f1 < 100
do instead nothing;

insert into rules_foo values(1);
insert into rules_foo values(1001);
select * from rules_foo;

drop rule rules_foorule on rules_foo;

-- this should fail because f1 is not exposed for unqualified reference:
create rule rules_foorule as on insert to rules_foo where f1 < 100
do instead insert into rules_foo2 values (f1);
-- this is the correct way:
create rule rules_foorule as on insert to rules_foo where f1 < 100
do instead insert into rules_foo2 values (new.f1);

insert into rules_foo values(2);
insert into rules_foo values(100);

select * from rules_foo;
select * from rules_foo2;

drop rule rules_foorule on rules_foo;
drop table rules_foo;
drop table rules_foo2;


--
-- Test rules containing INSERT ... SELECT, which is a very ugly special
-- case as of 7.1.  Example is based on bug report from Joel Burton.
--
create table pparent (pid int, txt text);
insert into pparent values (1,'parent1');
insert into pparent values (2,'parent2');

create table cchild (pid int, descrip text);
insert into cchild values (1,'descrip1');

create view vview as
  select pparent.pid, txt, descrip from
    pparent left join cchild using (pid);

create rule rrule as
  on update to vview do instead
(
  insert into cchild (pid, descrip)
    select old.pid, new.descrip where old.descrip isnull;
  update cchild set descrip = new.descrip where cchild.pid = old.pid;
);

select * from vview;
update vview set descrip='test1' where pid=1;
select * from vview;
update vview set descrip='test2' where pid=2;
select * from vview;
update vview set descrip='test3' where pid=3;
select * from vview;
select * from cchild;

drop rule rrule on vview;
drop view vview;
drop table pparent;
drop table cchild;


--
-- Check that ruleutils are working
--

-- temporarily disable fancy output, so view changes create less diff noise
\a\t

SELECT viewname, definition FROM pg_views
WHERE schemaname = 'pg_catalog'
ORDER BY viewname;

SELECT tablename, rulename, definition FROM pg_rules
WHERE schemaname = 'pg_catalog'
ORDER BY tablename, rulename;

-- restore normal output mode
\a\t

--
-- CREATE OR REPLACE RULE
--

CREATE TABLE ruletest_tbl (a int, b int);
CREATE TABLE ruletest_tbl2 (a int, b int);

CREATE OR REPLACE RULE myrule AS ON INSERT TO ruletest_tbl
	DO INSTEAD INSERT INTO ruletest_tbl2 VALUES (10, 10);

INSERT INTO ruletest_tbl VALUES (99, 99);

CREATE OR REPLACE RULE myrule AS ON INSERT TO ruletest_tbl
	DO INSTEAD INSERT INTO ruletest_tbl2 VALUES (1000, 1000);

INSERT INTO ruletest_tbl VALUES (99, 99);

SELECT * FROM ruletest_tbl2;

-- Check that rewrite rules splitting one INSERT into multiple
-- conditional statements does not disable FK checking.
create table rule_and_refint_t1 (
	id1a integer,
	id1b integer,

	primary key (id1a, id1b)
);

create table rule_and_refint_t2 (
	id2a integer,
	id2c integer,

	primary key (id2a, id2c)
);

create table rule_and_refint_t3 (
	id3a integer,
	id3b integer,
	id3c integer,
	data text,

	primary key (id3a, id3b, id3c),

	foreign key (id3a, id3b) references rule_and_refint_t1 (id1a, id1b),
	foreign key (id3a, id3c) references rule_and_refint_t2 (id2a, id2c)
);


insert into rule_and_refint_t1 values (1, 11);
insert into rule_and_refint_t1 values (1, 12);
insert into rule_and_refint_t1 values (2, 21);
insert into rule_and_refint_t1 values (2, 22);

insert into rule_and_refint_t2 values (1, 11);
insert into rule_and_refint_t2 values (1, 12);
insert into rule_and_refint_t2 values (2, 21);
insert into rule_and_refint_t2 values (2, 22);

insert into rule_and_refint_t3 values (1, 11, 11, 'row1');
insert into rule_and_refint_t3 values (1, 11, 12, 'row2');
insert into rule_and_refint_t3 values (1, 12, 11, 'row3');
insert into rule_and_refint_t3 values (1, 12, 12, 'row4');
insert into rule_and_refint_t3 values (1, 11, 13, 'row5');
insert into rule_and_refint_t3 values (1, 13, 11, 'row6');
-- Ordinary table
insert into rule_and_refint_t3 values (1, 13, 11, 'row6')
  on conflict do nothing;
-- rule not fired, so fk violation
insert into rule_and_refint_t3 values (1, 13, 11, 'row6')
  on conflict (id3a, id3b, id3c) do update
  set id3b = excluded.id3b;
-- rule fired, so unsupported
insert into shoelace values ('sl9', 0, 'pink', 35.0, 'inch', 0.0)
  on conflict (sl_name) do update
  set sl_avail = excluded.sl_avail;

create rule rule_and_refint_t3_ins as on insert to rule_and_refint_t3
	where (exists (select 1 from rule_and_refint_t3
			where (((rule_and_refint_t3.id3a = new.id3a)
			and (rule_and_refint_t3.id3b = new.id3b))
			and (rule_and_refint_t3.id3c = new.id3c))))
	do instead update rule_and_refint_t3 set data = new.data
	where (((rule_and_refint_t3.id3a = new.id3a)
	and (rule_and_refint_t3.id3b = new.id3b))
	and (rule_and_refint_t3.id3c = new.id3c));

insert into rule_and_refint_t3 values (1, 11, 13, 'row7');
insert into rule_and_refint_t3 values (1, 13, 11, 'row8');

--
-- disallow dropping a view's rule (bug #5072)
--

create view rules_fooview as select 'rules_foo'::text;
drop rule "_RETURN" on rules_fooview;
drop view rules_fooview;

--
-- test conversion of table to view (needed to load some pg_dump files)
--

create table rules_fooview (x int, y text);
select xmin, * from rules_fooview;

create rule "_RETURN" as on select to rules_fooview do instead
  select 1 as x, 'aaa'::text as y;

select * from rules_fooview;
select xmin, * from rules_fooview;  -- fail, views don't have such a column

select reltoastrelid, relkind, relfrozenxid
  from pg_class where oid = 'rules_fooview'::regclass;

drop view rules_fooview;

-- cannot convert an inheritance parent or child to a view, though
create table rules_fooview (x int, y text);
create table rules_fooview_child () inherits (rules_fooview);

create rule "_RETURN" as on select to rules_fooview do instead
  select 1 as x, 'aaa'::text as y;
create rule "_RETURN" as on select to rules_fooview_child do instead
  select 1 as x, 'aaa'::text as y;

drop table rules_fooview cascade;

-- likewise, converting a partitioned table or partition to view is not allowed
create table rules_fooview (x int, y text) partition by list (x);
create rule "_RETURN" as on select to rules_fooview do instead
  select 1 as x, 'aaa'::text as y;

create table rules_fooview_part partition of rules_fooview for values in (1);
create rule "_RETURN" as on select to rules_fooview_part do instead
  select 1 as x, 'aaa'::text as y;

drop table rules_fooview;

--
-- check for planner problems with complex inherited UPDATES
--

create table id (id serial primary key, name text);
-- currently, must respecify PKEY for each inherited subtable
create table test_1 (id integer primary key) inherits (id);
create table test_2 (id integer primary key) inherits (id);
create table test_3 (id integer primary key) inherits (id);

insert into test_1 (name) values ('Test 1');
insert into test_1 (name) values ('Test 2');
insert into test_2 (name) values ('Test 3');
insert into test_2 (name) values ('Test 4');
insert into test_3 (name) values ('Test 5');
insert into test_3 (name) values ('Test 6');

create view id_ordered as select * from id order by id;

create rule update_id_ordered as on update to id_ordered
	do instead update id set name = new.name where id = old.id;

select * from id_ordered;
update id_ordered set name = 'update 2' where id = 2;
update id_ordered set name = 'update 4' where id = 4;
update id_ordered set name = 'update 5' where id = 5;
select * from id_ordered;

drop table id cascade;

--
-- check corner case where an entirely-dummy subplan is created by
-- constraint exclusion
--

create temp table t1 (a integer primary key);

create temp table t1_1 (check (a >= 0 and a < 10)) inherits (t1);
create temp table t1_2 (check (a >= 10 and a < 20)) inherits (t1);

create rule t1_ins_1 as on insert to t1
	where new.a >= 0 and new.a < 10
	do instead
	insert into t1_1 values (new.a);
create rule t1_ins_2 as on insert to t1
	where new.a >= 10 and new.a < 20
	do instead
	insert into t1_2 values (new.a);

create rule t1_upd_1 as on update to t1
	where old.a >= 0 and old.a < 10
	do instead
	update t1_1 set a = new.a where a = old.a;
create rule t1_upd_2 as on update to t1
	where old.a >= 10 and old.a < 20
	do instead
	update t1_2 set a = new.a where a = old.a;

set constraint_exclusion = on;

insert into t1 select * from generate_series(5,19,1) g;
update t1 set a = 4 where a = 5;

select * from only t1;
select * from only t1_1;
select * from only t1_2;

reset constraint_exclusion;

-- test FOR UPDATE in rules

create table rules_base(f1 int, f2 int);
insert into rules_base values(1,2), (11,12);
create rule r1 as on update to rules_base do instead
  select * from rules_base where f1 = 1 for update;
update rules_base set f2 = f2 + 1;
create or replace rule r1 as on update to rules_base do instead
  select * from rules_base where f1 = 11 for update of rules_base;
update rules_base set f2 = f2 + 1;
create or replace rule r1 as on update to rules_base do instead
  select * from rules_base where f1 = 11 for update of old; -- error
drop table rules_base;

-- test various flavors of pg_get_viewdef()

select pg_get_viewdef('shoe'::regclass) as unpretty;
select pg_get_viewdef('shoe'::regclass,true) as pretty;
select pg_get_viewdef('shoe'::regclass,0) as prettier;

--
-- check multi-row VALUES in rules
--

create table rules_src(f1 int, f2 int default 0);
create table rules_log(f1 int, f2 int, tag text, id serial);
insert into rules_src values(1,2), (11,12);
create rule r1 as on update to rules_src do also
  insert into rules_log values(old.*, 'old', default), (new.*, 'new', default);
update rules_src set f2 = f2 + 1;
update rules_src set f2 = f2 * 10;
select * from rules_src;
select * from rules_log;
create rule r2 as on update to rules_src do also
  values(old.*, 'old'), (new.*, 'new');
update rules_src set f2 = f2 / 10;
create rule r3 as on insert to rules_src do also
  insert into rules_log values(null, null, '-', default), (new.*, 'new', default);
insert into rules_src values(22,23), (33,default);
select * from rules_src;
select * from rules_log;
create rule r4 as on delete to rules_src do notify rules_src_deletion;

--
-- Ensure an aliased target relation for insert is correctly deparsed.
--
create rule r5 as on insert to rules_src do instead insert into rules_log AS trgt SELECT NEW.* RETURNING trgt.f1, trgt.f2;
create rule r6 as on update to rules_src do instead UPDATE rules_log AS trgt SET tag = 'updated' WHERE trgt.f1 = new.f1;

--
-- Check deparse disambiguation of INSERT/UPDATE/DELETE targets.
--
create rule r7 as on delete to rules_src do instead
  with wins as (insert into int4_tbl as trgt values (0) returning *),
       wupd as (update int4_tbl trgt set f1 = f1+1 returning *),
       wdel as (delete from int4_tbl trgt where f1 = 0 returning *)
  insert into rules_log AS trgt select old.* from wins, wupd, wdel
  returning trgt.f1, trgt.f2;

-- check display of all rules added above
\d+ rules_src

--
-- Also check multiassignment deparsing.
--
create table rule_t1(f1 int, f2 int);
create table rule_dest(f1 int, f2 int[], tag text);
create rule rr as on update to rule_t1 do instead UPDATE rule_dest trgt
  SET (f2[1], f1, tag) = (SELECT new.f2, new.f1, 'updated'::varchar)
  WHERE trgt.f1 = new.f1 RETURNING new.*;
\d+ rule_t1
drop table rule_t1, rule_dest;

--
-- Test implicit LATERAL references to old/new in rules
--
CREATE TABLE rule_t1(a int, b text DEFAULT 'xxx', c int);
CREATE VIEW rule_v1 AS SELECT * FROM rule_t1;
CREATE RULE v1_ins AS ON INSERT TO rule_v1
  DO ALSO INSERT INTO rule_t1
  SELECT * FROM (SELECT a + 10 FROM rule_t1 WHERE a = NEW.a) tt;
CREATE RULE v1_upd AS ON UPDATE TO rule_v1
  DO ALSO UPDATE rule_t1 t
  SET c = tt.a * 10
  FROM (SELECT a FROM rule_t1 WHERE a = OLD.a) tt WHERE t.a = tt.a;
INSERT INTO rule_v1 VALUES (1, 'a'), (2, 'b');
UPDATE rule_v1 SET b = upper(b);
SELECT * FROM rule_t1;
DROP TABLE rule_t1 CASCADE;

--
-- check alter rename rule
--
CREATE TABLE rule_t1 (a INT);
CREATE VIEW rule_v1 AS SELECT * FROM rule_t1;

CREATE RULE InsertRule AS
    ON INSERT TO rule_v1
    DO INSTEAD
        INSERT INTO rule_t1 VALUES(new.a);

ALTER RULE InsertRule ON rule_v1 RENAME to NewInsertRule;

INSERT INTO rule_v1 VALUES(1);
SELECT * FROM rule_v1;

\d+ rule_v1

--
-- error conditions for alter rename rule
--
ALTER RULE InsertRule ON rule_v1 RENAME TO NewInsertRule; -- doesn't exist
ALTER RULE NewInsertRule ON rule_v1 RENAME TO "_RETURN"; -- already exists
ALTER RULE "_RETURN" ON rule_v1 RENAME TO abc; -- ON SELECT rule cannot be renamed

DROP VIEW rule_v1;
DROP TABLE rule_t1;

--
-- check display of VALUES in view definitions
--
create view rule_v1 as values(1,2);
\d+ rule_v1
alter table rule_v1 rename column column2 to q2;
\d+ rule_v1
drop view rule_v1;
create view rule_v1(x) as values(1,2);
\d+ rule_v1
drop view rule_v1;
create view rule_v1(x) as select * from (values(1,2)) v;
\d+ rule_v1
drop view rule_v1;
create view rule_v1(x) as select * from (values(1,2)) v(q,w);
\d+ rule_v1
drop view rule_v1;

--
-- Check DO INSTEAD rules with ON CONFLICT
--
CREATE TABLE hats (
	hat_name    char(10) primary key,
	hat_color   char(10)      -- hat color
);

CREATE TABLE hat_data (
	hat_name    char(10),
	hat_color   char(10)      -- hat color
);
create unique index hat_data_unique_idx
  on hat_data (hat_name COLLATE "C" bpchar_pattern_ops);

-- DO NOTHING with ON CONFLICT
CREATE RULE hat_nosert AS ON INSERT TO hats
    DO INSTEAD
    INSERT INTO hat_data VALUES (
           NEW.hat_name,
           NEW.hat_color)
        ON CONFLICT (hat_name COLLATE "C" bpchar_pattern_ops) WHERE hat_color = 'green'
        DO NOTHING
        RETURNING *;
SELECT definition FROM pg_rules WHERE tablename = 'hats' ORDER BY rulename;

-- Works (projects row)
INSERT INTO hats VALUES ('h7', 'black') RETURNING *;
-- Works (does nothing)
INSERT INTO hats VALUES ('h7', 'black') RETURNING *;
SELECT tablename, rulename, definition FROM pg_rules
	WHERE tablename = 'hats';
DROP RULE hat_nosert ON hats;

-- DO NOTHING without ON CONFLICT
CREATE RULE hat_nosert_all AS ON INSERT TO hats
    DO INSTEAD
    INSERT INTO hat_data VALUES (
           NEW.hat_name,
           NEW.hat_color)
        ON CONFLICT
        DO NOTHING
        RETURNING *;
SELECT definition FROM pg_rules WHERE tablename = 'hats' ORDER BY rulename;
DROP RULE hat_nosert_all ON hats;

-- Works (does nothing)
INSERT INTO hats VALUES ('h7', 'black') RETURNING *;

-- DO UPDATE with a WHERE clause
CREATE RULE hat_upsert AS ON INSERT TO hats
    DO INSTEAD
    INSERT INTO hat_data VALUES (
           NEW.hat_name,
           NEW.hat_color)
        ON CONFLICT (hat_name)
        DO UPDATE
           SET hat_name = hat_data.hat_name, hat_color = excluded.hat_color
           WHERE excluded.hat_color <>  'forbidden' AND hat_data.* != excluded.*
        RETURNING *;
SELECT definition FROM pg_rules WHERE tablename = 'hats' ORDER BY rulename;

-- Works (does upsert)
INSERT INTO hats VALUES ('h8', 'black') RETURNING *;
SELECT * FROM hat_data WHERE hat_name = 'h8';
INSERT INTO hats VALUES ('h8', 'white') RETURNING *;
SELECT * FROM hat_data WHERE hat_name = 'h8';
INSERT INTO hats VALUES ('h8', 'forbidden') RETURNING *;
SELECT * FROM hat_data WHERE hat_name = 'h8';
SELECT tablename, rulename, definition FROM pg_rules
	WHERE tablename = 'hats';
-- ensure explain works for on insert conflict rules
explain (costs off) INSERT INTO hats VALUES ('h8', 'forbidden') RETURNING *;

-- ensure upserting into a rule, with a CTE (different offsets!) works
WITH data(hat_name, hat_color) AS MATERIALIZED (
    VALUES ('h8', 'green'),
        ('h9', 'blue'),
        ('h7', 'forbidden')
)
INSERT INTO hats
    SELECT * FROM data
RETURNING *;
EXPLAIN (costs off)
WITH data(hat_name, hat_color) AS MATERIALIZED (
    VALUES ('h8', 'green'),
        ('h9', 'blue'),
        ('h7', 'forbidden')
)
INSERT INTO hats
    SELECT * FROM data
RETURNING *;
SELECT * FROM hat_data WHERE hat_name IN ('h8', 'h9', 'h7') ORDER BY hat_name;

DROP RULE hat_upsert ON hats;

drop table hats;
drop table hat_data;

-- test for pg_get_functiondef properly regurgitating SET parameters
-- Note that the function is kept around to stress pg_dump.
CREATE FUNCTION func_with_set_params() RETURNS integer
    AS 'select 1;'
    LANGUAGE SQL
    SET search_path TO PG_CATALOG
    SET extra_float_digits TO 2
    SET work_mem TO '4MB'
    SET datestyle to iso, mdy
    SET local_preload_libraries TO "Mixed/Case", 'c:/''a"/path', '', '0123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789'
    IMMUTABLE STRICT;
SELECT pg_get_functiondef('func_with_set_params()'::regprocedure);

-- tests for pg_get_*def with invalid objects
SELECT pg_get_constraintdef(0);
SELECT pg_get_functiondef(0);
SELECT pg_get_indexdef(0);
SELECT pg_get_ruledef(0);
SELECT pg_get_statisticsobjdef(0);
SELECT pg_get_triggerdef(0);
SELECT pg_get_viewdef(0);
SELECT pg_get_function_arguments(0);
SELECT pg_get_function_identity_arguments(0);
SELECT pg_get_function_result(0);
SELECT pg_get_function_arg_default(0, 0);
SELECT pg_get_function_arg_default('pg_class'::regclass, 0);
SELECT pg_get_partkeydef(0);

-- test rename for a rule defined on a partitioned table
CREATE TABLE rules_parted_table (a int) PARTITION BY LIST (a);
CREATE TABLE rules_parted_table_1 PARTITION OF rules_parted_table FOR VALUES IN (1);
CREATE RULE rules_parted_table_insert AS ON INSERT to rules_parted_table
    DO INSTEAD INSERT INTO rules_parted_table_1 VALUES (NEW.*);
ALTER RULE rules_parted_table_insert ON rules_parted_table RENAME TO rules_parted_table_insert_redirect;
DROP TABLE rules_parted_table;

--
-- test MERGE
--
CREATE TABLE rule_merge1 (a int, b text);
CREATE TABLE rule_merge2 (a int, b text);
CREATE RULE rule1 AS ON INSERT TO rule_merge1
	DO INSTEAD INSERT INTO rule_merge2 VALUES (NEW.*);
CREATE RULE rule2 AS ON UPDATE TO rule_merge1
	DO INSTEAD UPDATE rule_merge2 SET a = NEW.a, b = NEW.b
	WHERE a = OLD.a;
CREATE RULE rule3 AS ON DELETE TO rule_merge1
	DO INSTEAD DELETE FROM rule_merge2 WHERE a = OLD.a;

-- MERGE not supported for table with rules
MERGE INTO rule_merge1 t USING (SELECT 1 AS a) s
	ON t.a = s.a
	WHEN MATCHED AND t.a < 2 THEN
		UPDATE SET b = b || ' updated by merge'
	WHEN MATCHED AND t.a > 2 THEN
		DELETE
	WHEN NOT MATCHED THEN
		INSERT VALUES (s.a, '');

-- should be ok with the other table though
MERGE INTO rule_merge2 t USING (SELECT 1 AS a) s
	ON t.a = s.a
	WHEN MATCHED AND t.a < 2 THEN
		UPDATE SET b = b || ' updated by merge'
	WHEN MATCHED AND t.a > 2 THEN
		DELETE
	WHEN NOT MATCHED THEN
		INSERT VALUES (s.a, '');

-- test deparsing
CREATE TABLE sf_target(id int, data text, filling int[]);

CREATE FUNCTION merge_sf_test()
 RETURNS void
 LANGUAGE sql
BEGIN ATOMIC
 MERGE INTO sf_target t
   USING rule_merge1 s
   ON (s.a = t.id)
WHEN MATCHED
   AND (s.a + t.id) = 42
   THEN UPDATE SET data = repeat(t.data, s.a) || s.b, id = length(s.b)
WHEN NOT MATCHED
   AND (s.b IS NOT NULL)
   THEN INSERT (data, id)
   VALUES (s.b, s.a)
WHEN MATCHED
   AND length(s.b || t.data) > 10
   THEN UPDATE SET data = s.b
WHEN MATCHED
   AND s.a > 200
   THEN UPDATE SET filling[s.a] = t.id
WHEN MATCHED
   AND s.a > 100
   THEN DELETE
WHEN MATCHED
   THEN DO NOTHING
WHEN NOT MATCHED
   AND s.a > 200
   THEN INSERT DEFAULT VALUES
WHEN NOT MATCHED
   AND s.a > 100
   THEN INSERT (id, data) OVERRIDING USER VALUE
   VALUES (s.a, DEFAULT)
WHEN NOT MATCHED
   AND s.a > 0
   THEN INSERT
   VALUES (s.a, s.b, DEFAULT)
WHEN NOT MATCHED
   THEN INSERT (filling[1], id)
   VALUES (s.a, s.a);
END;

\sf merge_sf_test

DROP FUNCTION merge_sf_test;
DROP TABLE sf_target;

--
-- Test enabling/disabling
--
CREATE TABLE ruletest1 (a int);
CREATE TABLE ruletest2 (b int);

CREATE RULE rule1 AS ON INSERT TO ruletest1
    DO INSTEAD INSERT INTO ruletest2 VALUES (NEW.*);

INSERT INTO ruletest1 VALUES (1);
ALTER TABLE ruletest1 DISABLE RULE rule1;
INSERT INTO ruletest1 VALUES (2);
ALTER TABLE ruletest1 ENABLE RULE rule1;
SET session_replication_role = replica;
INSERT INTO ruletest1 VALUES (3);
ALTER TABLE ruletest1 ENABLE REPLICA RULE rule1;
INSERT INTO ruletest1 VALUES (4);
RESET session_replication_role;
INSERT INTO ruletest1 VALUES (5);

SELECT * FROM ruletest1;
SELECT * FROM ruletest2;

DROP TABLE ruletest1;
DROP TABLE ruletest2;

--
-- Test non-SELECT rule on security invoker view.
-- Should use view owner's permissions.
--
CREATE USER regress_rule_user1;

CREATE TABLE ruletest_t1 (x int);
CREATE TABLE ruletest_t2 (x int);
CREATE VIEW ruletest_v1 WITH (security_invoker=true) AS
    SELECT * FROM ruletest_t1;
GRANT INSERT ON ruletest_v1 TO regress_rule_user1;

CREATE RULE rule1 AS ON INSERT TO ruletest_v1
    DO INSTEAD INSERT INTO ruletest_t2 VALUES (NEW.*);

SET SESSION AUTHORIZATION regress_rule_user1;
INSERT INTO ruletest_v1 VALUES (1);

RESET SESSION AUTHORIZATION;
SELECT * FROM ruletest_t1;
SELECT * FROM ruletest_t2;

DROP VIEW ruletest_v1;
DROP TABLE ruletest_t2;
DROP TABLE ruletest_t1;

DROP USER regress_rule_user1;