~vcs-imports/mammoth-replicator/trunk

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
--
-- OPR_SANITY
-- Sanity checks for common errors in making operator/procedure system tables:
-- pg_operator, pg_proc, pg_cast, pg_aggregate, pg_am, pg_amop, pg_amproc, pg_opclass.
--
-- None of the SELECTs here should ever find any matching entries,
-- so the expected output is easy to maintain ;-).
-- A test failure indicates someone messed up an entry in the system tables.
--
-- NB: we assume the oidjoins test will have caught any dangling links,
-- that is OID or REGPROC fields that are not zero and do not match some
-- row in the linked-to table.  However, if we want to enforce that a link
-- field can't be 0, we have to check it here.
--
-- NB: run this test earlier than the create_operator test, because
-- that test creates some bogus operators...


-- Helper functions to deal with cases where binary-coercible matches are
-- allowed.

-- This should match IsBinaryCoercible() in parse_coerce.c.
create function binary_coercible(oid, oid) returns bool as
'SELECT ($1 = $2) OR
 EXISTS(select 1 from pg_cast where
        castsource = $1 and casttarget = $2 and
        castfunc = 0 and castcontext = ''i'')'
language sql;

-- This one ignores castcontext, so it considers only physical equivalence
-- and not whether the coercion can be invoked implicitly.
create function physically_coercible(oid, oid) returns bool as
'SELECT ($1 = $2) OR
 EXISTS(select 1 from pg_cast where
        castsource = $1 and casttarget = $2 and
        castfunc = 0)'
language sql;

-- **************** pg_proc ****************

-- Look for illegal values in pg_proc fields.
-- NOTE: in reality pronargs could be more than 10, but I'm too lazy to put
-- a larger number of proargtypes check clauses in here.  If we ever have
-- more-than-10-arg functions in the standard catalogs, extend this query.

SELECT p1.oid, p1.proname
FROM pg_proc as p1
WHERE p1.prolang = 0 OR p1.prorettype = 0 OR
       p1.pronargs < 0 OR p1.pronargs > 10 OR
       (p1.proargtypes[0] = 0 AND p1.pronargs > 0) OR
       (p1.proargtypes[1] = 0 AND p1.pronargs > 1) OR
       (p1.proargtypes[2] = 0 AND p1.pronargs > 2) OR
       (p1.proargtypes[3] = 0 AND p1.pronargs > 3) OR
       (p1.proargtypes[4] = 0 AND p1.pronargs > 4) OR
       (p1.proargtypes[5] = 0 AND p1.pronargs > 5) OR
       (p1.proargtypes[6] = 0 AND p1.pronargs > 6) OR
       (p1.proargtypes[7] = 0 AND p1.pronargs > 7) OR
       (p1.proargtypes[8] = 0 AND p1.pronargs > 8) OR
       (p1.proargtypes[9] = 0 AND p1.pronargs > 9);

