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 p1.pronargdefaults < 0 OR
48 p1.pronargdefaults > p1.pronargs OR
49 array_lower(p1.proargtypes, 1) != 0 OR
50 array_upper(p1.proargtypes, 1) != p1.pronargs-1 OR
51 0::oid = ANY (p1.proargtypes) OR
53 CASE WHEN proretset THEN prorows <= 0 ELSE prorows != 0 END;
58 -- prosrc should never be null or empty
59 SELECT p1.oid, p1.proname
61 WHERE prosrc IS NULL OR prosrc = '' OR prosrc = '-';
66 -- proiswindow shouldn't be set together with proisagg or proretset
67 SELECT p1.oid, p1.proname
69 WHERE proiswindow AND (proisagg OR proretset);
74 -- pronargdefaults should be 0 iff proargdefaults is null
75 SELECT p1.oid, p1.proname
77 WHERE (pronargdefaults <> 0) != (proargdefaults IS NOT NULL);
82 -- probin should be non-empty for C functions, null everywhere else
83 SELECT p1.oid, p1.proname
85 WHERE prolang = 13 AND (probin IS NULL OR probin = '' OR probin = '-');
90 SELECT p1.oid, p1.proname
92 WHERE prolang != 13 AND probin IS NOT NULL;
97 -- Look for conflicting proc definitions (same names and input datatypes).
98 -- (This test should be dead code now that we have the unique index
99 -- pg_proc_proname_args_nsp_index, but I'll leave it in anyway.)
100 SELECT p1.oid, p1.proname, p2.oid, p2.proname
101 FROM pg_proc AS p1, pg_proc AS p2
102 WHERE p1.oid != p2.oid AND
103 p1.proname = p2.proname AND
104 p1.pronargs = p2.pronargs AND
105 p1.proargtypes = p2.proargtypes;
106 oid | proname | oid | proname
107 -----+---------+-----+---------
110 -- Considering only built-in procs (prolang = 12), look for multiple uses
111 -- of the same internal function (ie, matching prosrc fields). It's OK to
112 -- have several entries with different pronames for the same internal function,
113 -- but conflicts in the number of arguments and other critical items should
114 -- be complained of. (We don't check data types here; see next query.)
115 -- Note: ignore aggregate functions here, since they all point to the same
116 -- dummy built-in function.
117 SELECT p1.oid, p1.proname, p2.oid, p2.proname
118 FROM pg_proc AS p1, pg_proc AS p2
119 WHERE p1.oid < p2.oid AND
120 p1.prosrc = p2.prosrc AND
121 p1.prolang = 12 AND p2.prolang = 12 AND
122 (p1.proisagg = false OR p2.proisagg = false) AND
123 (p1.prolang != p2.prolang OR
124 p1.proisagg != p2.proisagg OR
125 p1.prosecdef != p2.prosecdef OR
126 p1.proisstrict != p2.proisstrict OR
127 p1.proretset != p2.proretset OR
128 p1.provolatile != p2.provolatile OR
129 p1.pronargs != p2.pronargs);
130 oid | proname | oid | proname
131 -----+---------+-----+---------
134 -- Look for uses of different type OIDs in the argument/result type fields
135 -- for different aliases of the same built-in function.
136 -- This indicates that the types are being presumed to be binary-equivalent,
137 -- or that the built-in function is prepared to deal with different types.
138 -- That's not wrong, necessarily, but we make lists of all the types being
139 -- so treated. Note that the expected output of this part of the test will
140 -- need to be modified whenever new pairs of types are made binary-equivalent,
141 -- or when new polymorphic built-in functions are added!
142 -- Note: ignore aggregate functions here, since they all point to the same
143 -- dummy built-in function.
144 SELECT DISTINCT p1.prorettype, p2.prorettype
145 FROM pg_proc AS p1, pg_proc AS p2
146 WHERE p1.oid != p2.oid AND
147 p1.prosrc = p2.prosrc AND
148 p1.prolang = 12 AND p2.prolang = 12 AND
149 NOT p1.proisagg AND NOT p2.proisagg AND
150 (p1.prorettype < p2.prorettype)
152 prorettype | prorettype
153 ------------+------------
158 SELECT DISTINCT p1.proargtypes[0], p2.proargtypes[0]
159 FROM pg_proc AS p1, pg_proc AS p2
160 WHERE p1.oid != p2.oid AND
161 p1.prosrc = p2.prosrc AND
162 p1.prolang = 12 AND p2.prolang = 12 AND
163 NOT p1.proisagg AND NOT p2.proisagg AND
164 (p1.proargtypes[0] < p2.proargtypes[0])
166 proargtypes | proargtypes
167 -------------+-------------
175 SELECT DISTINCT p1.proargtypes[1], p2.proargtypes[1]
176 FROM pg_proc AS p1, pg_proc AS p2
177 WHERE p1.oid != p2.oid AND
178 p1.prosrc = p2.prosrc AND
179 p1.prolang = 12 AND p2.prolang = 12 AND
180 NOT p1.proisagg AND NOT p2.proisagg AND
181 (p1.proargtypes[1] < p2.proargtypes[1])
183 proargtypes | proargtypes
184 -------------+-------------
191 SELECT DISTINCT p1.proargtypes[2], p2.proargtypes[2]
192 FROM pg_proc AS p1, pg_proc AS p2
193 WHERE p1.oid != p2.oid AND
194 p1.prosrc = p2.prosrc AND
195 p1.prolang = 12 AND p2.prolang = 12 AND
196 NOT p1.proisagg AND NOT p2.proisagg AND
197 (p1.proargtypes[2] < p2.proargtypes[2])
199 proargtypes | proargtypes
200 -------------+-------------
204 SELECT DISTINCT p1.proargtypes[3], p2.proargtypes[3]
205 FROM pg_proc AS p1, pg_proc AS p2
206 WHERE p1.oid != p2.oid AND
207 p1.prosrc = p2.prosrc AND
208 p1.prolang = 12 AND p2.prolang = 12 AND
209 NOT p1.proisagg AND NOT p2.proisagg AND
210 (p1.proargtypes[3] < p2.proargtypes[3])
212 proargtypes | proargtypes
213 -------------+-------------
217 SELECT DISTINCT p1.proargtypes[4], p2.proargtypes[4]
218 FROM pg_proc AS p1, pg_proc AS p2
219 WHERE p1.oid != p2.oid AND
220 p1.prosrc = p2.prosrc AND
221 p1.prolang = 12 AND p2.prolang = 12 AND
222 NOT p1.proisagg AND NOT p2.proisagg AND
223 (p1.proargtypes[4] < p2.proargtypes[4])
225 proargtypes | proargtypes
226 -------------+-------------
229 SELECT DISTINCT p1.proargtypes[5], p2.proargtypes[5]
230 FROM pg_proc AS p1, pg_proc AS p2
231 WHERE p1.oid != p2.oid AND
232 p1.prosrc = p2.prosrc AND
233 p1.prolang = 12 AND p2.prolang = 12 AND
234 NOT p1.proisagg AND NOT p2.proisagg AND
235 (p1.proargtypes[5] < p2.proargtypes[5])
237 proargtypes | proargtypes
238 -------------+-------------
241 SELECT DISTINCT p1.proargtypes[6], p2.proargtypes[6]
242 FROM pg_proc AS p1, pg_proc AS p2
243 WHERE p1.oid != p2.oid AND
244 p1.prosrc = p2.prosrc AND
245 p1.prolang = 12 AND p2.prolang = 12 AND
246 NOT p1.proisagg AND NOT p2.proisagg AND
247 (p1.proargtypes[6] < p2.proargtypes[6])
249 proargtypes | proargtypes
250 -------------+-------------
253 SELECT DISTINCT p1.proargtypes[7], p2.proargtypes[7]
254 FROM pg_proc AS p1, pg_proc AS p2
255 WHERE p1.oid != p2.oid AND
256 p1.prosrc = p2.prosrc AND
257 p1.prolang = 12 AND p2.prolang = 12 AND
258 NOT p1.proisagg AND NOT p2.proisagg AND
259 (p1.proargtypes[7] < p2.proargtypes[7])
261 proargtypes | proargtypes
262 -------------+-------------
265 -- Look for functions that return type "internal" and do not have any
266 -- "internal" argument. Such a function would be a security hole since
267 -- it might be used to call an internal function from an SQL command.
268 -- As of 7.3 this query should find only internal_in.
269 SELECT p1.oid, p1.proname
271 WHERE p1.prorettype = 'internal'::regtype AND NOT
272 'internal'::regtype = ANY (p1.proargtypes);
278 -- **************** pg_cast ****************
279 -- Catch bogus values in pg_cast columns (other than cases detected by
283 WHERE castsource = 0 OR casttarget = 0 OR castcontext NOT IN ('e', 'a', 'i')
284 OR castmethod NOT IN ('f', 'b' ,'i');
285 castsource | casttarget | castfunc | castcontext | castmethod
286 ------------+------------+----------+-------------+------------
289 -- Check that castfunc is nonzero only for cast methods that need a function,
290 -- and zero otherwise
293 WHERE (castmethod = 'f' AND castfunc = 0)
294 OR (castmethod IN ('b', 'i') AND castfunc <> 0);
295 castsource | casttarget | castfunc | castcontext | castmethod
296 ------------+------------+----------+-------------+------------
299 -- Look for casts to/from the same type that aren't length coercion functions.
300 -- (We assume they are length coercions if they take multiple arguments.)
301 -- Such entries are not necessarily harmful, but they are useless.
304 WHERE castsource = casttarget AND castfunc = 0;
305 castsource | casttarget | castfunc | castcontext | castmethod
306 ------------+------------+----------+-------------+------------
310 FROM pg_cast c, pg_proc p
311 WHERE c.castfunc = p.oid AND p.pronargs < 2 AND castsource = casttarget;
312 castsource | casttarget | castfunc | castcontext | castmethod
313 ------------+------------+----------+-------------+------------
316 -- Look for cast functions that don't have the right signature. The
317 -- argument and result types in pg_proc must be the same as, or binary
318 -- compatible with, what it says in pg_cast.
319 -- As a special case, we allow casts from CHAR(n) that use functions
320 -- declared to take TEXT. This does not pass the binary-coercibility test
321 -- because CHAR(n)-to-TEXT normally invokes rtrim(). However, the results
322 -- are the same, so long as the function is one that ignores trailing blanks.
324 FROM pg_cast c, pg_proc p
325 WHERE c.castfunc = p.oid AND
326 (p.pronargs < 1 OR p.pronargs > 3
327 OR NOT (binary_coercible(c.castsource, p.proargtypes[0])
328 OR (c.castsource = 'character'::regtype AND
329 p.proargtypes[0] = 'text'::regtype))
330 OR NOT binary_coercible(p.prorettype, c.casttarget));
331 castsource | casttarget | castfunc | castcontext | castmethod
332 ------------+------------+----------+-------------+------------
336 FROM pg_cast c, pg_proc p
337 WHERE c.castfunc = p.oid AND
338 ((p.pronargs > 1 AND p.proargtypes[1] != 'int4'::regtype) OR
339 (p.pronargs > 2 AND p.proargtypes[2] != 'bool'::regtype));
340 castsource | casttarget | castfunc | castcontext | castmethod
341 ------------+------------+----------+-------------+------------
344 -- Look for binary compatible casts that do not have the reverse
345 -- direction registered as well, or where the reverse direction is not
346 -- also binary compatible. This is legal, but usually not intended.
347 -- As of 7.4, this finds the casts from text and varchar to bpchar, because
348 -- those are binary-compatible while the reverse way goes through rtrim().
349 -- As of 8.2, this finds the cast from cidr to inet, because that is a
350 -- trivial binary coercion while the other way goes through inet_to_cidr().
351 -- As of 8.3, this finds the casts from xml to text, varchar, and bpchar,
352 -- because those are binary-compatible while the reverse goes through
353 -- texttoxml(), which does an XML syntax check.
356 WHERE c.castmethod = 'b' AND
357 NOT EXISTS (SELECT 1 FROM pg_cast k
358 WHERE k.castmethod = 'b' AND
359 k.castsource = c.casttarget AND
360 k.casttarget = c.castsource);
361 castsource | casttarget | castfunc | castcontext | castmethod
362 ------------+------------+----------+-------------+------------
363 25 | 1042 | 0 | i | b
364 1043 | 1042 | 0 | i | b
365 650 | 869 | 0 | i | b
367 142 | 1043 | 0 | a | b
368 142 | 1042 | 0 | a | b
371 -- **************** pg_operator ****************
372 -- Look for illegal values in pg_operator fields.
373 SELECT p1.oid, p1.oprname
374 FROM pg_operator as p1
375 WHERE (p1.oprkind != 'b' AND p1.oprkind != 'l' AND p1.oprkind != 'r') OR
376 p1.oprresult = 0 OR p1.oprcode = 0;
381 -- Look for missing or unwanted operand types
382 SELECT p1.oid, p1.oprname
383 FROM pg_operator as p1
384 WHERE (p1.oprleft = 0 and p1.oprkind != 'l') OR
385 (p1.oprleft != 0 and p1.oprkind = 'l') OR
386 (p1.oprright = 0 and p1.oprkind != 'r') OR
387 (p1.oprright != 0 and p1.oprkind = 'r');
392 -- Look for conflicting operator definitions (same names and input datatypes).
393 SELECT p1.oid, p1.oprcode, p2.oid, p2.oprcode
394 FROM pg_operator AS p1, pg_operator AS p2
395 WHERE p1.oid != p2.oid AND
396 p1.oprname = p2.oprname AND
397 p1.oprkind = p2.oprkind AND
398 p1.oprleft = p2.oprleft AND
399 p1.oprright = p2.oprright;
400 oid | oprcode | oid | oprcode
401 -----+---------+-----+---------
404 -- Look for commutative operators that don't commute.
405 -- DEFINITIONAL NOTE: If A.oprcom = B, then x A y has the same result as y B x.
406 -- We expect that B will always say that B.oprcom = A as well; that's not
407 -- inherently essential, but it would be inefficient not to mark it so.
408 SELECT p1.oid, p1.oprcode, p2.oid, p2.oprcode
409 FROM pg_operator AS p1, pg_operator AS p2
410 WHERE p1.oprcom = p2.oid AND
411 (p1.oprkind != 'b' OR
412 p1.oprleft != p2.oprright OR
413 p1.oprright != p2.oprleft OR
414 p1.oprresult != p2.oprresult OR
415 p1.oid != p2.oprcom);
416 oid | oprcode | oid | oprcode
417 -----+---------+-----+---------
420 -- Look for negatory operators that don't agree.
421 -- DEFINITIONAL NOTE: If A.oprnegate = B, then both A and B must yield
422 -- boolean results, and (x A y) == ! (x B y), or the equivalent for
423 -- single-operand operators.
424 -- We expect that B will always say that B.oprnegate = A as well; that's not
425 -- inherently essential, but it would be inefficient not to mark it so.
426 -- Also, A and B had better not be the same operator.
427 SELECT p1.oid, p1.oprcode, p2.oid, p2.oprcode
428 FROM pg_operator AS p1, pg_operator AS p2
429 WHERE p1.oprnegate = p2.oid AND
430 (p1.oprkind != p2.oprkind OR
431 p1.oprleft != p2.oprleft OR
432 p1.oprright != p2.oprright OR
433 p1.oprresult != 'bool'::regtype OR
434 p2.oprresult != 'bool'::regtype OR
435 p1.oid != p2.oprnegate OR
437 oid | oprcode | oid | oprcode
438 -----+---------+-----+---------
441 -- A mergejoinable or hashjoinable operator must be binary, must return
442 -- boolean, and must have a commutator (itself, unless it's a cross-type
444 SELECT p1.oid, p1.oprname FROM pg_operator AS p1
445 WHERE (p1.oprcanmerge OR p1.oprcanhash) AND NOT
446 (p1.oprkind = 'b' AND p1.oprresult = 'bool'::regtype AND p1.oprcom != 0);
451 -- What's more, the commutator had better be mergejoinable/hashjoinable too.
452 SELECT p1.oid, p1.oprname, p2.oid, p2.oprname
453 FROM pg_operator AS p1, pg_operator AS p2
454 WHERE p1.oprcom = p2.oid AND
455 (p1.oprcanmerge != p2.oprcanmerge OR
456 p1.oprcanhash != p2.oprcanhash);
457 oid | oprname | oid | oprname
458 -----+---------+-----+---------
461 -- Mergejoinable operators should appear as equality members of btree index
463 SELECT p1.oid, p1.oprname
464 FROM pg_operator AS p1
465 WHERE p1.oprcanmerge AND NOT EXISTS
466 (SELECT 1 FROM pg_amop
467 WHERE amopmethod = (SELECT oid FROM pg_am WHERE amname = 'btree') AND
468 amopopr = p1.oid AND amopstrategy = 3);
474 SELECT p1.oid, p1.oprname, p.amopfamily
475 FROM pg_operator AS p1, pg_amop p
476 WHERE amopopr = p1.oid
477 AND amopmethod = (SELECT oid FROM pg_am WHERE amname = 'btree')
479 AND NOT p1.oprcanmerge;
480 oid | oprname | amopfamily
481 -----+---------+------------
484 -- Hashable operators should appear as members of hash index opfamilies.
485 SELECT p1.oid, p1.oprname
486 FROM pg_operator AS p1
487 WHERE p1.oprcanhash AND NOT EXISTS
488 (SELECT 1 FROM pg_amop
489 WHERE amopmethod = (SELECT oid FROM pg_am WHERE amname = 'hash') AND
490 amopopr = p1.oid AND amopstrategy = 1);
496 SELECT p1.oid, p1.oprname, p.amopfamily
497 FROM pg_operator AS p1, pg_amop p
498 WHERE amopopr = p1.oid
499 AND amopmethod = (SELECT oid FROM pg_am WHERE amname = 'hash')
500 AND NOT p1.oprcanhash;
501 oid | oprname | amopfamily
502 -----+---------+------------
505 -- Check that each operator defined in pg_operator matches its oprcode entry
506 -- in pg_proc. Easiest to do this separately for each oprkind.
507 SELECT p1.oid, p1.oprname, p2.oid, p2.proname
508 FROM pg_operator AS p1, pg_proc AS p2
509 WHERE p1.oprcode = p2.oid AND
512 OR NOT binary_coercible(p2.prorettype, p1.oprresult)
513 OR NOT binary_coercible(p1.oprleft, p2.proargtypes[0])
514 OR NOT binary_coercible(p1.oprright, p2.proargtypes[1]));
515 oid | oprname | oid | proname
516 -----+---------+-----+---------
519 SELECT p1.oid, p1.oprname, p2.oid, p2.proname
520 FROM pg_operator AS p1, pg_proc AS p2
521 WHERE p1.oprcode = p2.oid AND
524 OR NOT binary_coercible(p2.prorettype, p1.oprresult)
525 OR NOT binary_coercible(p1.oprright, p2.proargtypes[0])
527 oid | oprname | oid | proname
528 -----+---------+-----+---------
531 SELECT p1.oid, p1.oprname, p2.oid, p2.proname
532 FROM pg_operator AS p1, pg_proc AS p2
533 WHERE p1.oprcode = p2.oid AND
536 OR NOT binary_coercible(p2.prorettype, p1.oprresult)
537 OR NOT binary_coercible(p1.oprleft, p2.proargtypes[0])
538 OR p1.oprright != 0);
539 oid | oprname | oid | proname
540 -----+---------+-----+---------
543 -- If the operator is mergejoinable or hashjoinable, its underlying function
544 -- should not be volatile.
545 SELECT p1.oid, p1.oprname, p2.oid, p2.proname
546 FROM pg_operator AS p1, pg_proc AS p2
547 WHERE p1.oprcode = p2.oid AND
548 (p1.oprcanmerge OR p1.oprcanhash) AND
549 p2.provolatile = 'v';
550 oid | oprname | oid | proname
551 -----+---------+-----+---------
554 -- If oprrest is set, the operator must return boolean,
555 -- and it must link to a proc with the right signature
556 -- to be a restriction selectivity estimator.
557 -- The proc signature we want is: float8 proc(internal, oid, internal, int4)
558 SELECT p1.oid, p1.oprname, p2.oid, p2.proname
559 FROM pg_operator AS p1, pg_proc AS p2
560 WHERE p1.oprrest = p2.oid AND
561 (p1.oprresult != 'bool'::regtype OR
562 p2.prorettype != 'float8'::regtype OR p2.proretset OR
564 p2.proargtypes[0] != 'internal'::regtype OR
565 p2.proargtypes[1] != 'oid'::regtype OR
566 p2.proargtypes[2] != 'internal'::regtype OR
567 p2.proargtypes[3] != 'int4'::regtype);
568 oid | oprname | oid | proname
569 -----+---------+-----+---------
572 -- If oprjoin is set, the operator must be a binary boolean op,
573 -- and it must link to a proc with the right signature
574 -- to be a join selectivity estimator.
575 -- The proc signature we want is: float8 proc(internal, oid, internal, int2, internal)
576 -- (Note: the old signature with only 4 args is still allowed, but no core
577 -- estimator should be using it.)
578 SELECT p1.oid, p1.oprname, p2.oid, p2.proname
579 FROM pg_operator AS p1, pg_proc AS p2
580 WHERE p1.oprjoin = p2.oid AND
581 (p1.oprkind != 'b' OR p1.oprresult != 'bool'::regtype OR
582 p2.prorettype != 'float8'::regtype OR p2.proretset OR
584 p2.proargtypes[0] != 'internal'::regtype OR
585 p2.proargtypes[1] != 'oid'::regtype OR
586 p2.proargtypes[2] != 'internal'::regtype OR
587 p2.proargtypes[3] != 'int2'::regtype OR
588 p2.proargtypes[4] != 'internal'::regtype);
589 oid | oprname | oid | proname
590 -----+---------+-----+---------
593 -- **************** pg_aggregate ****************
594 -- Look for illegal values in pg_aggregate fields.
595 SELECT ctid, aggfnoid::oid
596 FROM pg_aggregate as p1
597 WHERE aggfnoid = 0 OR aggtransfn = 0 OR aggtranstype = 0;
602 -- Make sure the matching pg_proc entry is sensible, too.
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 (NOT p.proisagg OR p.proretset);
611 -- Make sure there are no proisagg pg_proc entries without matches.
615 NOT EXISTS (SELECT 1 FROM pg_aggregate a WHERE a.aggfnoid = p.oid);
620 -- If there is no finalfn then the output type must be the transtype.
621 SELECT a.aggfnoid::oid, p.proname
622 FROM pg_aggregate as a, pg_proc as p
623 WHERE a.aggfnoid = p.oid AND
624 a.aggfinalfn = 0 AND p.prorettype != a.aggtranstype;
629 -- Cross-check transfn against its entry in pg_proc.
630 -- NOTE: use physically_coercible here, not binary_coercible, because
631 -- max and min on abstime are implemented using int4larger/int4smaller.
632 SELECT a.aggfnoid::oid, p.proname, ptr.oid, ptr.proname
633 FROM pg_aggregate AS a, pg_proc AS p, pg_proc AS ptr
634 WHERE a.aggfnoid = p.oid AND
635 a.aggtransfn = ptr.oid AND
637 OR NOT (ptr.pronargs = p.pronargs + 1)
638 OR NOT physically_coercible(ptr.prorettype, a.aggtranstype)
639 OR NOT physically_coercible(a.aggtranstype, ptr.proargtypes[0])
640 OR (p.pronargs > 0 AND
641 NOT physically_coercible(p.proargtypes[0], ptr.proargtypes[1]))
642 OR (p.pronargs > 1 AND
643 NOT physically_coercible(p.proargtypes[1], ptr.proargtypes[2]))
644 OR (p.pronargs > 2 AND
645 NOT physically_coercible(p.proargtypes[2], ptr.proargtypes[3]))
646 -- we could carry the check further, but that's enough for now
648 aggfnoid | proname | oid | proname
649 ----------+---------+-----+---------
652 -- Cross-check finalfn (if present) against its entry in pg_proc.
653 SELECT a.aggfnoid::oid, p.proname, pfn.oid, pfn.proname
654 FROM pg_aggregate AS a, pg_proc AS p, pg_proc AS pfn
655 WHERE a.aggfnoid = p.oid AND
656 a.aggfinalfn = pfn.oid AND
658 OR NOT binary_coercible(pfn.prorettype, p.prorettype)
660 OR NOT binary_coercible(a.aggtranstype, pfn.proargtypes[0]));
661 aggfnoid | proname | oid | proname
662 ----------+---------+-----+---------
665 -- If transfn is strict then either initval should be non-NULL, or
666 -- input type should match transtype so that the first non-null input
667 -- can be assigned as the state value.
668 SELECT a.aggfnoid::oid, p.proname, ptr.oid, ptr.proname
669 FROM pg_aggregate AS a, pg_proc AS p, pg_proc AS ptr
670 WHERE a.aggfnoid = p.oid AND
671 a.aggtransfn = ptr.oid AND ptr.proisstrict AND
672 a.agginitval IS NULL AND
673 NOT binary_coercible(p.proargtypes[0], a.aggtranstype);
674 aggfnoid | proname | oid | proname
675 ----------+---------+-----+---------
678 -- Cross-check aggsortop (if present) against pg_operator.
679 -- We expect to find only "<" for "min" and ">" for "max".
680 SELECT DISTINCT proname, oprname
681 FROM pg_operator AS o, pg_aggregate AS a, pg_proc AS p
682 WHERE a.aggfnoid = p.oid AND a.aggsortop = o.oid
690 -- Check datatypes match
691 SELECT a.aggfnoid::oid, o.oid
692 FROM pg_operator AS o, pg_aggregate AS a, pg_proc AS p
693 WHERE a.aggfnoid = p.oid AND a.aggsortop = o.oid AND
694 (oprkind != 'b' OR oprresult != 'boolean'::regtype
695 OR oprleft != p.proargtypes[0] OR oprright != p.proargtypes[0]);
700 -- Check operator is a suitable btree opfamily member
701 SELECT a.aggfnoid::oid, o.oid
702 FROM pg_operator AS o, pg_aggregate AS a, pg_proc AS p
703 WHERE a.aggfnoid = p.oid AND a.aggsortop = o.oid AND
704 NOT EXISTS(SELECT 1 FROM pg_amop
705 WHERE amopmethod = (SELECT oid FROM pg_am WHERE amname = 'btree')
707 AND amoplefttype = o.oprleft
708 AND amoprighttype = o.oprright);
713 -- Check correspondence of btree strategies and names
714 SELECT DISTINCT proname, oprname, amopstrategy
715 FROM pg_operator AS o, pg_aggregate AS a, pg_proc AS p,
717 WHERE a.aggfnoid = p.oid AND a.aggsortop = o.oid AND
719 amopmethod = (SELECT oid FROM pg_am WHERE amname = 'btree')
721 proname | oprname | amopstrategy
722 ---------+---------+--------------
727 -- **************** pg_opfamily ****************
728 -- Look for illegal values in pg_opfamily fields
730 FROM pg_opfamily as p1
731 WHERE p1.opfmethod = 0 OR p1.opfnamespace = 0;
736 -- **************** pg_opclass ****************
737 -- Look for illegal values in pg_opclass fields
739 FROM pg_opclass AS p1
740 WHERE p1.opcmethod = 0 OR p1.opcnamespace = 0 OR p1.opcfamily = 0
746 -- opcmethod must match owning opfamily's opfmethod
747 SELECT p1.oid, p2.oid
748 FROM pg_opclass AS p1, pg_opfamily AS p2
749 WHERE p1.opcfamily = p2.oid AND p1.opcmethod != p2.opfmethod;
754 -- There should not be multiple entries in pg_opclass with opcdefault true
755 -- and the same opcmethod/opcintype combination.
756 SELECT p1.oid, p2.oid
757 FROM pg_opclass AS p1, pg_opclass AS p2
758 WHERE p1.oid != p2.oid AND
759 p1.opcmethod = p2.opcmethod AND p1.opcintype = p2.opcintype AND
760 p1.opcdefault AND p2.opcdefault;
765 -- **************** pg_amop ****************
766 -- Look for illegal values in pg_amop fields
767 SELECT p1.amopfamily, p1.amopstrategy
769 WHERE p1.amopfamily = 0 OR p1.amoplefttype = 0 OR p1.amoprighttype = 0
770 OR p1.amopopr = 0 OR p1.amopmethod = 0 OR p1.amopstrategy < 1;
771 amopfamily | amopstrategy
772 ------------+--------------
775 -- amoplefttype/amoprighttype must match the operator
776 SELECT p1.oid, p2.oid
777 FROM pg_amop AS p1, pg_operator AS p2
778 WHERE p1.amopopr = p2.oid AND NOT
779 (p1.amoplefttype = p2.oprleft AND p1.amoprighttype = p2.oprright);
784 -- amopmethod must match owning opfamily's opfmethod
785 SELECT p1.oid, p2.oid
786 FROM pg_amop AS p1, pg_opfamily AS p2
787 WHERE p1.amopfamily = p2.oid AND p1.amopmethod != p2.opfmethod;
792 -- Cross-check amopstrategy index against parent AM
793 SELECT p1.amopfamily, p1.amopopr, p2.oid, p2.amname
794 FROM pg_amop AS p1, pg_am AS p2
795 WHERE p1.amopmethod = p2.oid AND
796 p1.amopstrategy > p2.amstrategies AND p2.amstrategies <> 0;
797 amopfamily | amopopr | oid | amname
798 ------------+---------+-----+--------
801 -- Detect missing pg_amop entries: should have as many strategy operators
802 -- as AM expects for each datatype combination supported by the opfamily.
803 -- We can't check this for AMs with variable strategy sets.
804 SELECT p1.amname, p2.amoplefttype, p2.amoprighttype
805 FROM pg_am AS p1, pg_amop AS p2
806 WHERE p2.amopmethod = p1.oid AND
807 p1.amstrategies <> 0 AND
808 p1.amstrategies != (SELECT count(*) FROM pg_amop AS p3
809 WHERE p3.amopfamily = p2.amopfamily AND
810 p3.amoplefttype = p2.amoplefttype AND
811 p3.amoprighttype = p2.amoprighttype);
812 amname | amoplefttype | amoprighttype
813 --------+--------------+---------------
816 -- Check that amopopr points at a reasonable-looking operator, ie a binary
817 -- operator yielding boolean.
818 SELECT p1.amopfamily, p1.amopopr, p2.oid, p2.oprname
819 FROM pg_amop AS p1, pg_operator AS p2
820 WHERE p1.amopopr = p2.oid AND
821 (p2.oprkind != 'b' OR p2.oprresult != 'bool'::regtype);
822 amopfamily | amopopr | oid | oprname
823 ------------+---------+-----+---------
826 -- Make a list of all the distinct operator names being used in particular
827 -- strategy slots. This is a bit hokey, since the list might need to change
828 -- in future releases, but it's an effective way of spotting mistakes such as
829 -- swapping two operators within a family.
830 SELECT DISTINCT amopmethod, amopstrategy, oprname
831 FROM pg_amop p1 LEFT JOIN pg_operator p2 ON amopopr = p2.oid
833 amopmethod | amopstrategy | oprname
834 ------------+--------------+---------
868 -- Check that all operators linked to by opclass entries have selectivity
869 -- estimators. This is not absolutely required, but it seems a reasonable
870 -- thing to insist on for all standard datatypes.
871 SELECT p1.amopfamily, p1.amopopr, p2.oid, p2.oprname
872 FROM pg_amop AS p1, pg_operator AS p2
873 WHERE p1.amopopr = p2.oid AND
874 (p2.oprrest = 0 OR p2.oprjoin = 0);
875 amopfamily | amopopr | oid | oprname
876 ------------+---------+-----+---------
879 -- Check that each opclass in an opfamily has associated operators, that is
880 -- ones whose oprleft matches opcintype (possibly by coercion).
881 SELECT p1.opcname, p1.opcfamily
882 FROM pg_opclass AS p1
883 WHERE NOT EXISTS(SELECT 1 FROM pg_amop AS p2
884 WHERE p2.amopfamily = p1.opcfamily
885 AND binary_coercible(p1.opcintype, p2.amoplefttype));
887 ---------+-----------
890 -- Operators that are primary members of opclasses must be immutable (else
891 -- it suggests that the index ordering isn't fixed). Operators that are
892 -- cross-type members need only be stable, since they are just shorthands
893 -- for index probe queries.
894 SELECT p1.amopfamily, p1.amopopr, p2.oprname, p3.prosrc
895 FROM pg_amop AS p1, pg_operator AS p2, pg_proc AS p3
896 WHERE p1.amopopr = p2.oid AND p2.oprcode = p3.oid AND
897 p1.amoplefttype = p1.amoprighttype AND
898 p3.provolatile != 'i';
899 amopfamily | amopopr | oprname | prosrc
900 ------------+---------+---------+--------
903 SELECT p1.amopfamily, p1.amopopr, p2.oprname, p3.prosrc
904 FROM pg_amop AS p1, pg_operator AS p2, pg_proc AS p3
905 WHERE p1.amopopr = p2.oid AND p2.oprcode = p3.oid AND
906 p1.amoplefttype != p1.amoprighttype AND
907 p3.provolatile = 'v';
908 amopfamily | amopopr | oprname | prosrc
909 ------------+---------+---------+--------
912 -- Multiple-datatype btree opfamilies should provide closed sets of equality
913 -- operators; that is if you provide int2 = int4 and int4 = int8 then you
914 -- should also provide int2 = int8 (and commutators of all these). This is
915 -- important because the planner tries to deduce additional qual clauses from
916 -- transitivity of mergejoinable operators. If there are clauses
917 -- int2var = int4var and int4var = int8var, the planner will want to deduce
918 -- int2var = int8var ... so there should be a way to represent that. While
919 -- a missing cross-type operator is now only an efficiency loss rather than
920 -- an error condition, it still seems reasonable to insist that all built-in
921 -- opfamilies be complete.
922 -- check commutative closure
923 SELECT p1.amoplefttype, p1.amoprighttype
925 WHERE p1.amopmethod = (SELECT oid FROM pg_am WHERE amname = 'btree') AND
926 p1.amopstrategy = 3 AND
927 p1.amoplefttype != p1.amoprighttype AND
928 NOT EXISTS(SELECT 1 FROM pg_amop p2 WHERE
929 p2.amopfamily = p1.amopfamily AND
930 p2.amoplefttype = p1.amoprighttype AND
931 p2.amoprighttype = p1.amoplefttype AND
932 p2.amopstrategy = 3);
933 amoplefttype | amoprighttype
934 --------------+---------------
937 -- check transitive closure
938 SELECT p1.amoplefttype, p1.amoprighttype, p2.amoprighttype
939 FROM pg_amop AS p1, pg_amop AS p2
940 WHERE p1.amopfamily = p2.amopfamily AND
941 p1.amoprighttype = p2.amoplefttype AND
942 p1.amopmethod = (SELECT oid FROM pg_am WHERE amname = 'btree') AND
943 p2.amopmethod = (SELECT oid FROM pg_am WHERE amname = 'btree') AND
944 p1.amopstrategy = 3 AND p2.amopstrategy = 3 AND
945 p1.amoplefttype != p1.amoprighttype AND
946 p2.amoplefttype != p2.amoprighttype AND
947 NOT EXISTS(SELECT 1 FROM pg_amop p3 WHERE
948 p3.amopfamily = p1.amopfamily AND
949 p3.amoplefttype = p1.amoplefttype AND
950 p3.amoprighttype = p2.amoprighttype AND
951 p3.amopstrategy = 3);
952 amoplefttype | amoprighttype | amoprighttype
953 --------------+---------------+---------------
956 -- We also expect that built-in multiple-datatype hash opfamilies provide
957 -- complete sets of cross-type operators. Again, this isn't required, but
958 -- it is reasonable to expect it for built-in opfamilies.
959 -- if same family has x=x and y=y, it should have x=y
960 SELECT p1.amoplefttype, p2.amoplefttype
961 FROM pg_amop AS p1, pg_amop AS p2
962 WHERE p1.amopfamily = p2.amopfamily AND
963 p1.amoplefttype = p1.amoprighttype AND
964 p2.amoplefttype = p2.amoprighttype AND
965 p1.amopmethod = (SELECT oid FROM pg_am WHERE amname = 'hash') AND
966 p2.amopmethod = (SELECT oid FROM pg_am WHERE amname = 'hash') AND
967 p1.amopstrategy = 1 AND p2.amopstrategy = 1 AND
968 p1.amoplefttype != p2.amoplefttype AND
969 NOT EXISTS(SELECT 1 FROM pg_amop p3 WHERE
970 p3.amopfamily = p1.amopfamily AND
971 p3.amoplefttype = p1.amoplefttype AND
972 p3.amoprighttype = p2.amoplefttype AND
973 p3.amopstrategy = 1);
974 amoplefttype | amoplefttype
975 --------------+--------------
978 -- **************** pg_amproc ****************
979 -- Look for illegal values in pg_amproc fields
980 SELECT p1.amprocfamily, p1.amprocnum
982 WHERE p1.amprocfamily = 0 OR p1.amproclefttype = 0 OR p1.amprocrighttype = 0
983 OR p1.amprocnum < 1 OR p1.amproc = 0;
984 amprocfamily | amprocnum
985 --------------+-----------
988 -- Cross-check amprocnum index against parent AM
989 SELECT p1.amprocfamily, p1.amprocnum, p2.oid, p2.amname
990 FROM pg_amproc AS p1, pg_am AS p2, pg_opfamily AS p3
991 WHERE p1.amprocfamily = p3.oid AND p3.opfmethod = p2.oid AND
992 p1.amprocnum > p2.amsupport;
993 amprocfamily | amprocnum | oid | amname
994 --------------+-----------+-----+--------
997 -- Detect missing pg_amproc entries: should have as many support functions
998 -- as AM expects for each datatype combination supported by the opfamily.
999 -- GIN is a special case because it has an optional support function.
1000 SELECT p1.amname, p2.opfname, p3.amproclefttype, p3.amprocrighttype
1001 FROM pg_am AS p1, pg_opfamily AS p2, pg_amproc AS p3
1002 WHERE p2.opfmethod = p1.oid AND p3.amprocfamily = p2.oid AND
1003 p1.amname <> 'gin' AND
1004 p1.amsupport != (SELECT count(*) FROM pg_amproc AS p4
1005 WHERE p4.amprocfamily = p2.oid AND
1006 p4.amproclefttype = p3.amproclefttype AND
1007 p4.amprocrighttype = p3.amprocrighttype);
1008 amname | opfname | amproclefttype | amprocrighttype
1009 --------+---------+----------------+-----------------
1012 -- Similar check for GIN, allowing one optional proc
1013 SELECT p1.amname, p2.opfname, p3.amproclefttype, p3.amprocrighttype
1014 FROM pg_am AS p1, pg_opfamily AS p2, pg_amproc AS p3
1015 WHERE p2.opfmethod = p1.oid AND p3.amprocfamily = p2.oid AND
1016 p1.amname = 'gin' AND
1017 p1.amsupport - 1 > (SELECT count(*) FROM pg_amproc AS p4
1018 WHERE p4.amprocfamily = p2.oid AND
1019 p4.amproclefttype = p3.amproclefttype AND
1020 p4.amprocrighttype = p3.amprocrighttype);
1021 amname | opfname | amproclefttype | amprocrighttype
1022 --------+---------+----------------+-----------------
1025 -- Also, check if there are any pg_opclass entries that don't seem to have
1026 -- pg_amproc support. Again, GIN has to be checked separately.
1027 SELECT amname, opcname, count(*)
1028 FROM pg_am am JOIN pg_opclass op ON opcmethod = am.oid
1029 LEFT JOIN pg_amproc p ON amprocfamily = opcfamily AND
1030 amproclefttype = amprocrighttype AND amproclefttype = opcintype
1031 WHERE am.amname <> 'gin'
1032 GROUP BY amname, amsupport, opcname, amprocfamily
1033 HAVING count(*) != amsupport OR amprocfamily IS NULL;
1034 amname | opcname | count
1035 --------+---------+-------
1038 SELECT amname, opcname, count(*)
1039 FROM pg_am am JOIN pg_opclass op ON opcmethod = am.oid
1040 LEFT JOIN pg_amproc p ON amprocfamily = opcfamily AND
1041 amproclefttype = amprocrighttype AND amproclefttype = opcintype
1042 WHERE am.amname = 'gin'
1043 GROUP BY amname, amsupport, opcname, amprocfamily
1044 HAVING count(*) < amsupport - 1 OR amprocfamily IS NULL;
1045 amname | opcname | count
1046 --------+---------+-------
1049 -- Unfortunately, we can't check the amproc link very well because the
1050 -- signature of the function may be different for different support routines
1051 -- or different base data types.
1052 -- We can check that all the referenced instances of the same support
1053 -- routine number take the same number of parameters, but that's about it
1054 -- for a general check...
1055 SELECT p1.amprocfamily, p1.amprocnum,
1058 p4.amprocfamily, p4.amprocnum,
1061 FROM pg_amproc AS p1, pg_proc AS p2, pg_opfamily AS p3,
1062 pg_amproc AS p4, pg_proc AS p5, pg_opfamily AS p6
1063 WHERE p1.amprocfamily = p3.oid AND p4.amprocfamily = p6.oid AND
1064 p3.opfmethod = p6.opfmethod AND p1.amprocnum = p4.amprocnum AND
1065 p1.amproc = p2.oid AND p4.amproc = p5.oid AND
1066 (p2.proretset OR p5.proretset OR p2.pronargs != p5.pronargs);
1067 amprocfamily | amprocnum | oid | proname | opfname | amprocfamily | amprocnum | oid | proname | opfname
1068 --------------+-----------+-----+---------+---------+--------------+-----------+-----+---------+---------
1071 -- For btree, though, we can do better since we know the support routines
1072 -- must be of the form cmp(lefttype, righttype) returns int4.
1073 SELECT p1.amprocfamily, p1.amprocnum,
1076 FROM pg_amproc AS p1, pg_proc AS p2, pg_opfamily AS p3
1077 WHERE p3.opfmethod = (SELECT oid FROM pg_am WHERE amname = 'btree')
1078 AND p1.amprocfamily = p3.oid AND p1.amproc = p2.oid AND
1081 OR prorettype != 'int4'::regtype
1083 OR proargtypes[0] != amproclefttype
1084 OR proargtypes[1] != amprocrighttype);
1085 amprocfamily | amprocnum | oid | proname | opfname
1086 --------------+-----------+-----+---------+---------
1089 -- For hash we can also do a little better: the support routines must be
1090 -- of the form hash(lefttype) returns int4. There are several cases where
1091 -- we cheat and use a hash function that is physically compatible with the
1092 -- datatype even though there's no cast, so this check does find a small
1093 -- number of entries.
1094 SELECT p1.amprocfamily, p1.amprocnum, p2.proname, p3.opfname
1095 FROM pg_amproc AS p1, pg_proc AS p2, pg_opfamily AS p3
1096 WHERE p3.opfmethod = (SELECT oid FROM pg_am WHERE amname = 'hash')
1097 AND p1.amprocfamily = p3.oid AND p1.amproc = p2.oid AND
1100 OR prorettype != 'int4'::regtype
1102 OR NOT physically_coercible(amproclefttype, proargtypes[0])
1103 OR amproclefttype != amprocrighttype)
1105 amprocfamily | amprocnum | proname | opfname
1106 --------------+-----------+----------------+-----------------
1107 435 | 1 | hashint4 | date_ops
1108 1999 | 1 | timestamp_hash | timestamptz_ops
1109 2222 | 1 | hashchar | bool_ops
1110 2223 | 1 | hashvarlena | bytea_ops
1111 2225 | 1 | hashint4 | xid_ops
1112 2226 | 1 | hashint4 | cid_ops
1115 -- Support routines that are primary members of opfamilies must be immutable
1116 -- (else it suggests that the index ordering isn't fixed). But cross-type
1117 -- members need only be stable, since they are just shorthands
1118 -- for index probe queries.
1119 SELECT p1.amprocfamily, p1.amproc, p2.prosrc
1120 FROM pg_amproc AS p1, pg_proc AS p2
1121 WHERE p1.amproc = p2.oid AND
1122 p1.amproclefttype = p1.amprocrighttype AND
1123 p2.provolatile != 'i';
1124 amprocfamily | amproc | prosrc
1125 --------------+--------+--------
1128 SELECT p1.amprocfamily, p1.amproc, p2.prosrc
1129 FROM pg_amproc AS p1, pg_proc AS p2
1130 WHERE p1.amproc = p2.oid AND
1131 p1.amproclefttype != p1.amprocrighttype AND
1132 p2.provolatile = 'v';
1133 amprocfamily | amproc | prosrc
1134 --------------+--------+--------