3 -- Sanity checks for common errors in making operator/procedure system tables:
4 -- pg_operator, pg_proc, pg_cast, pg_aggregate, pg_am,
5 -- pg_amop, pg_amproc, pg_opclass, pg_opfamily.
7 -- None of the SELECTs here should ever find any matching entries,
8 -- so the expected output is easy to maintain ;-).
9 -- A test failure indicates someone messed up an entry in the system tables.
11 -- NB: we assume the oidjoins test will have caught any dangling links,
12 -- that is OID or REGPROC fields that are not zero and do not match some
13 -- row in the linked-to table. However, if we want to enforce that a link
14 -- field can't be 0, we have to check it here.
16 -- NB: run this test earlier than the create_operator test, because
17 -- that test creates some bogus operators...
18 -- Helper functions to deal with cases where binary-coercible matches are
20 -- This should match IsBinaryCoercible() in parse_coerce.c.
21 create function binary_coercible(oid, oid) returns bool as $$
23 EXISTS(select 1 from pg_catalog.pg_cast where
24 castsource = $1 and casttarget = $2 and
25 castmethod = 'b' and castcontext = 'i') OR
26 ($2 = 'pg_catalog.anyarray'::pg_catalog.regtype AND
27 EXISTS(select 1 from pg_catalog.pg_type where
28 oid = $1 and typelem != 0 and typlen = -1))
29 $$ language sql strict stable;
30 -- This one ignores castcontext, so it considers only physical equivalence
31 -- and not whether the coercion can be invoked implicitly.
32 create function physically_coercible(oid, oid) returns bool as $$
34 EXISTS(select 1 from pg_catalog.pg_cast where
35 castsource = $1 and casttarget = $2 and
37 ($2 = 'pg_catalog.anyarray'::pg_catalog.regtype AND
38 EXISTS(select 1 from pg_catalog.pg_type where
39 oid = $1 and typelem != 0 and typlen = -1))
40 $$ language sql strict stable;
41 -- **************** pg_proc ****************
42 -- Look for illegal values in pg_proc fields.
43 SELECT p1.oid, p1.proname
45 WHERE p1.prolang = 0 OR p1.prorettype = 0 OR
47 array_lower(p1.proargtypes, 1) != 0 OR
48 array_upper(p1.proargtypes, 1) != p1.pronargs-1 OR
49 0::oid = ANY (p1.proargtypes) OR
51 CASE WHEN proretset THEN prorows <= 0 ELSE prorows != 0 END;
56 -- prosrc should never be null or empty
57 SELECT p1.oid, p1.proname
59 WHERE prosrc IS NULL OR prosrc = '' OR prosrc = '-';
64 -- probin should be non-empty for C functions, null everywhere else
65 SELECT p1.oid, p1.proname
67 WHERE prolang = 13 AND (probin IS NULL OR probin = '' OR probin = '-');
72 SELECT p1.oid, p1.proname
74 WHERE prolang != 13 AND probin IS NOT NULL;
79 -- Look for conflicting proc definitions (same names and input datatypes).
80 -- (This test should be dead code now that we have the unique index
81 -- pg_proc_proname_args_nsp_index, but I'll leave it in anyway.)
82 SELECT p1.oid, p1.proname, p2.oid, p2.proname
83 FROM pg_proc AS p1, pg_proc AS p2
84 WHERE p1.oid != p2.oid AND
85 p1.proname = p2.proname AND
86 p1.pronargs = p2.pronargs AND
87 p1.proargtypes = p2.proargtypes;
88 oid | proname | oid | proname
89 -----+---------+-----+---------
92 -- Considering only built-in procs (prolang = 12), look for multiple uses
93 -- of the same internal function (ie, matching prosrc fields). It's OK to
94 -- have several entries with different pronames for the same internal function,
95 -- but conflicts in the number of arguments and other critical items should
96 -- be complained of. (We don't check data types here; see next query.)
97 -- Note: ignore aggregate functions here, since they all point to the same
98 -- dummy built-in function.
99 SELECT p1.oid, p1.proname, p2.oid, p2.proname
100 FROM pg_proc AS p1, pg_proc AS p2
101 WHERE p1.oid < p2.oid AND
102 p1.prosrc = p2.prosrc AND
103 p1.prolang = 12 AND p2.prolang = 12 AND
104 (p1.proisagg = false OR p2.proisagg = false) AND
105 (p1.prolang != p2.prolang OR
106 p1.proisagg != p2.proisagg OR
107 p1.prosecdef != p2.prosecdef OR
108 p1.proisstrict != p2.proisstrict OR
109 p1.proretset != p2.proretset OR
110 p1.provolatile != p2.provolatile OR
111 p1.pronargs != p2.pronargs);
112 oid | proname | oid | proname
113 -----+---------+-----+---------
116 -- Look for uses of different type OIDs in the argument/result type fields
117 -- for different aliases of the same built-in function.
118 -- This indicates that the types are being presumed to be binary-equivalent,
119 -- or that the built-in function is prepared to deal with different types.
120 -- That's not wrong, necessarily, but we make lists of all the types being
121 -- so treated. Note that the expected output of this part of the test will
122 -- need to be modified whenever new pairs of types are made binary-equivalent,
123 -- or when new polymorphic built-in functions are added!
124 -- Note: ignore aggregate functions here, since they all point to the same
125 -- dummy built-in function.
126 SELECT DISTINCT p1.prorettype, p2.prorettype
127 FROM pg_proc AS p1, pg_proc AS p2
128 WHERE p1.oid != p2.oid AND
129 p1.prosrc = p2.prosrc AND
130 p1.prolang = 12 AND p2.prolang = 12 AND
131 NOT p1.proisagg AND NOT p2.proisagg AND
132 (p1.prorettype < p2.prorettype)
134 prorettype | prorettype
135 ------------+------------
140 SELECT DISTINCT p1.proargtypes[0], p2.proargtypes[0]
141 FROM pg_proc AS p1, pg_proc AS p2
142 WHERE p1.oid != p2.oid AND
143 p1.prosrc = p2.prosrc AND
144 p1.prolang = 12 AND p2.prolang = 12 AND
145 NOT p1.proisagg AND NOT p2.proisagg AND
146 (p1.proargtypes[0] < p2.proargtypes[0])
148 proargtypes | proargtypes
149 -------------+-------------
157 SELECT DISTINCT p1.proargtypes[1], p2.proargtypes[1]
158 FROM pg_proc AS p1, pg_proc AS p2
159 WHERE p1.oid != p2.oid AND
160 p1.prosrc = p2.prosrc AND
161 p1.prolang = 12 AND p2.prolang = 12 AND
162 NOT p1.proisagg AND NOT p2.proisagg AND
163 (p1.proargtypes[1] < p2.proargtypes[1])
165 proargtypes | proargtypes
166 -------------+-------------
173 SELECT DISTINCT p1.proargtypes[2], p2.proargtypes[2]
174 FROM pg_proc AS p1, pg_proc AS p2
175 WHERE p1.oid != p2.oid AND
176 p1.prosrc = p2.prosrc AND
177 p1.prolang = 12 AND p2.prolang = 12 AND
178 NOT p1.proisagg AND NOT p2.proisagg AND
179 (p1.proargtypes[2] < p2.proargtypes[2])
181 proargtypes | proargtypes
182 -------------+-------------
186 SELECT DISTINCT p1.proargtypes[3], p2.proargtypes[3]
187 FROM pg_proc AS p1, pg_proc AS p2
188 WHERE p1.oid != p2.oid AND
189 p1.prosrc = p2.prosrc AND
190 p1.prolang = 12 AND p2.prolang = 12 AND
191 NOT p1.proisagg AND NOT p2.proisagg AND
192 (p1.proargtypes[3] < p2.proargtypes[3])
194 proargtypes | proargtypes
195 -------------+-------------
199 SELECT DISTINCT p1.proargtypes[4], p2.proargtypes[4]
200 FROM pg_proc AS p1, pg_proc AS p2
201 WHERE p1.oid != p2.oid AND
202 p1.prosrc = p2.prosrc AND
203 p1.prolang = 12 AND p2.prolang = 12 AND
204 NOT p1.proisagg AND NOT p2.proisagg AND
205 (p1.proargtypes[4] < p2.proargtypes[4])
207 proargtypes | proargtypes
208 -------------+-------------
211 SELECT DISTINCT p1.proargtypes[5], p2.proargtypes[5]
212 FROM pg_proc AS p1, pg_proc AS p2
213 WHERE p1.oid != p2.oid AND
214 p1.prosrc = p2.prosrc AND
215 p1.prolang = 12 AND p2.prolang = 12 AND
216 NOT p1.proisagg AND NOT p2.proisagg AND
217 (p1.proargtypes[5] < p2.proargtypes[5])
219 proargtypes | proargtypes
220 -------------+-------------
223 SELECT DISTINCT p1.proargtypes[6], p2.proargtypes[6]
224 FROM pg_proc AS p1, pg_proc AS p2
225 WHERE p1.oid != p2.oid AND
226 p1.prosrc = p2.prosrc AND
227 p1.prolang = 12 AND p2.prolang = 12 AND
228 NOT p1.proisagg AND NOT p2.proisagg AND
229 (p1.proargtypes[6] < p2.proargtypes[6])
231 proargtypes | proargtypes
232 -------------+-------------
235 SELECT DISTINCT p1.proargtypes[7], p2.proargtypes[7]
236 FROM pg_proc AS p1, pg_proc AS p2
237 WHERE p1.oid != p2.oid AND
238 p1.prosrc = p2.prosrc AND
239 p1.prolang = 12 AND p2.prolang = 12 AND
240 NOT p1.proisagg AND NOT p2.proisagg AND
241 (p1.proargtypes[7] < p2.proargtypes[7])
243 proargtypes | proargtypes
244 -------------+-------------
247 -- Look for functions that return type "internal" and do not have any
248 -- "internal" argument. Such a function would be a security hole since
249 -- it might be used to call an internal function from an SQL command.
250 -- As of 7.3 this query should find only internal_in.
251 SELECT p1.oid, p1.proname
253 WHERE p1.prorettype = 'internal'::regtype AND NOT
254 'internal'::regtype = ANY (p1.proargtypes);
260 -- **************** pg_cast ****************
261 -- Catch bogus values in pg_cast columns (other than cases detected by
265 WHERE castsource = 0 OR casttarget = 0 OR castcontext NOT IN ('e', 'a', 'i')
266 OR castmethod NOT IN ('f', 'b' ,'i');
267 castsource | casttarget | castfunc | castcontext | castmethod
268 ------------+------------+----------+-------------+------------
271 -- Check that castfunc is nonzero only for cast methods that need a function,
272 -- and zero otherwise
275 WHERE (castmethod = 'f' AND castfunc = 0)
276 OR (castmethod IN ('b', 'i') AND castfunc <> 0);
277 castsource | casttarget | castfunc | castcontext | castmethod
278 ------------+------------+----------+-------------+------------
281 -- Look for casts to/from the same type that aren't length coercion functions.
282 -- (We assume they are length coercions if they take multiple arguments.)
283 -- Such entries are not necessarily harmful, but they are useless.
286 WHERE castsource = casttarget AND castfunc = 0;
287 castsource | casttarget | castfunc | castcontext | castmethod
288 ------------+------------+----------+-------------+------------
292 FROM pg_cast c, pg_proc p
293 WHERE c.castfunc = p.oid AND p.pronargs < 2 AND castsource = casttarget;
294 castsource | casttarget | castfunc | castcontext | castmethod
295 ------------+------------+----------+-------------+------------
298 -- Look for cast functions that don't have the right signature. The
299 -- argument and result types in pg_proc must be the same as, or binary
300 -- compatible with, what it says in pg_cast.
301 -- As a special case, we allow casts from CHAR(n) that use functions
302 -- declared to take TEXT. This does not pass the binary-coercibility test
303 -- because CHAR(n)-to-TEXT normally invokes rtrim(). However, the results
304 -- are the same, so long as the function is one that ignores trailing blanks.
306 FROM pg_cast c, pg_proc p
307 WHERE c.castfunc = p.oid AND
308 (p.pronargs < 1 OR p.pronargs > 3
309 OR NOT (binary_coercible(c.castsource, p.proargtypes[0])
310 OR (c.castsource = 'character'::regtype AND
311 p.proargtypes[0] = 'text'::regtype))
312 OR NOT binary_coercible(p.prorettype, c.casttarget));
313 castsource | casttarget | castfunc | castcontext | castmethod
314 ------------+------------+----------+-------------+------------
318 FROM pg_cast c, pg_proc p
319 WHERE c.castfunc = p.oid AND
320 ((p.pronargs > 1 AND p.proargtypes[1] != 'int4'::regtype) OR
321 (p.pronargs > 2 AND p.proargtypes[2] != 'bool'::regtype));
322 castsource | casttarget | castfunc | castcontext | castmethod
323 ------------+------------+----------+-------------+------------
326 -- Look for binary compatible casts that do not have the reverse
327 -- direction registered as well, or where the reverse direction is not
328 -- also binary compatible. This is legal, but usually not intended.
329 -- As of 7.4, this finds the casts from text and varchar to bpchar, because
330 -- those are binary-compatible while the reverse way goes through rtrim().
331 -- As of 8.2, this finds the cast from cidr to inet, because that is a
332 -- trivial binary coercion while the other way goes through inet_to_cidr().
333 -- As of 8.3, this finds the casts from xml to text, varchar, and bpchar,
334 -- because those are binary-compatible while the reverse goes through
335 -- texttoxml(), which does an XML syntax check.
338 WHERE c.castmethod = 'b' AND
339 NOT EXISTS (SELECT 1 FROM pg_cast k
340 WHERE k.castmethod = 'b' AND
341 k.castsource = c.casttarget AND
342 k.casttarget = c.castsource);
343 castsource | casttarget | castfunc | castcontext | castmethod
344 ------------+------------+----------+-------------+------------
345 25 | 1042 | 0 | i | b
346 1043 | 1042 | 0 | i | b
347 650 | 869 | 0 | i | b
349 142 | 1043 | 0 | a | b
350 142 | 1042 | 0 | a | b
353 -- **************** pg_operator ****************
354 -- Look for illegal values in pg_operator fields.
355 SELECT p1.oid, p1.oprname
356 FROM pg_operator as p1
357 WHERE (p1.oprkind != 'b' AND p1.oprkind != 'l' AND p1.oprkind != 'r') OR
358 p1.oprresult = 0 OR p1.oprcode = 0;
363 -- Look for missing or unwanted operand types
364 SELECT p1.oid, p1.oprname
365 FROM pg_operator as p1
366 WHERE (p1.oprleft = 0 and p1.oprkind != 'l') OR
367 (p1.oprleft != 0 and p1.oprkind = 'l') OR
368 (p1.oprright = 0 and p1.oprkind != 'r') OR
369 (p1.oprright != 0 and p1.oprkind = 'r');
374 -- Look for conflicting operator definitions (same names and input datatypes).
375 SELECT p1.oid, p1.oprcode, p2.oid, p2.oprcode
376 FROM pg_operator AS p1, pg_operator AS p2
377 WHERE p1.oid != p2.oid AND
378 p1.oprname = p2.oprname AND
379 p1.oprkind = p2.oprkind AND
380 p1.oprleft = p2.oprleft AND
381 p1.oprright = p2.oprright;
382 oid | oprcode | oid | oprcode
383 -----+---------+-----+---------
386 -- Look for commutative operators that don't commute.
387 -- DEFINITIONAL NOTE: If A.oprcom = B, then x A y has the same result as y B x.
388 -- We expect that B will always say that B.oprcom = A as well; that's not
389 -- inherently essential, but it would be inefficient not to mark it so.
390 SELECT p1.oid, p1.oprcode, p2.oid, p2.oprcode
391 FROM pg_operator AS p1, pg_operator AS p2
392 WHERE p1.oprcom = p2.oid AND
393 (p1.oprkind != 'b' OR
394 p1.oprleft != p2.oprright OR
395 p1.oprright != p2.oprleft OR
396 p1.oprresult != p2.oprresult OR
397 p1.oid != p2.oprcom);
398 oid | oprcode | oid | oprcode
399 -----+---------+-----+---------
402 -- Look for negatory operators that don't agree.
403 -- DEFINITIONAL NOTE: If A.oprnegate = B, then both A and B must yield
404 -- boolean results, and (x A y) == ! (x B y), or the equivalent for
405 -- single-operand operators.
406 -- We expect that B will always say that B.oprnegate = A as well; that's not
407 -- inherently essential, but it would be inefficient not to mark it so.
408 -- Also, A and B had better not be the same operator.
409 SELECT p1.oid, p1.oprcode, p2.oid, p2.oprcode
410 FROM pg_operator AS p1, pg_operator AS p2
411 WHERE p1.oprnegate = p2.oid AND
412 (p1.oprkind != p2.oprkind OR
413 p1.oprleft != p2.oprleft OR
414 p1.oprright != p2.oprright OR
415 p1.oprresult != 'bool'::regtype OR
416 p2.oprresult != 'bool'::regtype OR
417 p1.oid != p2.oprnegate OR
419 oid | oprcode | oid | oprcode
420 -----+---------+-----+---------
423 -- A mergejoinable or hashjoinable operator must be binary, must return
424 -- boolean, and must have a commutator (itself, unless it's a cross-type
426 SELECT p1.oid, p1.oprname FROM pg_operator AS p1
427 WHERE (p1.oprcanmerge OR p1.oprcanhash) AND NOT
428 (p1.oprkind = 'b' AND p1.oprresult = 'bool'::regtype AND p1.oprcom != 0);
433 -- What's more, the commutator had better be mergejoinable/hashjoinable too.
434 SELECT p1.oid, p1.oprname, p2.oid, p2.oprname
435 FROM pg_operator AS p1, pg_operator AS p2
436 WHERE p1.oprcom = p2.oid AND
437 (p1.oprcanmerge != p2.oprcanmerge OR
438 p1.oprcanhash != p2.oprcanhash);
439 oid | oprname | oid | oprname
440 -----+---------+-----+---------
443 -- Mergejoinable operators should appear as equality members of btree index
445 SELECT p1.oid, p1.oprname
446 FROM pg_operator AS p1
447 WHERE p1.oprcanmerge AND NOT EXISTS
448 (SELECT 1 FROM pg_amop
449 WHERE amopmethod = (SELECT oid FROM pg_am WHERE amname = 'btree') AND
450 amopopr = p1.oid AND amopstrategy = 3);
456 SELECT p1.oid, p1.oprname, p.amopfamily
457 FROM pg_operator AS p1, pg_amop p
458 WHERE amopopr = p1.oid
459 AND amopmethod = (SELECT oid FROM pg_am WHERE amname = 'btree')
461 AND NOT p1.oprcanmerge;
462 oid | oprname | amopfamily
463 -----+---------+------------
466 -- Hashable operators should appear as members of hash index opfamilies.
467 SELECT p1.oid, p1.oprname
468 FROM pg_operator AS p1
469 WHERE p1.oprcanhash AND NOT EXISTS
470 (SELECT 1 FROM pg_amop
471 WHERE amopmethod = (SELECT oid FROM pg_am WHERE amname = 'hash') AND
472 amopopr = p1.oid AND amopstrategy = 1);
478 SELECT p1.oid, p1.oprname, p.amopfamily
479 FROM pg_operator AS p1, pg_amop p
480 WHERE amopopr = p1.oid
481 AND amopmethod = (SELECT oid FROM pg_am WHERE amname = 'hash')
482 AND NOT p1.oprcanhash;
483 oid | oprname | amopfamily
484 -----+---------+------------
487 -- Check that each operator defined in pg_operator matches its oprcode entry
488 -- in pg_proc. Easiest to do this separately for each oprkind.
489 SELECT p1.oid, p1.oprname, p2.oid, p2.proname
490 FROM pg_operator AS p1, pg_proc AS p2
491 WHERE p1.oprcode = p2.oid AND
494 OR NOT binary_coercible(p2.prorettype, p1.oprresult)
495 OR NOT binary_coercible(p1.oprleft, p2.proargtypes[0])
496 OR NOT binary_coercible(p1.oprright, p2.proargtypes[1]));
497 oid | oprname | oid | proname
498 -----+---------+-----+---------
501 SELECT p1.oid, p1.oprname, p2.oid, p2.proname
502 FROM pg_operator AS p1, pg_proc AS p2
503 WHERE p1.oprcode = p2.oid AND
506 OR NOT binary_coercible(p2.prorettype, p1.oprresult)
507 OR NOT binary_coercible(p1.oprright, p2.proargtypes[0])
509 oid | oprname | oid | proname
510 -----+---------+-----+---------
513 SELECT p1.oid, p1.oprname, p2.oid, p2.proname
514 FROM pg_operator AS p1, pg_proc AS p2
515 WHERE p1.oprcode = p2.oid AND
518 OR NOT binary_coercible(p2.prorettype, p1.oprresult)
519 OR NOT binary_coercible(p1.oprleft, p2.proargtypes[0])
520 OR p1.oprright != 0);
521 oid | oprname | oid | proname
522 -----+---------+-----+---------
525 -- If the operator is mergejoinable or hashjoinable, its underlying function
526 -- should not be volatile.
527 SELECT p1.oid, p1.oprname, p2.oid, p2.proname
528 FROM pg_operator AS p1, pg_proc AS p2
529 WHERE p1.oprcode = p2.oid AND
530 (p1.oprcanmerge OR p1.oprcanhash) AND
531 p2.provolatile = 'v';
532 oid | oprname | oid | proname
533 -----+---------+-----+---------
536 -- If oprrest is set, the operator must return boolean,
537 -- and it must link to a proc with the right signature
538 -- to be a restriction selectivity estimator.
539 -- The proc signature we want is: float8 proc(internal, oid, internal, int4)
540 SELECT p1.oid, p1.oprname, p2.oid, p2.proname
541 FROM pg_operator AS p1, pg_proc AS p2
542 WHERE p1.oprrest = p2.oid AND
543 (p1.oprresult != 'bool'::regtype OR
544 p2.prorettype != 'float8'::regtype OR p2.proretset OR
546 p2.proargtypes[0] != 'internal'::regtype OR
547 p2.proargtypes[1] != 'oid'::regtype OR
548 p2.proargtypes[2] != 'internal'::regtype OR
549 p2.proargtypes[3] != 'int4'::regtype);
550 oid | oprname | oid | proname
551 -----+---------+-----+---------
554 -- If oprjoin is set, the operator must be a binary boolean op,
555 -- and it must link to a proc with the right signature
556 -- to be a join selectivity estimator.
557 -- The proc signature we want is: float8 proc(internal, oid, internal, int2, internal)
558 -- (Note: the old signature with only 4 args is still allowed, but no core
559 -- estimator should be using it.)
560 SELECT p1.oid, p1.oprname, p2.oid, p2.proname
561 FROM pg_operator AS p1, pg_proc AS p2
562 WHERE p1.oprjoin = p2.oid AND
563 (p1.oprkind != 'b' OR p1.oprresult != 'bool'::regtype OR
564 p2.prorettype != 'float8'::regtype OR p2.proretset OR
566 p2.proargtypes[0] != 'internal'::regtype OR
567 p2.proargtypes[1] != 'oid'::regtype OR
568 p2.proargtypes[2] != 'internal'::regtype OR
569 p2.proargtypes[3] != 'int2'::regtype OR
570 p2.proargtypes[4] != 'internal'::regtype);
571 oid | oprname | oid | proname
572 -----+---------+-----+---------
575 -- **************** pg_aggregate ****************
576 -- Look for illegal values in pg_aggregate fields.
577 SELECT ctid, aggfnoid::oid
578 FROM pg_aggregate as p1
579 WHERE aggfnoid = 0 OR aggtransfn = 0 OR aggtranstype = 0;
584 -- Make sure the matching pg_proc entry is sensible, too.
585 SELECT a.aggfnoid::oid, p.proname
586 FROM pg_aggregate as a, pg_proc as p
587 WHERE a.aggfnoid = p.oid AND
588 (NOT p.proisagg OR p.proretset);
593 -- Make sure there are no proisagg pg_proc entries without matches.
597 NOT EXISTS (SELECT 1 FROM pg_aggregate a WHERE a.aggfnoid = p.oid);
602 -- If there is no finalfn then the output type must be the transtype.
603 SELECT a.aggfnoid::oid, p.proname
604 FROM pg_aggregate as a, pg_proc as p
605 WHERE a.aggfnoid = p.oid AND
606 a.aggfinalfn = 0 AND p.prorettype != a.aggtranstype;
611 -- Cross-check transfn against its entry in pg_proc.
612 -- NOTE: use physically_coercible here, not binary_coercible, because
613 -- max and min on abstime are implemented using int4larger/int4smaller.
614 SELECT a.aggfnoid::oid, p.proname, ptr.oid, ptr.proname
615 FROM pg_aggregate AS a, pg_proc AS p, pg_proc AS ptr
616 WHERE a.aggfnoid = p.oid AND
617 a.aggtransfn = ptr.oid AND
619 OR NOT (ptr.pronargs = p.pronargs + 1)
620 OR NOT physically_coercible(ptr.prorettype, a.aggtranstype)
621 OR NOT physically_coercible(a.aggtranstype, ptr.proargtypes[0])
622 OR (p.pronargs > 0 AND
623 NOT physically_coercible(p.proargtypes[0], ptr.proargtypes[1]))
624 OR (p.pronargs > 1 AND
625 NOT physically_coercible(p.proargtypes[1], ptr.proargtypes[2]))
626 OR (p.pronargs > 2 AND
627 NOT physically_coercible(p.proargtypes[2], ptr.proargtypes[3]))
628 -- we could carry the check further, but that's enough for now
630 aggfnoid | proname | oid | proname
631 ----------+---------+-----+---------
634 -- Cross-check finalfn (if present) against its entry in pg_proc.
635 SELECT a.aggfnoid::oid, p.proname, pfn.oid, pfn.proname
636 FROM pg_aggregate AS a, pg_proc AS p, pg_proc AS pfn
637 WHERE a.aggfnoid = p.oid AND
638 a.aggfinalfn = pfn.oid AND
640 OR NOT binary_coercible(pfn.prorettype, p.prorettype)
642 OR NOT binary_coercible(a.aggtranstype, pfn.proargtypes[0]));
643 aggfnoid | proname | oid | proname
644 ----------+---------+-----+---------
647 -- If transfn is strict then either initval should be non-NULL, or
648 -- input type should match transtype so that the first non-null input
649 -- can be assigned as the state value.
650 SELECT a.aggfnoid::oid, p.proname, ptr.oid, ptr.proname
651 FROM pg_aggregate AS a, pg_proc AS p, pg_proc AS ptr
652 WHERE a.aggfnoid = p.oid AND
653 a.aggtransfn = ptr.oid AND ptr.proisstrict AND
654 a.agginitval IS NULL AND
655 NOT binary_coercible(p.proargtypes[0], a.aggtranstype);
656 aggfnoid | proname | oid | proname
657 ----------+---------+-----+---------
660 -- Cross-check aggsortop (if present) against pg_operator.
661 -- We expect to find only "<" for "min" and ">" for "max".
662 SELECT DISTINCT proname, oprname
663 FROM pg_operator AS o, pg_aggregate AS a, pg_proc AS p
664 WHERE a.aggfnoid = p.oid AND a.aggsortop = o.oid
672 -- Check datatypes match
673 SELECT a.aggfnoid::oid, o.oid
674 FROM pg_operator AS o, pg_aggregate AS a, pg_proc AS p
675 WHERE a.aggfnoid = p.oid AND a.aggsortop = o.oid AND
676 (oprkind != 'b' OR oprresult != 'boolean'::regtype
677 OR oprleft != p.proargtypes[0] OR oprright != p.proargtypes[0]);
682 -- Check operator is a suitable btree opfamily member
683 SELECT a.aggfnoid::oid, o.oid
684 FROM pg_operator AS o, pg_aggregate AS a, pg_proc AS p
685 WHERE a.aggfnoid = p.oid AND a.aggsortop = o.oid AND
686 NOT EXISTS(SELECT 1 FROM pg_amop
687 WHERE amopmethod = (SELECT oid FROM pg_am WHERE amname = 'btree')
689 AND amoplefttype = o.oprleft
690 AND amoprighttype = o.oprright);
695 -- Check correspondence of btree strategies and names
696 SELECT DISTINCT proname, oprname, amopstrategy
697 FROM pg_operator AS o, pg_aggregate AS a, pg_proc AS p,
699 WHERE a.aggfnoid = p.oid AND a.aggsortop = o.oid AND
701 amopmethod = (SELECT oid FROM pg_am WHERE amname = 'btree')
703 proname | oprname | amopstrategy
704 ---------+---------+--------------
709 -- **************** pg_opfamily ****************
710 -- Look for illegal values in pg_opfamily fields
712 FROM pg_opfamily as p1
713 WHERE p1.opfmethod = 0 OR p1.opfnamespace = 0;
718 -- **************** pg_opclass ****************
719 -- Look for illegal values in pg_opclass fields
721 FROM pg_opclass AS p1
722 WHERE p1.opcmethod = 0 OR p1.opcnamespace = 0 OR p1.opcfamily = 0
728 -- opcmethod must match owning opfamily's opfmethod
729 SELECT p1.oid, p2.oid
730 FROM pg_opclass AS p1, pg_opfamily AS p2
731 WHERE p1.opcfamily = p2.oid AND p1.opcmethod != p2.opfmethod;
736 -- There should not be multiple entries in pg_opclass with opcdefault true
737 -- and the same opcmethod/opcintype combination.
738 SELECT p1.oid, p2.oid
739 FROM pg_opclass AS p1, pg_opclass AS p2
740 WHERE p1.oid != p2.oid AND
741 p1.opcmethod = p2.opcmethod AND p1.opcintype = p2.opcintype AND
742 p1.opcdefault AND p2.opcdefault;
747 -- **************** pg_amop ****************
748 -- Look for illegal values in pg_amop fields
749 SELECT p1.amopfamily, p1.amopstrategy
751 WHERE p1.amopfamily = 0 OR p1.amoplefttype = 0 OR p1.amoprighttype = 0
752 OR p1.amopopr = 0 OR p1.amopmethod = 0 OR p1.amopstrategy < 1;
753 amopfamily | amopstrategy
754 ------------+--------------
757 -- amoplefttype/amoprighttype must match the operator
758 SELECT p1.oid, p2.oid
759 FROM pg_amop AS p1, pg_operator AS p2
760 WHERE p1.amopopr = p2.oid AND NOT
761 (p1.amoplefttype = p2.oprleft AND p1.amoprighttype = p2.oprright);
766 -- amopmethod must match owning opfamily's opfmethod
767 SELECT p1.oid, p2.oid
768 FROM pg_amop AS p1, pg_opfamily AS p2
769 WHERE p1.amopfamily = p2.oid AND p1.amopmethod != p2.opfmethod;
774 -- Cross-check amopstrategy index against parent AM
775 SELECT p1.amopfamily, p1.amopopr, p2.oid, p2.amname
776 FROM pg_amop AS p1, pg_am AS p2
777 WHERE p1.amopmethod = p2.oid AND
778 p1.amopstrategy > p2.amstrategies AND p2.amstrategies <> 0;
779 amopfamily | amopopr | oid | amname
780 ------------+---------+-----+--------
783 -- Detect missing pg_amop entries: should have as many strategy operators
784 -- as AM expects for each datatype combination supported by the opfamily.
785 -- We can't check this for AMs with variable strategy sets.
786 SELECT p1.amname, p2.amoplefttype, p2.amoprighttype
787 FROM pg_am AS p1, pg_amop AS p2
788 WHERE p2.amopmethod = p1.oid AND
789 p1.amstrategies <> 0 AND
790 p1.amstrategies != (SELECT count(*) FROM pg_amop AS p3
791 WHERE p3.amopfamily = p2.amopfamily AND
792 p3.amoplefttype = p2.amoplefttype AND
793 p3.amoprighttype = p2.amoprighttype);
794 amname | amoplefttype | amoprighttype
795 --------+--------------+---------------
798 -- Check that amopopr points at a reasonable-looking operator, ie a binary
799 -- operator yielding boolean.
800 SELECT p1.amopfamily, p1.amopopr, p2.oid, p2.oprname
801 FROM pg_amop AS p1, pg_operator AS p2
802 WHERE p1.amopopr = p2.oid AND
803 (p2.oprkind != 'b' OR p2.oprresult != 'bool'::regtype);
804 amopfamily | amopopr | oid | oprname
805 ------------+---------+-----+---------
808 -- Make a list of all the distinct operator names being used in particular
809 -- strategy slots. This is a bit hokey, since the list might need to change
810 -- in future releases, but it's an effective way of spotting mistakes such as
811 -- swapping two operators within a family.
812 SELECT DISTINCT amopmethod, amopstrategy, oprname
813 FROM pg_amop p1 LEFT JOIN pg_operator p2 ON amopopr = p2.oid
815 amopmethod | amopstrategy | oprname
816 ------------+--------------+---------
850 -- Check that all operators linked to by opclass entries have selectivity
851 -- estimators. This is not absolutely required, but it seems a reasonable
852 -- thing to insist on for all standard datatypes.
853 SELECT p1.amopfamily, p1.amopopr, p2.oid, p2.oprname
854 FROM pg_amop AS p1, pg_operator AS p2
855 WHERE p1.amopopr = p2.oid AND
856 (p2.oprrest = 0 OR p2.oprjoin = 0);
857 amopfamily | amopopr | oid | oprname
858 ------------+---------+-----+---------
861 -- Check that each opclass in an opfamily has associated operators, that is
862 -- ones whose oprleft matches opcintype (possibly by coercion).
863 SELECT p1.opcname, p1.opcfamily
864 FROM pg_opclass AS p1
865 WHERE NOT EXISTS(SELECT 1 FROM pg_amop AS p2
866 WHERE p2.amopfamily = p1.opcfamily
867 AND binary_coercible(p1.opcintype, p2.amoplefttype));
869 ---------+-----------
872 -- Operators that are primary members of opclasses must be immutable (else
873 -- it suggests that the index ordering isn't fixed). Operators that are
874 -- cross-type members need only be stable, since they are just shorthands
875 -- for index probe queries.
876 SELECT p1.amopfamily, p1.amopopr, p2.oprname, p3.prosrc
877 FROM pg_amop AS p1, pg_operator AS p2, pg_proc AS p3
878 WHERE p1.amopopr = p2.oid AND p2.oprcode = p3.oid AND
879 p1.amoplefttype = p1.amoprighttype AND
880 p3.provolatile != 'i';
881 amopfamily | amopopr | oprname | prosrc
882 ------------+---------+---------+--------
885 SELECT p1.amopfamily, p1.amopopr, p2.oprname, p3.prosrc
886 FROM pg_amop AS p1, pg_operator AS p2, pg_proc AS p3
887 WHERE p1.amopopr = p2.oid AND p2.oprcode = p3.oid AND
888 p1.amoplefttype != p1.amoprighttype AND
889 p3.provolatile = 'v';
890 amopfamily | amopopr | oprname | prosrc
891 ------------+---------+---------+--------
894 -- Multiple-datatype btree opfamilies should provide closed sets of equality
895 -- operators; that is if you provide int2 = int4 and int4 = int8 then you
896 -- should also provide int2 = int8 (and commutators of all these). This is
897 -- important because the planner tries to deduce additional qual clauses from
898 -- transitivity of mergejoinable operators. If there are clauses
899 -- int2var = int4var and int4var = int8var, the planner will want to deduce
900 -- int2var = int8var ... so there should be a way to represent that. While
901 -- a missing cross-type operator is now only an efficiency loss rather than
902 -- an error condition, it still seems reasonable to insist that all built-in
903 -- opfamilies be complete.
904 -- check commutative closure
905 SELECT p1.amoplefttype, p1.amoprighttype
907 WHERE p1.amopmethod = (SELECT oid FROM pg_am WHERE amname = 'btree') AND
908 p1.amopstrategy = 3 AND
909 p1.amoplefttype != p1.amoprighttype AND
910 NOT EXISTS(SELECT 1 FROM pg_amop p2 WHERE
911 p2.amopfamily = p1.amopfamily AND
912 p2.amoplefttype = p1.amoprighttype AND
913 p2.amoprighttype = p1.amoplefttype AND
914 p2.amopstrategy = 3);
915 amoplefttype | amoprighttype
916 --------------+---------------
919 -- check transitive closure
920 SELECT p1.amoplefttype, p1.amoprighttype, p2.amoprighttype
921 FROM pg_amop AS p1, pg_amop AS p2
922 WHERE p1.amopfamily = p2.amopfamily AND
923 p1.amoprighttype = p2.amoplefttype AND
924 p1.amopmethod = (SELECT oid FROM pg_am WHERE amname = 'btree') AND
925 p2.amopmethod = (SELECT oid FROM pg_am WHERE amname = 'btree') AND
926 p1.amopstrategy = 3 AND p2.amopstrategy = 3 AND
927 p1.amoplefttype != p1.amoprighttype AND
928 p2.amoplefttype != p2.amoprighttype AND
929 NOT EXISTS(SELECT 1 FROM pg_amop p3 WHERE
930 p3.amopfamily = p1.amopfamily AND
931 p3.amoplefttype = p1.amoplefttype AND
932 p3.amoprighttype = p2.amoprighttype AND
933 p3.amopstrategy = 3);
934 amoplefttype | amoprighttype | amoprighttype
935 --------------+---------------+---------------
938 -- We also expect that built-in multiple-datatype hash opfamilies provide
939 -- complete sets of cross-type operators. Again, this isn't required, but
940 -- it is reasonable to expect it for built-in opfamilies.
941 -- if same family has x=x and y=y, it should have x=y
942 SELECT p1.amoplefttype, p2.amoplefttype
943 FROM pg_amop AS p1, pg_amop AS p2
944 WHERE p1.amopfamily = p2.amopfamily AND
945 p1.amoplefttype = p1.amoprighttype AND
946 p2.amoplefttype = p2.amoprighttype AND
947 p1.amopmethod = (SELECT oid FROM pg_am WHERE amname = 'hash') AND
948 p2.amopmethod = (SELECT oid FROM pg_am WHERE amname = 'hash') AND
949 p1.amopstrategy = 1 AND p2.amopstrategy = 1 AND
950 p1.amoplefttype != p2.amoplefttype AND
951 NOT EXISTS(SELECT 1 FROM pg_amop p3 WHERE
952 p3.amopfamily = p1.amopfamily AND
953 p3.amoplefttype = p1.amoplefttype AND
954 p3.amoprighttype = p2.amoplefttype AND
955 p3.amopstrategy = 1);
956 amoplefttype | amoplefttype
957 --------------+--------------
960 -- **************** pg_amproc ****************
961 -- Look for illegal values in pg_amproc fields
962 SELECT p1.amprocfamily, p1.amprocnum
964 WHERE p1.amprocfamily = 0 OR p1.amproclefttype = 0 OR p1.amprocrighttype = 0
965 OR p1.amprocnum < 1 OR p1.amproc = 0;
966 amprocfamily | amprocnum
967 --------------+-----------
970 -- Cross-check amprocnum index against parent AM
971 SELECT p1.amprocfamily, p1.amprocnum, p2.oid, p2.amname
972 FROM pg_amproc AS p1, pg_am AS p2, pg_opfamily AS p3
973 WHERE p1.amprocfamily = p3.oid AND p3.opfmethod = p2.oid AND
974 p1.amprocnum > p2.amsupport;
975 amprocfamily | amprocnum | oid | amname
976 --------------+-----------+-----+--------
979 -- Detect missing pg_amproc entries: should have as many support functions
980 -- as AM expects for each datatype combination supported by the opfamily.
981 -- GIN is a special case because it has an optional support function.
982 SELECT p1.amname, p2.opfname, p3.amproclefttype, p3.amprocrighttype
983 FROM pg_am AS p1, pg_opfamily AS p2, pg_amproc AS p3
984 WHERE p2.opfmethod = p1.oid AND p3.amprocfamily = p2.oid AND
985 p1.amname <> 'gin' AND
986 p1.amsupport != (SELECT count(*) FROM pg_amproc AS p4
987 WHERE p4.amprocfamily = p2.oid AND
988 p4.amproclefttype = p3.amproclefttype AND
989 p4.amprocrighttype = p3.amprocrighttype);
990 amname | opfname | amproclefttype | amprocrighttype
991 --------+---------+----------------+-----------------
994 -- Similar check for GIN, allowing one optional proc
995 SELECT p1.amname, p2.opfname, p3.amproclefttype, p3.amprocrighttype
996 FROM pg_am AS p1, pg_opfamily AS p2, pg_amproc AS p3
997 WHERE p2.opfmethod = p1.oid AND p3.amprocfamily = p2.oid AND
998 p1.amname = 'gin' AND
999 p1.amsupport - 1 > (SELECT count(*) FROM pg_amproc AS p4
1000 WHERE p4.amprocfamily = p2.oid AND
1001 p4.amproclefttype = p3.amproclefttype AND
1002 p4.amprocrighttype = p3.amprocrighttype);
1003 amname | opfname | amproclefttype | amprocrighttype
1004 --------+---------+----------------+-----------------
1007 -- Also, check if there are any pg_opclass entries that don't seem to have
1008 -- pg_amproc support. Again, GIN has to be checked separately.
1009 SELECT amname, opcname, count(*)
1010 FROM pg_am am JOIN pg_opclass op ON opcmethod = am.oid
1011 LEFT JOIN pg_amproc p ON amprocfamily = opcfamily AND
1012 amproclefttype = amprocrighttype AND amproclefttype = opcintype
1013 WHERE am.amname <> 'gin'
1014 GROUP BY amname, amsupport, opcname, amprocfamily
1015 HAVING count(*) != amsupport OR amprocfamily IS NULL;
1016 amname | opcname | count
1017 --------+---------+-------
1020 SELECT amname, opcname, count(*)
1021 FROM pg_am am JOIN pg_opclass op ON opcmethod = am.oid
1022 LEFT JOIN pg_amproc p ON amprocfamily = opcfamily AND
1023 amproclefttype = amprocrighttype AND amproclefttype = opcintype
1024 WHERE am.amname = 'gin'
1025 GROUP BY amname, amsupport, opcname, amprocfamily
1026 HAVING count(*) < amsupport - 1 OR amprocfamily IS NULL;
1027 amname | opcname | count
1028 --------+---------+-------
1031 -- Unfortunately, we can't check the amproc link very well because the
1032 -- signature of the function may be different for different support routines
1033 -- or different base data types.
1034 -- We can check that all the referenced instances of the same support
1035 -- routine number take the same number of parameters, but that's about it
1036 -- for a general check...
1037 SELECT p1.amprocfamily, p1.amprocnum,
1040 p4.amprocfamily, p4.amprocnum,
1043 FROM pg_amproc AS p1, pg_proc AS p2, pg_opfamily AS p3,
1044 pg_amproc AS p4, pg_proc AS p5, pg_opfamily AS p6
1045 WHERE p1.amprocfamily = p3.oid AND p4.amprocfamily = p6.oid AND
1046 p3.opfmethod = p6.opfmethod AND p1.amprocnum = p4.amprocnum AND
1047 p1.amproc = p2.oid AND p4.amproc = p5.oid AND
1048 (p2.proretset OR p5.proretset OR p2.pronargs != p5.pronargs);
1049 amprocfamily | amprocnum | oid | proname | opfname | amprocfamily | amprocnum | oid | proname | opfname
1050 --------------+-----------+-----+---------+---------+--------------+-----------+-----+---------+---------
1053 -- For btree, though, we can do better since we know the support routines
1054 -- must be of the form cmp(lefttype, righttype) returns int4.
1055 SELECT p1.amprocfamily, p1.amprocnum,
1058 FROM pg_amproc AS p1, pg_proc AS p2, pg_opfamily AS p3
1059 WHERE p3.opfmethod = (SELECT oid FROM pg_am WHERE amname = 'btree')
1060 AND p1.amprocfamily = p3.oid AND p1.amproc = p2.oid AND
1063 OR prorettype != 'int4'::regtype
1065 OR proargtypes[0] != amproclefttype
1066 OR proargtypes[1] != amprocrighttype);
1067 amprocfamily | amprocnum | oid | proname | opfname
1068 --------------+-----------+-----+---------+---------
1071 -- For hash we can also do a little better: the support routines must be
1072 -- of the form hash(lefttype) returns int4. There are several cases where
1073 -- we cheat and use a hash function that is physically compatible with the
1074 -- datatype even though there's no cast, so this check does find a small
1075 -- number of entries.
1076 SELECT p1.amprocfamily, p1.amprocnum, p2.proname, p3.opfname
1077 FROM pg_amproc AS p1, pg_proc AS p2, pg_opfamily AS p3
1078 WHERE p3.opfmethod = (SELECT oid FROM pg_am WHERE amname = 'hash')
1079 AND p1.amprocfamily = p3.oid AND p1.amproc = p2.oid AND
1082 OR prorettype != 'int4'::regtype
1084 OR NOT physically_coercible(amproclefttype, proargtypes[0])
1085 OR amproclefttype != amprocrighttype)
1087 amprocfamily | amprocnum | proname | opfname
1088 --------------+-----------+----------------+-----------------
1089 435 | 1 | hashint4 | date_ops
1090 1999 | 1 | timestamp_hash | timestamptz_ops
1091 2222 | 1 | hashchar | bool_ops
1092 2223 | 1 | hashvarlena | bytea_ops
1093 2225 | 1 | hashint4 | xid_ops
1094 2226 | 1 | hashint4 | cid_ops
1097 -- Support routines that are primary members of opfamilies must be immutable
1098 -- (else it suggests that the index ordering isn't fixed). But cross-type
1099 -- members need only be stable, since they are just shorthands
1100 -- for index probe queries.
1101 SELECT p1.amprocfamily, p1.amproc, p2.prosrc
1102 FROM pg_amproc AS p1, pg_proc AS p2
1103 WHERE p1.amproc = p2.oid AND
1104 p1.amproclefttype = p1.amprocrighttype AND
1105 p2.provolatile != 'i';
1106 amprocfamily | amproc | prosrc
1107 --------------+--------+--------
1110 SELECT p1.amprocfamily, p1.amproc, p2.prosrc
1111 FROM pg_amproc AS p1, pg_proc AS p2
1112 WHERE p1.amproc = p2.oid AND
1113 p1.amproclefttype != p1.amprocrighttype AND
1114 p2.provolatile = 'v';
1115 amprocfamily | amproc | prosrc
1116 --------------+--------+--------