-- Look for conflicting proc definitions (same names and input datatypes).
-- (This test should be dead code now that we have the unique index
-- pg_proc_proname_narg_type_index, but I'll leave it in anyway.)

SELECT p1.oid, p1.proname, p2.oid, p2.proname
FROM pg_proc AS p1, pg_proc AS p2
WHERE p1.oid != p2.oid AND
    p1.proname = p2.proname AND
    p1.pronargs = p2.pronargs AND
    p1.proargtypes = p2.proargtypes;

-- Considering only built-in procs (prolang = 12), look for multiple uses
-- of the same internal function (ie, matching prosrc fields).  It's OK to
-- have several entries with different pronames for the same internal function,
-- but conflicts in the number of arguments and other critical items should
-- be complained of.

SELECT p1.oid, p1.proname, p2.oid, p2.proname
FROM pg_proc AS p1, pg_proc AS p2
WHERE p1.oid != p2.oid AND
    p1.prosrc = p2.prosrc AND
    p1.prolang = 12 AND p2.prolang = 12 AND
    (p1.prolang != p2.prolang OR
     p1.proisagg != p2.proisagg OR
     p1.prosecdef != p2.prosecdef OR
     p1.proisstrict != p2.proisstrict OR
     p1.proretset != p2.proretset OR
     p1.provolatile != p2.provolatile OR
     p1.pronargs != p2.pronargs);

-- Look for uses of different type OIDs in the argument/result type fields
-- for different aliases of the same built-in function.
-- This indicates that the types are being presumed to be binary-equivalent,
-- or that the built-in function is prepared to deal with different types.
-- That's not wrong, necessarily, but we make lists of all the types being
-- so treated.  Note that the expected output of this part of the test will
-- need to be modified whenever new pairs of types are made binary-equivalent,
-- or when new polymorphic built-in functions are added!
-- Note: ignore aggregate functions here, since they all point to the same
-- dummy built-in function.

SELECT DISTINCT p1.prorettype, p2.prorettype
FROM pg_proc AS p1, pg_proc AS p2
WHERE p1.oid != p2.oid AND
    p1.prosrc = p2.prosrc AND
    p1.prolang = 12 AND p2.prolang = 12 AND
    NOT p1.proisagg AND NOT p2.proisagg AND
    (p1.prorettype < p2.prorettype);

SELECT DISTINCT p1.proargtypes[0], p2.proargtypes[0]
FROM pg_proc AS p1, pg_proc AS p2
WHERE p1.oid != p2.oid AND
    p1.prosrc = p2.prosrc AND
    p1.prolang = 12 AND p2.prolang = 12 AND
    NOT p1.proisagg AND NOT p2.proisagg AND
    (p1.proargtypes[0] < p2.proargtypes[0]);

SELECT DISTINCT p1.proargtypes[1], p2.proargtypes[1]
FROM pg_proc AS p1, pg_proc AS p2
WHERE p1.oid != p2.oid AND
    p1.prosrc = p2.prosrc AND
    p1.prolang = 12 AND p2.prolang = 12 AND
    NOT p1.proisagg AND NOT p2.proisagg AND
    (p1.proargtypes[1] < p2.proargtypes[1]);

SELECT DISTINCT p1.proargtypes[2], p2.proargtypes[2]
FROM pg_proc AS p1, pg_proc AS p2
WHERE p1.oid != p2.oid AND
    p1.prosrc = p2.prosrc AND
    p1.prolang = 12 AND p2.prolang = 12 AND
    NOT p1.proisagg AND NOT p2.proisagg AND
    (p1.proargtypes[2] < p2.proargtypes[2]);

SELECT DISTINCT p1.proargtypes[3], p2.proargtypes[3]
FROM pg_proc AS p1, pg_proc AS p2
WHERE p1.oid != p2.oid AND
    p1.prosrc = p2.prosrc AND
    p1.prolang = 12 AND p2.prolang = 12 AND
    NOT p1.proisagg AND NOT p2.proisagg AND
    (p1.proargtypes[3] < p2.proargtypes[3]);

SELECT DISTINCT p1.proargtypes[4], p2.proargtypes[4]
FROM pg_proc AS p1, pg_proc AS p2
WHERE p1.oid != p2.oid AND
    p1.prosrc = p2.prosrc AND
    p1.prolang = 12 AND p2.prolang = 12 AND
    NOT p1.proisagg AND NOT p2.proisagg AND
    (p1.proargtypes[4] < p2.proargtypes[4]);

SELECT DISTINCT p1.proargtypes[5], p2.proargtypes[5]
FROM pg_proc AS p1, pg_proc AS p2
WHERE p1.oid != p2.oid AND
    p1.prosrc = p2.prosrc AND
    p1.prolang = 12 AND p2.prolang = 12 AND
    NOT p1.proisagg AND NOT p2.proisagg AND
    (p1.proargtypes[5] < p2.proargtypes[5]);

SELECT DISTINCT p1.proargtypes[6], p2.proargtypes[6]
FROM pg_proc AS p1, pg_proc AS p2
WHERE p1.oid != p2.oid AND
    p1.prosrc = p2.prosrc AND
    p1.prolang = 12 AND p2.prolang = 12 AND
    NOT p1.proisagg AND NOT p2.proisagg AND
    (p1.proargtypes[6] < p2.proargtypes[6]);

SELECT DISTINCT p1.proargtypes[7], p2.proargtypes[7]
FROM pg_proc AS p1, pg_proc AS p2
WHERE p1.oid != p2.oid AND
    p1.prosrc = p2.prosrc AND
    p1.prolang = 12 AND p2.prolang = 12 AND
    NOT p1.proisagg AND NOT p2.proisagg AND
    (p1.proargtypes[7] < p2.proargtypes[7]);

-- Look for functions that return type "internal" and do not have any
-- "internal" argument.  Such a function would be a security hole since
-- it might be used to call an internal function from an SQL command.
-- As of 7.3 this query should find only internal_in.

SELECT p1.oid, p1.proname
FROM pg_proc as p1
WHERE p1.prorettype = 'internal'::regtype AND NOT
    ('(' || oidvectortypes(p1.proargtypes) || ')') ~ '[^a-z0-9_]internal[^a-z0-9_]';


-- **************** pg_cast ****************

-- Catch bogus values in pg_cast columns (other than cases detected by
-- oidjoins test).

SELECT *
FROM pg_cast c
WHERE castsource = 0 OR casttarget = 0 OR castcontext NOT IN ('e', 'a', 'i');

-- Look for casts to/from the same type that aren't length coercion functions.
-- (We assume they are length coercions if they take multiple arguments.)
-- Such entries are not necessarily harmful, but they are useless.

SELECT *
FROM pg_cast c
WHERE castsource = casttarget AND castfunc = 0;

SELECT c.*
FROM pg_cast c, pg_proc p
WHERE c.castfunc = p.oid AND p.pronargs < 2 AND castsource = casttarget;

-- Look for cast functions that don't have the right signature.  The
-- argument and result types in pg_proc must be the same as, or binary
-- compatible with, what it says in pg_cast.
-- As a special case, we allow casts from CHAR(n) that use functions
-- declared to take TEXT.  This does not pass the binary-coercibility test
-- because CHAR(n)-to-TEXT normally invokes rtrim().  However, the results
-- are the same, so long as the function is one that ignores trailing blanks.

SELECT c.*
FROM pg_cast c, pg_proc p
WHERE c.castfunc = p.oid AND
    (p.pronargs < 1 OR p.pronargs > 3
     OR NOT (binary_coercible(c.castsource, p.proargtypes[0])
             OR (c.castsource = 'character'::regtype AND
                 p.proargtypes[0] = 'text'::regtype))
     OR NOT binary_coercible(p.prorettype, c.casttarget));

SELECT c.*
FROM pg_cast c, pg_proc p
WHERE c.castfunc = p.oid AND
    ((p.pronargs > 1 AND p.proargtypes[1] != 'int4'::regtype) OR
     (p.pronargs > 2 AND p.proargtypes[2] != 'bool'::regtype));

-- Look for binary compatible casts that do not have the reverse
-- direction registered as well, or where the reverse direction is not
-- also binary compatible.  This is legal, but usually not intended.

-- As of 7.4, this finds the casts from text and varchar to bpchar, because
-- those are binary-compatible while the reverse way goes through rtrim().

SELECT *
FROM pg_cast c
WHERE c.castfunc = 0 AND
    NOT EXISTS (SELECT 1 FROM pg_cast k
                WHERE k.castfunc = 0 AND
                    k.castsource = c.casttarget AND
                    k.casttarget = c.castsource);

-- **************** pg_operator ****************

-- Look for illegal values in pg_operator fields.

SELECT p1.oid, p1.oprname
FROM pg_operator as p1
WHERE (p1.oprkind != 'b' AND p1.oprkind != 'l' AND p1.oprkind != 'r') OR
    p1.oprresult = 0 OR p1.oprcode = 0;

-- Look for missing or unwanted operand types

SELECT p1.oid, p1.oprname
FROM pg_operator as p1
WHERE (p1.oprleft = 0 and p1.oprkind != 'l') OR
    (p1.oprleft != 0 and p1.oprkind = 'l') OR
    (p1.oprright = 0 and p1.oprkind != 'r') OR
    (p1.oprright != 0 and p1.oprkind = 'r');

-- Look for conflicting operator definitions (same names and input datatypes).

SELECT p1.oid, p1.oprcode, p2.oid, p2.oprcode
FROM pg_operator AS p1, pg_operator AS p2
WHERE p1.oid != p2.oid AND
    p1.oprname = p2.oprname AND
    p1.oprkind = p2.oprkind AND
    p1.oprleft = p2.oprleft AND
    p1.oprright = p2.oprright;

-- Look for commutative operators that don't commute.
-- DEFINITIONAL NOTE: If A.oprcom = B, then x A y has the same result as y B x.
-- We expect that B will always say that B.oprcom = A as well; that's not
-- inherently essential, but it would be inefficient not to mark it so.

SELECT p1.oid, p1.oprcode, p2.oid, p2.oprcode
FROM pg_operator AS p1, pg_operator AS p2
WHERE p1.oprcom = p2.oid AND
    (p1.oprkind != 'b' OR
     p1.oprleft != p2.oprright OR
     p1.oprright != p2.oprleft OR
     p1.oprresult != p2.oprresult OR
     p1.oid != p2.oprcom);

-- Look for negatory operators that don't agree.
-- DEFINITIONAL NOTE: If A.oprnegate = B, then both A and B must yield
-- boolean results, and (x A y) == ! (x B y), or the equivalent for
-- single-operand operators.
-- We expect that B will always say that B.oprnegate = A as well; that's not
-- inherently essential, but it would be inefficient not to mark it so.
-- Also, A and B had better not be the same operator.

SELECT p1.oid, p1.oprcode, p2.oid, p2.oprcode
FROM pg_operator AS p1, pg_operator AS p2
WHERE p1.oprnegate = p2.oid AND
    (p1.oprkind != p2.oprkind OR
     p1.oprleft != p2.oprleft OR
     p1.oprright != p2.oprright OR
     p1.oprresult != 'bool'::regtype OR
     p2.oprresult != 'bool'::regtype OR
     p1.oid != p2.oprnegate OR
     p1.oid = p2.oid);

-- Look for mergejoin operators that don't match their links.
-- An lsortop/rsortop link leads from an '=' operator to the
-- sort operator ('<' operator) that's appropriate for
-- its left-side or right-side data type.
-- An ltcmpop/gtcmpop link leads from an '=' operator to the
-- '<' or '>' operator of the same input datatypes.
-- (If the '=' operator has identical L and R input datatypes,
-- then lsortop, rsortop, and ltcmpop are all the same operator.)

SELECT p1.oid, p1.oprcode, p2.oid, p2.oprcode
FROM pg_operator AS p1, pg_operator AS p2
WHERE p1.oprlsortop = p2.oid AND
    (p1.oprname NOT IN ('=', '~=~') OR p2.oprname NOT IN ('<', '~<~') OR
     p1.oprkind != 'b' OR p2.oprkind != 'b' OR
     p1.oprleft != p2.oprleft OR
     p1.oprleft != p2.oprright OR
     p1.oprresult != 'bool'::regtype OR
     p2.oprresult != 'bool'::regtype);

SELECT p1.oid, p1.oprcode, p2.oid, p2.oprcode
FROM pg_operator AS p1, pg_operator AS p2
WHERE p1.oprrsortop = p2.oid AND
    (p1.oprname NOT IN ('=', '~=~') OR p2.oprname NOT IN ('<', '~<~') OR
     p1.oprkind != 'b' OR p2.oprkind != 'b' OR
     p1.oprright != p2.oprleft OR
     p1.oprright != p2.oprright OR
     p1.oprresult != 'bool'::regtype OR
     p2.oprresult != 'bool'::regtype);

SELECT p1.oid, p1.oprcode, p2.oid, p2.oprcode
FROM pg_operator AS p1, pg_operator AS p2
WHERE p1.oprltcmpop = p2.oid AND
    (p1.oprname NOT IN ('=', '~=~') OR p2.oprname NOT IN ('<', '~<~') OR
     p1.oprkind != 'b' OR p2.oprkind != 'b' OR
     p1.oprleft != p2.oprleft OR
     p1.oprright != p2.oprright OR
     p1.oprresult != 'bool'::regtype OR
     p2.oprresult != 'bool'::regtype);

SELECT p1.oid, p1.oprcode, p2.oid, p2.oprcode
FROM pg_operator AS p1, pg_operator AS p2
WHERE p1.oprgtcmpop = p2.oid AND
    (p1.oprname NOT IN ('=', '~=~') OR p2.oprname NOT IN ('>', '~>~') OR
     p1.oprkind != 'b' OR p2.oprkind != 'b' OR
     p1.oprleft != p2.oprleft OR
     p1.oprright != p2.oprright OR
     p1.oprresult != 'bool'::regtype OR
     p2.oprresult != 'bool'::regtype);

-- Make sure all four links are specified if any are.

SELECT p1.oid, p1.oprcode
FROM pg_operator AS p1
WHERE NOT ((oprlsortop = 0 AND oprrsortop = 0 AND
            oprltcmpop = 0 AND oprgtcmpop = 0) OR
           (oprlsortop != 0 AND oprrsortop != 0 AND
            oprltcmpop != 0 AND oprgtcmpop != 0));

-- A mergejoinable = operator must have a commutator (usually itself).

SELECT p1.oid, p1.oprname FROM pg_operator AS p1
WHERE p1.oprlsortop != 0 AND
      p1.oprcom = 0;

-- Mergejoinable operators across datatypes must come in closed sets, that
-- is if you provide int2 = int4 and int4 = int8 then you must also provide
-- int2 = int8 (and commutators of all these).  This is necessary because
-- the planner tries to deduce additional qual clauses from transitivity
-- of mergejoinable operators.  If there are clauses int2var = int4var and
-- int4var = int8var, the planner will deduce int2var = int8var ... and it
-- had better have a way to represent it.

SELECT p1.oid, p2.oid FROM pg_operator AS p1, pg_operator AS p2
WHERE p1.oprlsortop != p1.oprrsortop AND
      p1.oprrsortop = p2.oprlsortop AND
      p2.oprlsortop != p2.oprrsortop AND
      NOT EXISTS (SELECT 1 FROM pg_operator p3 WHERE
      p3.oprlsortop = p1.oprlsortop AND p3.oprrsortop = p2.oprrsortop);


-- Hashing only works on simple equality operators "type = sametype",
-- since the hash itself depends on the bitwise representation of the type.
-- Check that allegedly hashable operators look like they might be "=".

SELECT p1.oid, p1.oprname
FROM pg_operator AS p1
WHERE p1.oprcanhash AND NOT
    (p1.oprkind = 'b' AND p1.oprresult = 'bool'::regtype AND
     p1.oprleft = p1.oprright AND p1.oprname IN ('=', '~=~') AND
     p1.oprcom = p1.oid);

-- In 6.5 we accepted hashable array equality operators when the array element
-- type is hashable.  However, what we actually need to make hashjoin work on
-- an array is a hashable element type *and* no padding between elements in
-- the array storage (or, perhaps, guaranteed-zero padding).  Currently,
-- since the padding code in arrayfuncs.c is pretty bogus, it seems safest
-- to just forbid hashjoin on array equality ops.
-- This should be reconsidered someday.

-- -- Look for array equality operators that are hashable when the underlying
-- -- type is not, or vice versa.  This is presumably bogus.
-- 
-- SELECT p1.oid, p1.oprcanhash, p2.oid, p2.oprcanhash, t1.typname, t2.typname
-- FROM pg_operator AS p1, pg_operator AS p2, pg_type AS t1, pg_type AS t2
-- WHERE p1.oprname = '=' AND p1.oprleft = p1.oprright AND 
--     p2.oprname = '=' AND p2.oprleft = p2.oprright AND
--     p1.oprleft = t1.oid AND p2.oprleft = t2.oid AND t1.typelem = t2.oid AND
--     p1.oprcanhash != p2.oprcanhash;

-- Substitute check: forbid hashable array ops, period.
SELECT p1.oid, p1.oprname
FROM pg_operator AS p1, pg_proc AS p2
WHERE p1.oprcanhash AND p1.oprcode = p2.oid AND p2.proname = 'array_eq';

-- Hashable operators should appear as members of hash index opclasses.

SELECT p1.oid, p1.oprname
FROM pg_operator AS p1
WHERE p1.oprcanhash AND NOT EXISTS
  (SELECT 1 FROM pg_opclass op JOIN pg_amop p ON op.oid = amopclaid
   WHERE opcamid = (SELECT oid FROM pg_am WHERE amname = 'hash') AND
         amopopr = p1.oid);

-- And the converse.

SELECT p1.oid, p1.oprname, op.opcname
FROM pg_operator AS p1, pg_opclass op, pg_amop p
WHERE amopopr = p1.oid AND amopclaid = op.oid
  AND opcamid = (SELECT oid FROM pg_am WHERE amname = 'hash')
  AND NOT p1.oprcanhash;

-- Check that each operator defined in pg_operator matches its oprcode entry
-- in pg_proc.  Easiest to do this separately for each oprkind.

SELECT p1.oid, p1.oprname, p2.oid, p2.proname
FROM pg_operator AS p1, pg_proc AS p2
WHERE p1.oprcode = p2.oid AND
    p1.oprkind = 'b' AND
    (p2.pronargs != 2
     OR NOT binary_coercible(p2.prorettype, p1.oprresult)
     OR NOT binary_coercible(p1.oprleft, p2.proargtypes[0])
     OR NOT binary_coercible(p1.oprright, p2.proargtypes[1]));

SELECT p1.oid, p1.oprname, p2.oid, p2.proname
FROM pg_operator AS p1, pg_proc AS p2
WHERE p1.oprcode = p2.oid AND
    p1.oprkind = 'l' AND
    (p2.pronargs != 1
     OR NOT binary_coercible(p2.prorettype, p1.oprresult)
     OR NOT binary_coercible(p1.oprright, p2.proargtypes[0])
     OR p1.oprleft != 0);

SELECT p1.oid, p1.oprname, p2.oid, p2.proname
FROM pg_operator AS p1, pg_proc AS p2
WHERE p1.oprcode = p2.oid AND
    p1.oprkind = 'r' AND
    (p2.pronargs != 1
     OR NOT binary_coercible(p2.prorettype, p1.oprresult)
     OR NOT binary_coercible(p1.oprleft, p2.proargtypes[0])
     OR p1.oprright != 0);

-- If the operator is mergejoinable or hashjoinable, its underlying function
-- should not be volatile.

SELECT p1.oid, p1.oprname, p2.oid, p2.proname
FROM pg_operator AS p1, pg_proc AS p2
WHERE p1.oprcode = p2.oid AND
    (p1.oprlsortop != 0 OR p1.oprcanhash) AND
    p2.provolatile = 'v';

-- If oprrest is set, the operator must return boolean,
-- and it must link to a proc with the right signature
-- to be a restriction selectivity estimator.
-- The proc signature we want is: float8 proc(internal, oid, internal, int4)

SELECT p1.oid, p1.oprname, p2.oid, p2.proname
FROM pg_operator AS p1, pg_proc AS p2
WHERE p1.oprrest = p2.oid AND
    (p1.oprresult != 'bool'::regtype OR
     p2.prorettype != 'float8'::regtype OR p2.proretset OR
     p2.pronargs != 4 OR
     p2.proargtypes[0] != 'internal'::regtype OR
     p2.proargtypes[1] != 'oid'::regtype OR
     p2.proargtypes[2] != 'internal'::regtype OR
     p2.proargtypes[3] != 'int4'::regtype);

-- If oprjoin is set, the operator must be a binary boolean op,
-- and it must link to a proc with the right signature
-- to be a join selectivity estimator.
-- The proc signature we want is: float8 proc(internal, oid, internal, int2)

SELECT p1.oid, p1.oprname, p2.oid, p2.proname
FROM pg_operator AS p1, pg_proc AS p2
WHERE p1.oprjoin = p2.oid AND
    (p1.oprkind != 'b' OR p1.oprresult != 'bool'::regtype OR
     p2.prorettype != 'float8'::regtype OR p2.proretset OR
     p2.pronargs != 4 OR
     p2.proargtypes[0] != 'internal'::regtype OR
     p2.proargtypes[1] != 'oid'::regtype OR
     p2.proargtypes[2] != 'internal'::regtype OR
     p2.proargtypes[3] != 'int2'::regtype);

-- **************** pg_aggregate ****************

-- Look for illegal values in pg_aggregate fields.

SELECT ctid, aggfnoid::oid
FROM pg_aggregate as p1
WHERE aggfnoid = 0 OR aggtransfn = 0 OR aggtranstype = 0;

-- Make sure the matching pg_proc entry is sensible, too.

SELECT a.aggfnoid::oid, p.proname
FROM pg_aggregate as a, pg_proc as p
WHERE a.aggfnoid = p.oid AND
    (NOT p.proisagg OR p.pronargs != 1 OR p.proretset);

-- Make sure there are no proisagg pg_proc entries without matches.

SELECT oid, proname
FROM pg_proc as p
WHERE p.proisagg AND
    NOT EXISTS (SELECT 1 FROM pg_aggregate a WHERE a.aggfnoid = p.oid);

-- If there is no finalfn then the output type must be the transtype.

SELECT a.aggfnoid::oid, p.proname
FROM pg_aggregate as a, pg_proc as p
WHERE a.aggfnoid = p.oid AND
    a.aggfinalfn = 0 AND p.prorettype != a.aggtranstype;

-- Cross-check transfn against its entry in pg_proc.
-- NOTE: use physically_coercible here, not binary_coercible, because
-- max and min on abstime are implemented using int4larger/int4smaller.
SELECT a.aggfnoid::oid, p.proname, ptr.oid, ptr.proname
FROM pg_aggregate AS a, pg_proc AS p, pg_proc AS ptr
WHERE a.aggfnoid = p.oid AND
    a.aggtransfn = ptr.oid AND
    (ptr.proretset
     OR NOT physically_coercible(ptr.prorettype, a.aggtranstype)
     OR NOT physically_coercible(a.aggtranstype, ptr.proargtypes[0])
     OR NOT ((ptr.pronargs = 2 AND
              physically_coercible(p.proargtypes[0], ptr.proargtypes[1]))
             OR
             (ptr.pronargs = 1 AND
              p.proargtypes[0] = '"any"'::regtype)));

-- Cross-check finalfn (if present) against its entry in pg_proc.

SELECT a.aggfnoid::oid, p.proname, pfn.oid, pfn.proname
FROM pg_aggregate AS a, pg_proc AS p, pg_proc AS pfn
WHERE a.aggfnoid = p.oid AND
    a.aggfinalfn = pfn.oid AND
    (pfn.proretset
     OR NOT binary_coercible(pfn.prorettype, p.prorettype)
     OR pfn.pronargs != 1
     OR NOT binary_coercible(a.aggtranstype, pfn.proargtypes[0]));

-- If transfn is strict then either initval should be non-NULL, or
-- input type should match transtype so that the first non-null input
-- can be assigned as the state value.

SELECT a.aggfnoid::oid, p.proname, ptr.oid, ptr.proname
FROM pg_aggregate AS a, pg_proc AS p, pg_proc AS ptr
WHERE a.aggfnoid = p.oid AND
    a.aggtransfn = ptr.oid AND ptr.proisstrict AND
    a.agginitval IS NULL AND
    NOT binary_coercible(p.proargtypes[0], a.aggtranstype);

-- **************** pg_opclass ****************

-- Look for illegal values in pg_opclass fields

SELECT p1.oid
FROM pg_opclass as p1
WHERE p1.opcamid = 0 OR p1.opcintype = 0;

-- There should not be multiple entries in pg_opclass with opcdefault true
-- and the same opcamid/opcintype combination.

SELECT p1.oid, p2.oid
FROM pg_opclass AS p1, pg_opclass AS p2
WHERE p1.oid != p2.oid AND
    p1.opcamid = p2.opcamid AND p1.opcintype = p2.opcintype AND
    p1.opcdefault AND p2.opcdefault;

-- **************** pg_amop ****************

-- Look for illegal values in pg_amop fields

SELECT p1.amopclaid, p1.amopstrategy
FROM pg_amop as p1
WHERE p1.amopclaid = 0 OR p1.amopstrategy <= 0 OR p1.amopopr = 0;

-- Cross-check amopstrategy index against parent AM

SELECT p1.amopclaid, p1.amopopr, p2.oid, p2.amname
FROM pg_amop AS p1, pg_am AS p2, pg_opclass AS p3
WHERE p1.amopclaid = p3.oid AND p3.opcamid = p2.oid AND
    p1.amopstrategy > p2.amstrategies;

-- Detect missing pg_amop entries: should have as many strategy operators
-- as AM expects for each opclass for the AM.  When nondefault subtypes are
-- present, enforce condition separately for each subtype.

SELECT p1.oid, p1.amname, p2.oid, p2.opcname, p3.amopsubtype
FROM pg_am AS p1, pg_opclass AS p2, pg_amop AS p3
WHERE p2.opcamid = p1.oid AND p3.amopclaid = p2.oid AND
    p1.amstrategies != (SELECT count(*) FROM pg_amop AS p4
                        WHERE p4.amopclaid = p2.oid AND
                              p4.amopsubtype = p3.amopsubtype);

-- Check that amopopr points at a reasonable-looking operator, ie a binary
-- operator yielding boolean.

SELECT p1.amopclaid, p1.amopopr, p2.oid, p2.oprname
FROM pg_amop AS p1, pg_operator AS p2
WHERE p1.amopopr = p2.oid AND
    (p2.oprkind != 'b' OR p2.oprresult != 'bool'::regtype);

-- Make a list of all the distinct operator names being used in particular
-- strategy slots.  This is a bit hokey, since the list might need to change
-- in future releases, but it's an effective way of spotting mistakes such as
-- swapping two operators within a class.

SELECT DISTINCT opcamid, amopstrategy, oprname
FROM pg_amop p1 LEFT JOIN pg_opclass p2 ON amopclaid = p2.oid
                LEFT JOIN pg_operator p3 ON amopopr = p3.oid
ORDER BY 1, 2, 3;

-- Check that all operators linked to by opclass entries have selectivity
-- estimators.  This is not absolutely required, but it seems a reasonable
-- thing to insist on for all standard datatypes.

SELECT p1.amopclaid, p1.amopopr, p2.oid, p2.oprname
FROM pg_amop AS p1, pg_operator AS p2
WHERE p1.amopopr = p2.oid AND
    (p2.oprrest = 0 OR p2.oprjoin = 0);

-- Check that operator input types match the opclass
-- For 8.0, we require that oprleft match opcintype (possibly by coercion).
-- When amopsubtype is zero (default), oprright must equal oprleft;
-- when amopsubtype is not zero, oprright must equal amopsubtype.

SELECT p1.amopclaid, p1.amopopr, p2.oid, p2.oprname, p3.opcname
FROM pg_amop AS p1, pg_operator AS p2, pg_opclass AS p3
WHERE p1.amopopr = p2.oid AND p1.amopclaid = p3.oid AND
    NOT binary_coercible(p3.opcintype, p2.oprleft);

SELECT p1.amopclaid, p1.amopopr, p2.oid, p2.oprname, p3.opcname
FROM pg_amop AS p1, pg_operator AS p2, pg_opclass AS p3
WHERE p1.amopopr = p2.oid AND p1.amopclaid = p3.oid AND
    p1.amopsubtype = 0 AND
    p2.oprleft != p2.oprright;

SELECT p1.amopclaid, p1.amopopr, p2.oid, p2.oprname, p3.opcname
FROM pg_amop AS p1, pg_operator AS p2, pg_opclass AS p3
WHERE p1.amopopr = p2.oid AND p1.amopclaid = p3.oid AND
    p1.amopsubtype != 0 AND
    p1.amopsubtype != p2.oprright;

-- Operators that are primary members of opclasses must be immutable (else
-- it suggests that the index ordering isn't fixed).  Operators that are
-- cross-type members need only be stable, since they are just shorthands
-- for index probe queries.

SELECT p1.amopclaid, p1.amopopr, p2.oprname, p3.prosrc
FROM pg_amop AS p1, pg_operator AS p2, pg_proc AS p3
WHERE p1.amopopr = p2.oid AND p2.oprcode = p3.oid AND
    p1.amopsubtype = 0 AND
    p3.provolatile != 'i';

SELECT p1.amopclaid, p1.amopopr, p2.oprname, p3.prosrc
FROM pg_amop AS p1, pg_operator AS p2, pg_proc AS p3
WHERE p1.amopopr = p2.oid AND p2.oprcode = p3.oid AND
    p1.amopsubtype != 0 AND
    p3.provolatile = 'v';

-- **************** pg_amproc ****************

-- Look for illegal values in pg_amproc fields

SELECT p1.amopclaid, p1.amprocnum
FROM pg_amproc as p1
WHERE p1.amopclaid = 0 OR p1.amprocnum <= 0 OR p1.amproc = 0;

-- Cross-check amprocnum index against parent AM

SELECT p1.amopclaid, p1.amprocnum, p2.oid, p2.amname
FROM pg_amproc AS p1, pg_am AS p2, pg_opclass AS p3
WHERE p1.amopclaid = p3.oid AND p3.opcamid = p2.oid AND
    p1.amprocnum > p2.amsupport;

-- Detect missing pg_amproc entries: should have as many support functions
-- as AM expects for each opclass for the AM.  When nondefault subtypes are
-- present, enforce condition separately for each subtype.

SELECT p1.oid, p1.amname, p2.oid, p2.opcname, p3.amprocsubtype
FROM pg_am AS p1, pg_opclass AS p2, pg_amproc AS p3
WHERE p2.opcamid = p1.oid AND p3.amopclaid = p2.oid AND
    p1.amsupport != (SELECT count(*) FROM pg_amproc AS p4
                     WHERE p4.amopclaid = p2.oid AND
                           p4.amprocsubtype = p3.amprocsubtype);

-- Unfortunately, we can't check the amproc link very well because the
-- signature of the function may be different for different support routines
-- or different base data types.
-- We can check that all the referenced instances of the same support
-- routine number take the same number of parameters, but that's about it
-- for a general check...

SELECT p1.amopclaid, p1.amprocnum,
	p2.oid, p2.proname,
	p3.opcname,
	p4.amopclaid, p4.amprocnum,
	p5.oid, p5.proname,
	p6.opcname
FROM pg_amproc AS p1, pg_proc AS p2, pg_opclass AS p3,
     pg_amproc AS p4, pg_proc AS p5, pg_opclass AS p6
WHERE p1.amopclaid = p3.oid AND p4.amopclaid = p6.oid AND
    p3.opcamid = p6.opcamid AND p1.amprocnum = p4.amprocnum AND
    p1.amproc = p2.oid AND p4.amproc = p5.oid AND
    (p2.proretset OR p5.proretset OR p2.pronargs != p5.pronargs);

-- For btree, though, we can do better since we know the support routines
-- must be of the form cmp(input, input) returns int4 in the default case
-- (subtype = 0), and cmp(input, subtype) returns int4 when subtype != 0.

SELECT p1.amopclaid, p1.amprocnum,
	p2.oid, p2.proname,
	p3.opcname
FROM pg_amproc AS p1, pg_proc AS p2, pg_opclass AS p3
WHERE p3.opcamid = (SELECT oid FROM pg_am WHERE amname = 'btree')
    AND p1.amopclaid = p3.oid AND p1.amproc = p2.oid AND
    amprocsubtype = 0 AND
    (opckeytype != 0
     OR amprocnum != 1
     OR proretset
     OR prorettype != 23
     OR pronargs != 2
     OR NOT binary_coercible(opcintype, proargtypes[0])
     OR proargtypes[0] != proargtypes[1]);

SELECT p1.amopclaid, p1.amprocnum,
	p2.oid, p2.proname,
	p3.opcname
FROM pg_amproc AS p1, pg_proc AS p2, pg_opclass AS p3
WHERE p3.opcamid = (SELECT oid FROM pg_am WHERE amname = 'btree')
    AND p1.amopclaid = p3.oid AND p1.amproc = p2.oid AND
    amprocsubtype != 0 AND
    (opckeytype != 0
     OR amprocnum != 1
     OR proretset
     OR prorettype != 23
     OR pronargs != 2
     OR NOT binary_coercible(opcintype, proargtypes[0])
     OR proargtypes[1] != amprocsubtype);

-- For hash we can also do a little better: the support routines must be
-- of the form hash(something) returns int4.  Ideally we'd check that the
-- opcintype is binary-coercible to the function's input, but there are
-- enough cases where that fails that I'll just leave out the check for now.

SELECT p1.amopclaid, p1.amprocnum,
	p2.oid, p2.proname,
	p3.opcname
FROM pg_amproc AS p1, pg_proc AS p2, pg_opclass AS p3
WHERE p3.opcamid = (SELECT oid FROM pg_am WHERE amname = 'hash')
    AND p1.amopclaid = p3.oid AND p1.amproc = p2.oid AND
    (opckeytype != 0
     OR amprocnum != 1
     OR proretset
     OR prorettype != 23
     OR pronargs != 1
--   OR NOT physically_coercible(opcintype, proargtypes[0])
);

-- Support routines that are primary members of opclasses must be immutable
-- (else it suggests that the index ordering isn't fixed).  But cross-type
-- members need only be stable, since they are just shorthands
-- for index probe queries.

SELECT p1.amopclaid, p1.amproc, p2.prosrc
FROM pg_amproc AS p1, pg_proc AS p2
WHERE p1.amproc = p2.oid AND
    p1.amprocsubtype = 0 AND
    p2.provolatile != 'i';

SELECT p1.amopclaid, p1.amproc, p2.prosrc
FROM pg_amproc AS p1, pg_proc AS p2
WHERE p1.amproc = p2.oid AND
    p1.amprocsubtype != 0 AND
    p2.provolatile = 'v';