3 -- Sanity checks for common errors in making operator/procedure system tables:
4 -- pg_operator, pg_proc, pg_cast, pg_conversion, pg_aggregate, pg_am,
5 -- pg_amop, pg_amproc, pg_opclass, pg_opfamily, pg_index.
7 -- Every test failure in this file should be closely inspected.
8 -- The description of the failing test should be read carefully before
9 -- adjusting the expected output. In most cases, the queries should
10 -- not find *any* matching entries.
12 -- NB: we assume the oidjoins test will have caught any dangling links,
13 -- that is OID or REGPROC fields that are not zero and do not match some
14 -- row in the linked-to table. However, if we want to enforce that a link
15 -- field can't be 0, we have to check it here.
17 -- NB: run this test earlier than the create_operator test, because
18 -- that test creates some bogus operators...
19 -- **************** pg_proc ****************
20 -- Look for illegal values in pg_proc fields.
21 SELECT p1.oid, p1.proname
23 WHERE p1.prolang = 0 OR p1.prorettype = 0 OR
25 p1.pronargdefaults < 0 OR
26 p1.pronargdefaults > p1.pronargs OR
27 array_lower(p1.proargtypes, 1) != 0 OR
28 array_upper(p1.proargtypes, 1) != p1.pronargs-1 OR
29 0::oid = ANY (p1.proargtypes) OR
31 CASE WHEN proretset THEN prorows <= 0 ELSE prorows != 0 END OR
32 prokind NOT IN ('f', 'a', 'w', 'p') OR
33 provolatile NOT IN ('i', 's', 'v') OR
34 proparallel NOT IN ('s', 'r', 'u');
39 -- prosrc should never be null; it can be empty only if prosqlbody isn't null
40 SELECT p1.oid, p1.proname
47 SELECT p1.oid, p1.proname
49 WHERE (prosrc = '' OR prosrc = '-') AND prosqlbody IS NULL;
54 -- proretset should only be set for normal functions
55 SELECT p1.oid, p1.proname
57 WHERE proretset AND prokind != 'f';
62 -- currently, no built-in functions should be SECURITY DEFINER;
63 -- this might change in future, but there will probably never be many.
64 SELECT p1.oid, p1.proname
72 -- pronargdefaults should be 0 iff proargdefaults is null
73 SELECT p1.oid, p1.proname
75 WHERE (pronargdefaults <> 0) != (proargdefaults IS NOT NULL);
80 -- probin should be non-empty for C functions, null everywhere else
81 SELECT p1.oid, p1.proname
83 WHERE prolang = 13 AND (probin IS NULL OR probin = '' OR probin = '-');
88 SELECT p1.oid, p1.proname
90 WHERE prolang != 13 AND probin IS NOT NULL;
95 -- Look for conflicting proc definitions (same names and input datatypes).
96 -- (This test should be dead code now that we have the unique index
97 -- pg_proc_proname_args_nsp_index, but I'll leave it in anyway.)
98 SELECT p1.oid, p1.proname, p2.oid, p2.proname
99 FROM pg_proc AS p1, pg_proc AS p2
100 WHERE p1.oid != p2.oid AND
101 p1.proname = p2.proname AND
102 p1.pronargs = p2.pronargs AND
103 p1.proargtypes = p2.proargtypes;
104 oid | proname | oid | proname
105 -----+---------+-----+---------
108 -- Considering only built-in procs (prolang = 12), look for multiple uses
109 -- of the same internal function (ie, matching prosrc fields). It's OK to
110 -- have several entries with different pronames for the same internal function,
111 -- but conflicts in the number of arguments and other critical items should
112 -- be complained of. (We don't check data types here; see next query.)
113 -- Note: ignore aggregate functions here, since they all point to the same
114 -- dummy built-in function.
115 SELECT p1.oid, p1.proname, p2.oid, p2.proname
116 FROM pg_proc AS p1, pg_proc AS p2
117 WHERE p1.oid < p2.oid AND
118 p1.prosrc = p2.prosrc AND
119 p1.prolang = 12 AND p2.prolang = 12 AND
120 (p1.prokind != 'a' OR p2.prokind != 'a') AND
121 (p1.prolang != p2.prolang OR
122 p1.prokind != p2.prokind OR
123 p1.prosecdef != p2.prosecdef OR
124 p1.proleakproof != p2.proleakproof OR
125 p1.proisstrict != p2.proisstrict OR
126 p1.proretset != p2.proretset OR
127 p1.provolatile != p2.provolatile OR
128 p1.pronargs != p2.pronargs);
129 oid | proname | oid | proname
130 -----+---------+-----+---------
133 -- Look for uses of different type OIDs in the argument/result type fields
134 -- for different aliases of the same built-in function.
135 -- This indicates that the types are being presumed to be binary-equivalent,
136 -- or that the built-in function is prepared to deal with different types.
137 -- That's not wrong, necessarily, but we make lists of all the types being
138 -- so treated. Note that the expected output of this part of the test will
139 -- need to be modified whenever new pairs of types are made binary-equivalent,
140 -- or when new polymorphic built-in functions are added!
141 -- Note: ignore aggregate functions here, since they all point to the same
142 -- dummy built-in function. Likewise, ignore range and multirange constructor
144 SELECT DISTINCT p1.prorettype::regtype, p2.prorettype::regtype
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 p1.prokind != 'a' AND p2.prokind != 'a' AND
150 p1.prosrc NOT LIKE E'range\\_constructor_' AND
151 p2.prosrc NOT LIKE E'range\\_constructor_' AND
152 p1.prosrc NOT LIKE E'multirange\\_constructor_' AND
153 p2.prosrc NOT LIKE E'multirange\\_constructor_' AND
154 (p1.prorettype < p2.prorettype)
156 prorettype | prorettype
157 -----------------------------+--------------------------
159 text | character varying
160 timestamp without time zone | timestamp with time zone
161 txid_snapshot | pg_snapshot
164 SELECT DISTINCT p1.proargtypes[0]::regtype, p2.proargtypes[0]::regtype
165 FROM pg_proc AS p1, pg_proc AS p2
166 WHERE p1.oid != p2.oid AND
167 p1.prosrc = p2.prosrc AND
168 p1.prolang = 12 AND p2.prolang = 12 AND
169 p1.prokind != 'a' AND p2.prokind != 'a' AND
170 p1.prosrc NOT LIKE E'range\\_constructor_' AND
171 p2.prosrc NOT LIKE E'range\\_constructor_' AND
172 p1.prosrc NOT LIKE E'multirange\\_constructor_' AND
173 p2.prosrc NOT LIKE E'multirange\\_constructor_' AND
174 (p1.proargtypes[0] < p2.proargtypes[0])
176 proargtypes | proargtypes
177 -----------------------------+--------------------------
180 text | character varying
181 timestamp without time zone | timestamp with time zone
183 txid_snapshot | pg_snapshot
186 SELECT DISTINCT p1.proargtypes[1]::regtype, p2.proargtypes[1]::regtype
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 p1.prokind != 'a' AND p2.prokind != 'a' AND
192 p1.prosrc NOT LIKE E'range\\_constructor_' AND
193 p2.prosrc NOT LIKE E'range\\_constructor_' AND
194 p1.prosrc NOT LIKE E'multirange\\_constructor_' AND
195 p2.prosrc NOT LIKE E'multirange\\_constructor_' AND
196 (p1.proargtypes[1] < p2.proargtypes[1])
198 proargtypes | proargtypes
199 -----------------------------+--------------------------
201 timestamp without time zone | timestamp with time zone
203 txid_snapshot | pg_snapshot
204 anyrange | anymultirange
207 SELECT DISTINCT p1.proargtypes[2]::regtype, p2.proargtypes[2]::regtype
208 FROM pg_proc AS p1, pg_proc AS p2
209 WHERE p1.oid != p2.oid AND
210 p1.prosrc = p2.prosrc AND
211 p1.prolang = 12 AND p2.prolang = 12 AND
212 p1.prokind != 'a' AND p2.prokind != 'a' AND
213 (p1.proargtypes[2] < p2.proargtypes[2])
215 proargtypes | proargtypes
216 -----------------------------+--------------------------
217 timestamp without time zone | timestamp with time zone
220 SELECT DISTINCT p1.proargtypes[3]::regtype, p2.proargtypes[3]::regtype
221 FROM pg_proc AS p1, pg_proc AS p2
222 WHERE p1.oid != p2.oid AND
223 p1.prosrc = p2.prosrc AND
224 p1.prolang = 12 AND p2.prolang = 12 AND
225 p1.prokind != 'a' AND p2.prokind != 'a' AND
226 (p1.proargtypes[3] < p2.proargtypes[3])
228 proargtypes | proargtypes
229 -----------------------------+--------------------------
230 timestamp without time zone | timestamp with time zone
233 SELECT DISTINCT p1.proargtypes[4]::regtype, p2.proargtypes[4]::regtype
234 FROM pg_proc AS p1, pg_proc AS p2
235 WHERE p1.oid != p2.oid AND
236 p1.prosrc = p2.prosrc AND
237 p1.prolang = 12 AND p2.prolang = 12 AND
238 p1.prokind != 'a' AND p2.prokind != 'a' AND
239 (p1.proargtypes[4] < p2.proargtypes[4])
241 proargtypes | proargtypes
242 -------------+-------------
245 SELECT DISTINCT p1.proargtypes[5]::regtype, p2.proargtypes[5]::regtype
246 FROM pg_proc AS p1, pg_proc AS p2
247 WHERE p1.oid != p2.oid AND
248 p1.prosrc = p2.prosrc AND
249 p1.prolang = 12 AND p2.prolang = 12 AND
250 p1.prokind != 'a' AND p2.prokind != 'a' AND
251 (p1.proargtypes[5] < p2.proargtypes[5])
253 proargtypes | proargtypes
254 -------------+-------------
257 SELECT DISTINCT p1.proargtypes[6]::regtype, p2.proargtypes[6]::regtype
258 FROM pg_proc AS p1, pg_proc AS p2
259 WHERE p1.oid != p2.oid AND
260 p1.prosrc = p2.prosrc AND
261 p1.prolang = 12 AND p2.prolang = 12 AND
262 p1.prokind != 'a' AND p2.prokind != 'a' AND
263 (p1.proargtypes[6] < p2.proargtypes[6])
265 proargtypes | proargtypes
266 -------------+-------------
269 SELECT DISTINCT p1.proargtypes[7]::regtype, p2.proargtypes[7]::regtype
270 FROM pg_proc AS p1, pg_proc AS p2
271 WHERE p1.oid != p2.oid AND
272 p1.prosrc = p2.prosrc AND
273 p1.prolang = 12 AND p2.prolang = 12 AND
274 p1.prokind != 'a' AND p2.prokind != 'a' AND
275 (p1.proargtypes[7] < p2.proargtypes[7])
277 proargtypes | proargtypes
278 -------------+-------------
281 -- Look for functions that return type "internal" and do not have any
282 -- "internal" argument. Such a function would be a security hole since
283 -- it might be used to call an internal function from an SQL command.
284 -- As of 7.3 this query should find only internal_in, which is safe because
285 -- it always throws an error when called.
286 SELECT p1.oid, p1.proname
288 WHERE p1.prorettype = 'internal'::regtype AND NOT
289 'internal'::regtype = ANY (p1.proargtypes);
295 -- Look for functions that return a polymorphic type and do not have any
296 -- polymorphic argument. Calls of such functions would be unresolvable
297 -- at parse time. As of 9.6 this query should find only some input functions
298 -- and GiST support functions associated with these pseudotypes.
299 SELECT p1.oid, p1.proname
301 WHERE p1.prorettype IN
302 ('anyelement'::regtype, 'anyarray'::regtype, 'anynonarray'::regtype,
305 ('anyelement'::regtype = ANY (p1.proargtypes) OR
306 'anyarray'::regtype = ANY (p1.proargtypes) OR
307 'anynonarray'::regtype = ANY (p1.proargtypes) OR
308 'anyenum'::regtype = ANY (p1.proargtypes) OR
309 'anyrange'::regtype = ANY (p1.proargtypes) OR
310 'anymultirange'::regtype = ANY (p1.proargtypes))
313 ------+----------------
318 2777 | anynonarray_in
325 -- anyrange and anymultirange are tighter than the rest, can only resolve
327 SELECT p1.oid, p1.proname
329 WHERE p1.prorettype IN ('anyrange'::regtype, 'anymultirange'::regtype)
331 ('anyrange'::regtype = ANY (p1.proargtypes) OR
332 'anymultirange'::regtype = ANY (p1.proargtypes))
335 ------+------------------
336 4229 | anymultirange_in
339 4233 | multirange_recv
340 3876 | range_gist_union
345 -- similarly for the anycompatible family
346 SELECT p1.oid, p1.proname
348 WHERE p1.prorettype IN
349 ('anycompatible'::regtype, 'anycompatiblearray'::regtype,
350 'anycompatiblenonarray'::regtype)
352 ('anycompatible'::regtype = ANY (p1.proargtypes) OR
353 'anycompatiblearray'::regtype = ANY (p1.proargtypes) OR
354 'anycompatiblenonarray'::regtype = ANY (p1.proargtypes) OR
355 'anycompatiblerange'::regtype = ANY (p1.proargtypes))
358 ------+--------------------------
359 5086 | anycompatible_in
360 5088 | anycompatiblearray_in
361 5090 | anycompatiblearray_recv
362 5092 | anycompatiblenonarray_in
365 SELECT p1.oid, p1.proname
367 WHERE p1.prorettype = 'anycompatiblerange'::regtype
369 'anycompatiblerange'::regtype = ANY (p1.proargtypes)
372 ------+-----------------------
373 5094 | anycompatiblerange_in
376 -- Look for functions that accept cstring and are neither datatype input
377 -- functions nor encoding conversion functions. It's almost never a good
378 -- idea to use cstring input for a function meant to be called from SQL;
379 -- text should be used instead, because cstring lacks suitable casts.
380 -- As of 9.6 this query should find only cstring_out and cstring_send.
381 -- However, we must manually exclude shell_in, which might or might not be
382 -- rejected by the EXISTS clause depending on whether there are currently
384 SELECT p1.oid, p1.proname
386 WHERE 'cstring'::regtype = ANY (p1.proargtypes)
387 AND NOT EXISTS(SELECT 1 FROM pg_type WHERE typinput = p1.oid)
388 AND NOT EXISTS(SELECT 1 FROM pg_conversion WHERE conproc = p1.oid)
389 AND p1.oid != 'shell_in(cstring)'::regprocedure
392 ------+--------------
397 -- Likewise, look for functions that return cstring and aren't datatype output
398 -- functions nor typmod output functions.
399 -- As of 9.6 this query should find only cstring_in and cstring_recv.
400 -- However, we must manually exclude shell_out.
401 SELECT p1.oid, p1.proname
403 WHERE p1.prorettype = 'cstring'::regtype
404 AND NOT EXISTS(SELECT 1 FROM pg_type WHERE typoutput = p1.oid)
405 AND NOT EXISTS(SELECT 1 FROM pg_type WHERE typmodout = p1.oid)
406 AND p1.oid != 'shell_out(void)'::regprocedure
409 ------+--------------
414 -- Check for length inconsistencies between the various argument-info arrays.
415 SELECT p1.oid, p1.proname
417 WHERE proallargtypes IS NOT NULL AND
418 array_length(proallargtypes,1) < array_length(proargtypes,1);
423 SELECT p1.oid, p1.proname
425 WHERE proargmodes IS NOT NULL AND
426 array_length(proargmodes,1) < array_length(proargtypes,1);
431 SELECT p1.oid, p1.proname
433 WHERE proargnames IS NOT NULL AND
434 array_length(proargnames,1) < array_length(proargtypes,1);
439 SELECT p1.oid, p1.proname
441 WHERE proallargtypes IS NOT NULL AND proargmodes IS NOT NULL AND
442 array_length(proallargtypes,1) <> array_length(proargmodes,1);
447 SELECT p1.oid, p1.proname
449 WHERE proallargtypes IS NOT NULL AND proargnames IS NOT NULL AND
450 array_length(proallargtypes,1) <> array_length(proargnames,1);
455 SELECT p1.oid, p1.proname
457 WHERE proargmodes IS NOT NULL AND proargnames IS NOT NULL AND
458 array_length(proargmodes,1) <> array_length(proargnames,1);
463 -- Check that proallargtypes matches proargtypes
464 SELECT p1.oid, p1.proname, p1.proargtypes, p1.proallargtypes, p1.proargmodes
466 WHERE proallargtypes IS NOT NULL AND
467 ARRAY(SELECT unnest(proargtypes)) <>
468 ARRAY(SELECT proallargtypes[i]
469 FROM generate_series(1, array_length(proallargtypes, 1)) g(i)
470 WHERE proargmodes IS NULL OR proargmodes[i] IN ('i', 'b', 'v'));
471 oid | proname | proargtypes | proallargtypes | proargmodes
472 -----+---------+-------------+----------------+-------------
475 -- Check for type of the variadic array parameter's elements.
476 -- provariadic should be ANYOID if the type of the last element is ANYOID,
477 -- ANYELEMENTOID if the type of the last element is ANYARRAYOID,
478 -- ANYCOMPATIBLEOID if the type of the last element is ANYCOMPATIBLEARRAYOID,
479 -- and otherwise the element type corresponding to the array type.
480 SELECT oid::regprocedure, provariadic::regtype, proargtypes::regtype[]
482 WHERE provariadic != 0
483 AND case proargtypes[array_length(proargtypes, 1)-1]
484 WHEN '"any"'::regtype THEN '"any"'::regtype
485 WHEN 'anyarray'::regtype THEN 'anyelement'::regtype
486 WHEN 'anycompatiblearray'::regtype THEN 'anycompatible'::regtype
489 WHERE t.typarray = proargtypes[array_length(proargtypes, 1)-1])
491 oid | provariadic | proargtypes
492 -----+-------------+-------------
495 -- Check that all and only those functions with a variadic type have
496 -- a variadic argument.
497 SELECT oid::regprocedure, proargmodes, provariadic
499 WHERE (proargmodes IS NOT NULL AND 'v' = any(proargmodes))
502 oid | proargmodes | provariadic
503 -----+-------------+-------------
506 -- Check for prosupport functions with the wrong signature
507 SELECT p1.oid, p1.proname, p2.oid, p2.proname
508 FROM pg_proc AS p1, pg_proc AS p2
509 WHERE p2.oid = p1.prosupport AND
510 (p2.prorettype != 'internal'::regtype OR p2.proretset OR p2.pronargs != 1
511 OR p2.proargtypes[0] != 'internal'::regtype);
512 oid | proname | oid | proname
513 -----+---------+-----+---------
516 -- Insist that all built-in pg_proc entries have descriptions
517 SELECT p1.oid, p1.proname
518 FROM pg_proc as p1 LEFT JOIN pg_description as d
519 ON p1.tableoid = d.classoid and p1.oid = d.objoid and d.objsubid = 0
520 WHERE d.classoid IS NULL AND p1.oid <= 9999;
525 -- List of built-in leakproof functions
527 -- Leakproof functions should only be added after carefully
528 -- scrutinizing all possibly executed codepaths for possible
529 -- information leaks. Don't add functions here unless you know what a
530 -- leakproof function is. If unsure, don't mark it as such.
531 -- temporarily disable fancy output, so catalog changes create less diff noise
533 SELECT p1.oid::regprocedure
534 FROM pg_proc p1 JOIN pg_namespace pn
535 ON pronamespace = pn.oid
536 WHERE nspname = 'pg_catalog' AND proleakproof
538 boollt(boolean,boolean)
539 boolgt(boolean,boolean)
540 booleq(boolean,boolean)
541 chareq("char","char")
543 int2eq(smallint,smallint)
544 int2lt(smallint,smallint)
545 int4eq(integer,integer)
546 int4lt(integer,integer)
550 charne("char","char")
551 charle("char","char")
552 chargt("char","char")
553 charge("char","char")
554 boolne(boolean,boolean)
555 int4ne(integer,integer)
556 int2ne(smallint,smallint)
557 int2gt(smallint,smallint)
558 int4gt(integer,integer)
559 int2le(smallint,smallint)
560 int4le(integer,integer)
561 int4ge(integer,integer)
562 int2ge(smallint,smallint)
564 int24eq(smallint,integer)
565 int42eq(integer,smallint)
566 int24lt(smallint,integer)
567 int42lt(integer,smallint)
568 int24gt(smallint,integer)
569 int42gt(integer,smallint)
570 int24ne(smallint,integer)
571 int42ne(integer,smallint)
572 int24le(smallint,integer)
573 int42le(integer,smallint)
574 int24ge(smallint,integer)
575 int42ge(integer,smallint)
580 nameeqtext(name,text)
581 namelttext(name,text)
582 nameletext(name,text)
583 namegetext(name,text)
584 namegttext(name,text)
585 namenetext(name,text)
586 btnametextcmp(name,text)
587 texteqname(text,name)
588 textltname(text,name)
589 textlename(text,name)
590 textgename(text,name)
591 textgtname(text,name)
592 textnename(text,name)
593 bttextnamecmp(text,name)
600 float8eq(double precision,double precision)
601 float8ne(double precision,double precision)
602 float8lt(double precision,double precision)
603 float8le(double precision,double precision)
604 float8gt(double precision,double precision)
605 float8ge(double precision,double precision)
606 float48eq(real,double precision)
607 float48ne(real,double precision)
608 float48lt(real,double precision)
609 float48le(real,double precision)
610 float48gt(real,double precision)
611 float48ge(real,double precision)
612 float84eq(double precision,real)
613 float84ne(double precision,real)
614 float84lt(double precision,real)
615 float84le(double precision,real)
616 float84gt(double precision,real)
617 float84ge(double precision,real)
622 btint2cmp(smallint,smallint)
623 btint4cmp(integer,integer)
624 btfloat4cmp(real,real)
625 btfloat8cmp(double precision,double precision)
627 btcharcmp("char","char")
630 cash_cmp(money,money)
631 btoidvectorcmp(oidvector,oidvector)
635 text_larger(text,text)
636 text_smaller(text,text)
637 int8eq(bigint,bigint)
638 int8ne(bigint,bigint)
639 int8lt(bigint,bigint)
640 int8gt(bigint,bigint)
641 int8le(bigint,bigint)
642 int8ge(bigint,bigint)
643 int84eq(bigint,integer)
644 int84ne(bigint,integer)
645 int84lt(bigint,integer)
646 int84gt(bigint,integer)
647 int84le(bigint,integer)
648 int84ge(bigint,integer)
651 oidvectorne(oidvector,oidvector)
658 oidvectorlt(oidvector,oidvector)
659 oidvectorle(oidvector,oidvector)
660 oidvectoreq(oidvector,oidvector)
661 oidvectorge(oidvector,oidvector)
662 oidvectorgt(oidvector,oidvector)
670 macaddr_eq(macaddr,macaddr)
671 macaddr_lt(macaddr,macaddr)
672 macaddr_le(macaddr,macaddr)
673 macaddr_gt(macaddr,macaddr)
674 macaddr_ge(macaddr,macaddr)
675 macaddr_ne(macaddr,macaddr)
676 macaddr_cmp(macaddr,macaddr)
677 btint8cmp(bigint,bigint)
678 int48eq(integer,bigint)
679 int48ne(integer,bigint)
680 int48lt(integer,bigint)
681 int48gt(integer,bigint)
682 int48le(integer,bigint)
683 int48ge(integer,bigint)
690 network_eq(inet,inet)
691 network_lt(inet,inet)
692 network_le(inet,inet)
693 network_gt(inet,inet)
694 network_ge(inet,inet)
695 network_ne(inet,inet)
696 network_cmp(inet,inet)
698 bpchareq(character,character)
699 bpcharlt(character,character)
700 bpcharle(character,character)
701 bpchargt(character,character)
702 bpcharge(character,character)
703 bpcharne(character,character)
704 bpchar_larger(character,character)
705 bpchar_smaller(character,character)
706 bpcharcmp(character,character)
714 time_lt(time without time zone,time without time zone)
715 time_le(time without time zone,time without time zone)
716 time_gt(time without time zone,time without time zone)
717 time_ge(time without time zone,time without time zone)
718 time_ne(time without time zone,time without time zone)
719 time_cmp(time without time zone,time without time zone)
720 time_eq(time without time zone,time without time zone)
721 timestamptz_eq(timestamp with time zone,timestamp with time zone)
722 timestamptz_ne(timestamp with time zone,timestamp with time zone)
723 timestamptz_lt(timestamp with time zone,timestamp with time zone)
724 timestamptz_le(timestamp with time zone,timestamp with time zone)
725 timestamptz_ge(timestamp with time zone,timestamp with time zone)
726 timestamptz_gt(timestamp with time zone,timestamp with time zone)
727 interval_eq(interval,interval)
728 interval_ne(interval,interval)
729 interval_lt(interval,interval)
730 interval_le(interval,interval)
731 interval_ge(interval,interval)
732 interval_gt(interval,interval)
733 charlt("char","char")
737 timestamptz_cmp(timestamp with time zone,timestamp with time zone)
738 interval_cmp(interval,interval)
739 xideqint4(xid,integer)
740 timetz_eq(time with time zone,time with time zone)
741 timetz_ne(time with time zone,time with time zone)
742 timetz_lt(time with time zone,time with time zone)
743 timetz_le(time with time zone,time with time zone)
744 timetz_ge(time with time zone,time with time zone)
745 timetz_gt(time with time zone,time with time zone)
746 timetz_cmp(time with time zone,time with time zone)
747 "interval"(time without time zone)
748 name(character varying)
750 circle_eq(circle,circle)
751 circle_ne(circle,circle)
752 circle_lt(circle,circle)
753 circle_gt(circle,circle)
754 circle_le(circle,circle)
755 circle_ge(circle,circle)
770 varbiteq(bit varying,bit varying)
771 varbitne(bit varying,bit varying)
772 varbitge(bit varying,bit varying)
773 varbitgt(bit varying,bit varying)
774 varbitle(bit varying,bit varying)
775 varbitlt(bit varying,bit varying)
776 varbitcmp(bit varying,bit varying)
777 boolle(boolean,boolean)
778 boolge(boolean,boolean)
779 btboolcmp(boolean,boolean)
782 "numeric"(double precision)
785 int28eq(smallint,bigint)
786 int28ne(smallint,bigint)
787 int28lt(smallint,bigint)
788 int28gt(smallint,bigint)
789 int28le(smallint,bigint)
790 int28ge(smallint,bigint)
791 int82eq(bigint,smallint)
792 int82ne(bigint,smallint)
793 int82lt(bigint,smallint)
794 int82gt(bigint,smallint)
795 int82le(bigint,smallint)
796 int82ge(bigint,smallint)
803 byteacmp(bytea,bytea)
804 timestamp_cmp(timestamp without time zone,timestamp without time zone)
805 timestamp_eq(timestamp without time zone,timestamp without time zone)
806 timestamp_ne(timestamp without time zone,timestamp without time zone)
807 timestamp_lt(timestamp without time zone,timestamp without time zone)
808 timestamp_le(timestamp without time zone,timestamp without time zone)
809 timestamp_ge(timestamp without time zone,timestamp without time zone)
810 timestamp_gt(timestamp without time zone,timestamp without time zone)
811 text_pattern_lt(text,text)
812 text_pattern_le(text,text)
813 text_pattern_ge(text,text)
814 text_pattern_gt(text,text)
815 bttext_pattern_cmp(text,text)
816 bpchar_pattern_lt(character,character)
817 bpchar_pattern_le(character,character)
818 bpchar_pattern_ge(character,character)
819 bpchar_pattern_gt(character,character)
820 btbpchar_pattern_cmp(character,character)
821 btint48cmp(integer,bigint)
822 btint84cmp(bigint,integer)
823 btint24cmp(smallint,integer)
824 btint42cmp(integer,smallint)
825 btint28cmp(smallint,bigint)
826 btint82cmp(bigint,smallint)
827 btfloat48cmp(real,double precision)
828 btfloat84cmp(double precision,real)
845 pg_lsn_lt(pg_lsn,pg_lsn)
846 pg_lsn_le(pg_lsn,pg_lsn)
847 pg_lsn_eq(pg_lsn,pg_lsn)
848 pg_lsn_ge(pg_lsn,pg_lsn)
849 pg_lsn_gt(pg_lsn,pg_lsn)
850 pg_lsn_ne(pg_lsn,pg_lsn)
851 pg_lsn_cmp(pg_lsn,pg_lsn)
853 xidneqint4(xid,integer)
858 starts_with(text,text)
859 macaddr8_eq(macaddr8,macaddr8)
860 macaddr8_lt(macaddr8,macaddr8)
861 macaddr8_le(macaddr8,macaddr8)
862 macaddr8_gt(macaddr8,macaddr8)
863 macaddr8_ge(macaddr8,macaddr8)
864 macaddr8_ne(macaddr8,macaddr8)
865 macaddr8_cmp(macaddr8,macaddr8)
874 uuid_extract_timestamp(uuid)
875 uuid_extract_version(uuid)
878 bytea_larger(bytea,bytea)
879 bytea_smaller(bytea,bytea)
880 -- Check that functions without argument are not marked as leakproof.
881 SELECT p1.oid::regprocedure
882 FROM pg_proc p1 JOIN pg_namespace pn
883 ON pronamespace = pn.oid
884 WHERE nspname = 'pg_catalog' AND proleakproof AND pronargs = 0
886 -- restore normal output mode
888 -- List of functions used by libpq's fe-lobj.c
890 -- If the output of this query changes, you probably broke libpq.
891 -- lo_initialize() assumes that there will be at most one match for
893 select proname, oid from pg_catalog.pg_proc
908 and pronamespace = (select oid from pg_catalog.pg_namespace
909 where nspname = 'pg_catalog')
912 ---------------+------
928 -- Check that all immutable functions are marked parallel safe
929 SELECT p1.oid, p1.proname
931 WHERE provolatile = 'i' AND proparallel = 'u';
936 -- **************** pg_cast ****************
937 -- Catch bogus values in pg_cast columns (other than cases detected by
941 WHERE castsource = 0 OR casttarget = 0 OR castcontext NOT IN ('e', 'a', 'i')
942 OR castmethod NOT IN ('f', 'b' ,'i');
943 oid | castsource | casttarget | castfunc | castcontext | castmethod
944 -----+------------+------------+----------+-------------+------------
947 -- Check that castfunc is nonzero only for cast methods that need a function,
948 -- and zero otherwise
951 WHERE (castmethod = 'f' AND castfunc = 0)
952 OR (castmethod IN ('b', 'i') AND castfunc <> 0);
953 oid | castsource | casttarget | castfunc | castcontext | castmethod
954 -----+------------+------------+----------+-------------+------------
957 -- Look for casts to/from the same type that aren't length coercion functions.
958 -- (We assume they are length coercions if they take multiple arguments.)
959 -- Such entries are not necessarily harmful, but they are useless.
962 WHERE castsource = casttarget AND castfunc = 0;
963 oid | castsource | casttarget | castfunc | castcontext | castmethod
964 -----+------------+------------+----------+-------------+------------
968 FROM pg_cast c, pg_proc p
969 WHERE c.castfunc = p.oid AND p.pronargs < 2 AND castsource = casttarget;
970 oid | castsource | casttarget | castfunc | castcontext | castmethod
971 -----+------------+------------+----------+-------------+------------
974 -- Look for cast functions that don't have the right signature. The
975 -- argument and result types in pg_proc must be the same as, or binary
976 -- compatible with, what it says in pg_cast.
977 -- As a special case, we allow casts from CHAR(n) that use functions
978 -- declared to take TEXT. This does not pass the binary-coercibility test
979 -- because CHAR(n)-to-TEXT normally invokes rtrim(). However, the results
980 -- are the same, so long as the function is one that ignores trailing blanks.
982 FROM pg_cast c, pg_proc p
983 WHERE c.castfunc = p.oid AND
984 (p.pronargs < 1 OR p.pronargs > 3
985 OR NOT (binary_coercible(c.castsource, p.proargtypes[0])
986 OR (c.castsource = 'character'::regtype AND
987 p.proargtypes[0] = 'text'::regtype))
988 OR NOT binary_coercible(p.prorettype, c.casttarget));
989 oid | castsource | casttarget | castfunc | castcontext | castmethod
990 -----+------------+------------+----------+-------------+------------
994 FROM pg_cast c, pg_proc p
995 WHERE c.castfunc = p.oid AND
996 ((p.pronargs > 1 AND p.proargtypes[1] != 'int4'::regtype) OR
997 (p.pronargs > 2 AND p.proargtypes[2] != 'bool'::regtype));
998 oid | castsource | casttarget | castfunc | castcontext | castmethod
999 -----+------------+------------+----------+-------------+------------
1002 -- Look for binary compatible casts that do not have the reverse
1003 -- direction registered as well, or where the reverse direction is not
1004 -- also binary compatible. This is legal, but usually not intended.
1005 -- As of 7.4, this finds the casts from text and varchar to bpchar, because
1006 -- those are binary-compatible while the reverse way goes through rtrim().
1007 -- As of 8.2, this finds the cast from cidr to inet, because that is a
1008 -- trivial binary coercion while the other way goes through inet_to_cidr().
1009 -- As of 8.3, this finds the casts from xml to text, varchar, and bpchar,
1010 -- because those are binary-compatible while the reverse goes through
1011 -- texttoxml(), which does an XML syntax check.
1012 -- As of 9.1, this finds the cast from pg_node_tree to text, which we
1013 -- intentionally do not provide a reverse pathway for.
1014 SELECT castsource::regtype, casttarget::regtype, castfunc, castcontext
1016 WHERE c.castmethod = 'b' AND
1017 NOT EXISTS (SELECT 1 FROM pg_cast k
1018 WHERE k.castmethod = 'b' AND
1019 k.castsource = c.casttarget AND
1020 k.casttarget = c.castsource);
1021 castsource | casttarget | castfunc | castcontext
1022 -------------------+-------------------+----------+-------------
1023 text | character | 0 | i
1024 character varying | character | 0 | i
1025 pg_node_tree | text | 0 | i
1026 pg_ndistinct | bytea | 0 | i
1027 pg_dependencies | bytea | 0 | i
1028 pg_mcv_list | bytea | 0 | i
1031 xml | character varying | 0 | a
1032 xml | character | 0 | a
1035 -- **************** pg_conversion ****************
1036 -- Look for illegal values in pg_conversion fields.
1037 SELECT c.oid, c.conname
1038 FROM pg_conversion as c
1039 WHERE c.conproc = 0 OR
1040 pg_encoding_to_char(conforencoding) = '' OR
1041 pg_encoding_to_char(contoencoding) = '';
1046 -- Look for conprocs that don't have the expected signature.
1047 SELECT p.oid, p.proname, c.oid, c.conname
1048 FROM pg_proc p, pg_conversion c
1049 WHERE p.oid = c.conproc AND
1050 (p.prorettype != 'int4'::regtype OR p.proretset OR
1052 p.proargtypes[0] != 'int4'::regtype OR
1053 p.proargtypes[1] != 'int4'::regtype OR
1054 p.proargtypes[2] != 'cstring'::regtype OR
1055 p.proargtypes[3] != 'internal'::regtype OR
1056 p.proargtypes[4] != 'int4'::regtype OR
1057 p.proargtypes[5] != 'bool'::regtype);
1058 oid | proname | oid | conname
1059 -----+---------+-----+---------
1062 -- Check for conprocs that don't perform the specific conversion that
1063 -- pg_conversion alleges they do, by trying to invoke each conversion
1064 -- on some simple ASCII data. (The conproc should throw an error if
1065 -- it doesn't accept the encodings that are passed to it.)
1066 -- Unfortunately, we can't test non-default conprocs this way, because
1067 -- there is no way to ask convert() to invoke them, and we cannot call
1068 -- them directly from SQL. But there are no non-default built-in
1069 -- conversions anyway.
1070 -- (Similarly, this doesn't cope with any search path issues.)
1071 SELECT c.oid, c.conname
1072 FROM pg_conversion as c
1073 WHERE condefault AND
1074 convert('ABC'::bytea, pg_encoding_to_char(conforencoding),
1075 pg_encoding_to_char(contoencoding)) != 'ABC';
1080 -- **************** pg_operator ****************
1081 -- Look for illegal values in pg_operator fields.
1082 SELECT o1.oid, o1.oprname
1083 FROM pg_operator as o1
1084 WHERE (o1.oprkind != 'b' AND o1.oprkind != 'l') OR
1085 o1.oprresult = 0 OR o1.oprcode = 0;
1090 -- Look for missing or unwanted operand types
1091 SELECT o1.oid, o1.oprname
1092 FROM pg_operator as o1
1093 WHERE (o1.oprleft = 0 and o1.oprkind != 'l') OR
1094 (o1.oprleft != 0 and o1.oprkind = 'l') OR
1100 -- Look for conflicting operator definitions (same names and input datatypes).
1101 SELECT o1.oid, o1.oprcode, o2.oid, o2.oprcode
1102 FROM pg_operator AS o1, pg_operator AS o2
1103 WHERE o1.oid != o2.oid AND
1104 o1.oprname = o2.oprname AND
1105 o1.oprkind = o2.oprkind AND
1106 o1.oprleft = o2.oprleft AND
1107 o1.oprright = o2.oprright;
1108 oid | oprcode | oid | oprcode
1109 -----+---------+-----+---------
1112 -- Look for commutative operators that don't commute.
1113 -- DEFINITIONAL NOTE: If A.oprcom = B, then x A y has the same result as y B x.
1114 -- We expect that B will always say that B.oprcom = A as well; that's not
1115 -- inherently essential, but it would be inefficient not to mark it so.
1116 SELECT o1.oid, o1.oprcode, o2.oid, o2.oprcode
1117 FROM pg_operator AS o1, pg_operator AS o2
1118 WHERE o1.oprcom = o2.oid AND
1119 (o1.oprkind != 'b' OR
1120 o1.oprleft != o2.oprright OR
1121 o1.oprright != o2.oprleft OR
1122 o1.oprresult != o2.oprresult OR
1123 o1.oid != o2.oprcom);
1124 oid | oprcode | oid | oprcode
1125 -----+---------+-----+---------
1128 -- Look for negatory operators that don't agree.
1129 -- DEFINITIONAL NOTE: If A.oprnegate = B, then both A and B must yield
1130 -- boolean results, and (x A y) == ! (x B y), or the equivalent for
1131 -- single-operand operators.
1132 -- We expect that B will always say that B.oprnegate = A as well; that's not
1133 -- inherently essential, but it would be inefficient not to mark it so.
1134 -- Also, A and B had better not be the same operator.
1135 SELECT o1.oid, o1.oprcode, o2.oid, o2.oprcode
1136 FROM pg_operator AS o1, pg_operator AS o2
1137 WHERE o1.oprnegate = o2.oid AND
1138 (o1.oprkind != o2.oprkind OR
1139 o1.oprleft != o2.oprleft OR
1140 o1.oprright != o2.oprright OR
1141 o1.oprresult != 'bool'::regtype OR
1142 o2.oprresult != 'bool'::regtype OR
1143 o1.oid != o2.oprnegate OR
1145 oid | oprcode | oid | oprcode
1146 -----+---------+-----+---------
1149 -- Make a list of the names of operators that are claimed to be commutator
1150 -- pairs. This list will grow over time, but before accepting a new entry
1151 -- make sure you didn't link the wrong operators.
1152 SELECT DISTINCT o1.oprname AS op1, o2.oprname AS op2
1153 FROM pg_operator o1, pg_operator o2
1154 WHERE o1.oprcom = o2.oid AND o1.oprname <= o2.oprname
1189 -- Likewise for negator pairs.
1190 SELECT DISTINCT o1.oprname AS op1, o2.oprname AS op2
1191 FROM pg_operator o1, pg_operator o2
1192 WHERE o1.oprnegate = o2.oid AND o1.oprname <= o2.oprname
1211 -- A mergejoinable or hashjoinable operator must be binary, must return
1212 -- boolean, and must have a commutator (itself, unless it's a cross-type
1214 SELECT o1.oid, o1.oprname FROM pg_operator AS o1
1215 WHERE (o1.oprcanmerge OR o1.oprcanhash) AND NOT
1216 (o1.oprkind = 'b' AND o1.oprresult = 'bool'::regtype AND o1.oprcom != 0);
1221 -- What's more, the commutator had better be mergejoinable/hashjoinable too.
1222 SELECT o1.oid, o1.oprname, o2.oid, o2.oprname
1223 FROM pg_operator AS o1, pg_operator AS o2
1224 WHERE o1.oprcom = o2.oid AND
1225 (o1.oprcanmerge != o2.oprcanmerge OR
1226 o1.oprcanhash != o2.oprcanhash);
1227 oid | oprname | oid | oprname
1228 -----+---------+-----+---------
1231 -- Mergejoinable operators should appear as equality members of btree index
1233 SELECT o1.oid, o1.oprname
1234 FROM pg_operator AS o1
1235 WHERE o1.oprcanmerge AND NOT EXISTS
1236 (SELECT 1 FROM pg_amop
1237 WHERE amopmethod = (SELECT oid FROM pg_am WHERE amname = 'btree') AND
1238 amopopr = o1.oid AND amopstrategy = 3);
1243 -- And the converse.
1244 SELECT o1.oid, o1.oprname, p.amopfamily
1245 FROM pg_operator AS o1, pg_amop p
1246 WHERE amopopr = o1.oid
1247 AND amopmethod = (SELECT oid FROM pg_am WHERE amname = 'btree')
1248 AND amopstrategy = 3
1249 AND NOT o1.oprcanmerge;
1250 oid | oprname | amopfamily
1251 -----+---------+------------
1254 -- Hashable operators should appear as members of hash index opfamilies.
1255 SELECT o1.oid, o1.oprname
1256 FROM pg_operator AS o1
1257 WHERE o1.oprcanhash AND NOT EXISTS
1258 (SELECT 1 FROM pg_amop
1259 WHERE amopmethod = (SELECT oid FROM pg_am WHERE amname = 'hash') AND
1260 amopopr = o1.oid AND amopstrategy = 1);
1265 -- And the converse.
1266 SELECT o1.oid, o1.oprname, p.amopfamily
1267 FROM pg_operator AS o1, pg_amop p
1268 WHERE amopopr = o1.oid
1269 AND amopmethod = (SELECT oid FROM pg_am WHERE amname = 'hash')
1270 AND NOT o1.oprcanhash;
1271 oid | oprname | amopfamily
1272 -----+---------+------------
1275 -- Check that each operator defined in pg_operator matches its oprcode entry
1276 -- in pg_proc. Easiest to do this separately for each oprkind.
1277 SELECT o1.oid, o1.oprname, p1.oid, p1.proname
1278 FROM pg_operator AS o1, pg_proc AS p1
1279 WHERE o1.oprcode = p1.oid AND
1280 o1.oprkind = 'b' AND
1282 OR NOT binary_coercible(p1.prorettype, o1.oprresult)
1283 OR NOT binary_coercible(o1.oprleft, p1.proargtypes[0])
1284 OR NOT binary_coercible(o1.oprright, p1.proargtypes[1]));
1285 oid | oprname | oid | proname
1286 -----+---------+-----+---------
1289 SELECT o1.oid, o1.oprname, p1.oid, p1.proname
1290 FROM pg_operator AS o1, pg_proc AS p1
1291 WHERE o1.oprcode = p1.oid AND
1292 o1.oprkind = 'l' AND
1294 OR NOT binary_coercible(p1.prorettype, o1.oprresult)
1295 OR NOT binary_coercible(o1.oprright, p1.proargtypes[0])
1296 OR o1.oprleft != 0);
1297 oid | oprname | oid | proname
1298 -----+---------+-----+---------
1301 -- If the operator is mergejoinable or hashjoinable, its underlying function
1302 -- should not be volatile.
1303 SELECT o1.oid, o1.oprname, p1.oid, p1.proname
1304 FROM pg_operator AS o1, pg_proc AS p1
1305 WHERE o1.oprcode = p1.oid AND
1306 (o1.oprcanmerge OR o1.oprcanhash) AND
1307 p1.provolatile = 'v';
1308 oid | oprname | oid | proname
1309 -----+---------+-----+---------
1312 -- If oprrest is set, the operator must return boolean,
1313 -- and it must link to a proc with the right signature
1314 -- to be a restriction selectivity estimator.
1315 -- The proc signature we want is: float8 proc(internal, oid, internal, int4)
1316 SELECT o1.oid, o1.oprname, p2.oid, p2.proname
1317 FROM pg_operator AS o1, pg_proc AS p2
1318 WHERE o1.oprrest = p2.oid AND
1319 (o1.oprresult != 'bool'::regtype OR
1320 p2.prorettype != 'float8'::regtype OR p2.proretset OR
1322 p2.proargtypes[0] != 'internal'::regtype OR
1323 p2.proargtypes[1] != 'oid'::regtype OR
1324 p2.proargtypes[2] != 'internal'::regtype OR
1325 p2.proargtypes[3] != 'int4'::regtype);
1326 oid | oprname | oid | proname
1327 -----+---------+-----+---------
1330 -- If oprjoin is set, the operator must be a binary boolean op,
1331 -- and it must link to a proc with the right signature
1332 -- to be a join selectivity estimator.
1333 -- The proc signature we want is: float8 proc(internal, oid, internal, int2, internal)
1334 -- (Note: the old signature with only 4 args is still allowed, but no core
1335 -- estimator should be using it.)
1336 SELECT o1.oid, o1.oprname, p2.oid, p2.proname
1337 FROM pg_operator AS o1, pg_proc AS p2
1338 WHERE o1.oprjoin = p2.oid AND
1339 (o1.oprkind != 'b' OR o1.oprresult != 'bool'::regtype OR
1340 p2.prorettype != 'float8'::regtype OR p2.proretset OR
1342 p2.proargtypes[0] != 'internal'::regtype OR
1343 p2.proargtypes[1] != 'oid'::regtype OR
1344 p2.proargtypes[2] != 'internal'::regtype OR
1345 p2.proargtypes[3] != 'int2'::regtype OR
1346 p2.proargtypes[4] != 'internal'::regtype);
1347 oid | oprname | oid | proname
1348 -----+---------+-----+---------
1351 -- Insist that all built-in pg_operator entries have descriptions
1352 SELECT o1.oid, o1.oprname
1353 FROM pg_operator as o1 LEFT JOIN pg_description as d
1354 ON o1.tableoid = d.classoid and o1.oid = d.objoid and d.objsubid = 0
1355 WHERE d.classoid IS NULL AND o1.oid <= 9999;
1360 -- Check that operators' underlying functions have suitable comments,
1361 -- namely 'implementation of XXX operator'. (Note: it's not necessary to
1362 -- put such comments into pg_proc.dat; initdb will generate them as needed.)
1363 -- In some cases involving legacy names for operators, there are multiple
1364 -- operators referencing the same pg_proc entry, so ignore operators whose
1365 -- comments say they are deprecated.
1366 -- We also have a few functions that are both operator support and meant to
1367 -- be called directly; those should have comments matching their operator.
1369 SELECT p.oid as p_oid, proname, o.oid as o_oid,
1370 pd.description as prodesc,
1371 'implementation of ' || oprname || ' operator' as expecteddesc,
1372 od.description as oprdesc
1373 FROM pg_proc p JOIN pg_operator o ON oprcode = p.oid
1374 LEFT JOIN pg_description pd ON
1375 (pd.objoid = p.oid and pd.classoid = p.tableoid and pd.objsubid = 0)
1376 LEFT JOIN pg_description od ON
1377 (od.objoid = o.oid and od.classoid = o.tableoid and od.objsubid = 0)
1380 SELECT * FROM funcdescs
1381 WHERE prodesc IS DISTINCT FROM expecteddesc
1382 AND oprdesc NOT LIKE 'deprecated%'
1383 AND prodesc IS DISTINCT FROM oprdesc;
1384 p_oid | proname | o_oid | prodesc | expecteddesc | oprdesc
1385 -------+---------+-------+---------+--------------+---------
1388 -- Show all the operator-implementation functions that have their own
1389 -- comments. This should happen only in cases where the function and
1390 -- operator syntaxes are both documented at the user level.
1391 -- This should be a pretty short list; it's mostly legacy cases.
1393 SELECT p.oid as p_oid, proname, o.oid as o_oid,
1394 pd.description as prodesc,
1395 'implementation of ' || oprname || ' operator' as expecteddesc,
1396 od.description as oprdesc
1397 FROM pg_proc p JOIN pg_operator o ON oprcode = p.oid
1398 LEFT JOIN pg_description pd ON
1399 (pd.objoid = p.oid and pd.classoid = p.tableoid and pd.objsubid = 0)
1400 LEFT JOIN pg_description od ON
1401 (od.objoid = o.oid and od.classoid = o.tableoid and od.objsubid = 0)
1404 SELECT p_oid, proname, prodesc FROM funcdescs
1405 WHERE prodesc IS DISTINCT FROM expecteddesc
1406 AND oprdesc NOT LIKE 'deprecated%'
1408 p_oid | proname | prodesc
1409 -------+-------------------------+-------------------------------------------------
1410 378 | array_append | append element onto end of array
1411 379 | array_prepend | prepend element onto front of array
1412 1035 | aclinsert | add/update ACL item
1413 1036 | aclremove | remove ACL item
1414 1037 | aclcontains | contains
1415 3217 | jsonb_extract_path | get value from jsonb with path elements
1416 3940 | jsonb_extract_path_text | get value from jsonb as text with path elements
1417 3951 | json_extract_path | get value from json with path elements
1418 3953 | json_extract_path_text | get value from json as text with path elements
1421 -- Operators that are commutator pairs should have identical volatility
1422 -- and leakproofness markings on their implementation functions.
1423 SELECT o1.oid, o1.oprcode, o2.oid, o2.oprcode
1424 FROM pg_operator AS o1, pg_operator AS o2, pg_proc AS p1, pg_proc AS p2
1425 WHERE o1.oprcom = o2.oid AND p1.oid = o1.oprcode AND p2.oid = o2.oprcode AND
1426 (p1.provolatile != p2.provolatile OR
1427 p1.proleakproof != p2.proleakproof);
1428 oid | oprcode | oid | oprcode
1429 -----+---------+-----+---------
1432 -- Likewise for negator pairs.
1433 SELECT o1.oid, o1.oprcode, o2.oid, o2.oprcode
1434 FROM pg_operator AS o1, pg_operator AS o2, pg_proc AS p1, pg_proc AS p2
1435 WHERE o1.oprnegate = o2.oid AND p1.oid = o1.oprcode AND p2.oid = o2.oprcode AND
1436 (p1.provolatile != p2.provolatile OR
1437 p1.proleakproof != p2.proleakproof);
1438 oid | oprcode | oid | oprcode
1439 -----+---------+-----+---------
1442 -- Btree comparison operators' functions should have the same volatility
1443 -- and leakproofness markings as the associated comparison support function.
1444 SELECT pp.oid::regprocedure as proc, pp.provolatile as vp, pp.proleakproof as lp,
1445 po.oid::regprocedure as opr, po.provolatile as vo, po.proleakproof as lo
1446 FROM pg_proc pp, pg_proc po, pg_operator o, pg_amproc ap, pg_amop ao
1447 WHERE pp.oid = ap.amproc AND po.oid = o.oprcode AND o.oid = ao.amopopr AND
1448 ao.amopmethod = (SELECT oid FROM pg_am WHERE amname = 'btree') AND
1449 ao.amopfamily = ap.amprocfamily AND
1450 ao.amoplefttype = ap.amproclefttype AND
1451 ao.amoprighttype = ap.amprocrighttype AND
1452 ap.amprocnum = 1 AND
1453 (pp.provolatile != po.provolatile OR
1454 pp.proleakproof != po.proleakproof)
1456 proc | vp | lp | opr | vo | lo
1457 ------+----+----+-----+----+----
1460 -- **************** pg_aggregate ****************
1461 -- Look for illegal values in pg_aggregate fields.
1462 SELECT ctid, aggfnoid::oid
1463 FROM pg_aggregate as a
1464 WHERE aggfnoid = 0 OR aggtransfn = 0 OR
1465 aggkind NOT IN ('n', 'o', 'h') OR
1466 aggnumdirectargs < 0 OR
1467 (aggkind = 'n' AND aggnumdirectargs > 0) OR
1468 aggfinalmodify NOT IN ('r', 's', 'w') OR
1469 aggmfinalmodify NOT IN ('r', 's', 'w') OR
1470 aggtranstype = 0 OR aggtransspace < 0 OR aggmtransspace < 0;
1475 -- Make sure the matching pg_proc entry is sensible, too.
1476 SELECT a.aggfnoid::oid, p.proname
1477 FROM pg_aggregate as a, pg_proc as p
1478 WHERE a.aggfnoid = p.oid AND
1479 (p.prokind != 'a' OR p.proretset OR p.pronargs < a.aggnumdirectargs);
1481 ----------+---------
1484 -- Make sure there are no prokind = PROKIND_AGGREGATE pg_proc entries without matches.
1487 WHERE p.prokind = 'a' AND
1488 NOT EXISTS (SELECT 1 FROM pg_aggregate a WHERE a.aggfnoid = p.oid);
1493 -- If there is no finalfn then the output type must be the transtype.
1494 SELECT a.aggfnoid::oid, p.proname
1495 FROM pg_aggregate as a, pg_proc as p
1496 WHERE a.aggfnoid = p.oid AND
1497 a.aggfinalfn = 0 AND p.prorettype != a.aggtranstype;
1499 ----------+---------
1502 -- Cross-check transfn against its entry in pg_proc.
1503 SELECT a.aggfnoid::oid, p.proname, ptr.oid, ptr.proname
1504 FROM pg_aggregate AS a, pg_proc AS p, pg_proc AS ptr
1505 WHERE a.aggfnoid = p.oid AND
1506 a.aggtransfn = ptr.oid AND
1508 OR NOT (ptr.pronargs =
1509 CASE WHEN a.aggkind = 'n' THEN p.pronargs + 1
1510 ELSE greatest(p.pronargs - a.aggnumdirectargs, 1) + 1 END)
1511 OR NOT binary_coercible(ptr.prorettype, a.aggtranstype)
1512 OR NOT binary_coercible(a.aggtranstype, ptr.proargtypes[0])
1513 OR (p.pronargs > 0 AND
1514 NOT binary_coercible(p.proargtypes[0], ptr.proargtypes[1]))
1515 OR (p.pronargs > 1 AND
1516 NOT binary_coercible(p.proargtypes[1], ptr.proargtypes[2]))
1517 OR (p.pronargs > 2 AND
1518 NOT binary_coercible(p.proargtypes[2], ptr.proargtypes[3]))
1519 OR (p.pronargs > 3 AND
1520 NOT binary_coercible(p.proargtypes[3], ptr.proargtypes[4]))
1521 -- we could carry the check further, but 4 args is enough for now
1524 aggfnoid | proname | oid | proname
1525 ----------+---------+-----+---------
1528 -- Cross-check finalfn (if present) against its entry in pg_proc.
1529 SELECT a.aggfnoid::oid, p.proname, pfn.oid, pfn.proname
1530 FROM pg_aggregate AS a, pg_proc AS p, pg_proc AS pfn
1531 WHERE a.aggfnoid = p.oid AND
1532 a.aggfinalfn = pfn.oid AND
1534 NOT binary_coercible(pfn.prorettype, p.prorettype) OR
1535 NOT binary_coercible(a.aggtranstype, pfn.proargtypes[0]) OR
1536 CASE WHEN a.aggfinalextra THEN pfn.pronargs != p.pronargs + 1
1537 ELSE pfn.pronargs != a.aggnumdirectargs + 1 END
1538 OR (pfn.pronargs > 1 AND
1539 NOT binary_coercible(p.proargtypes[0], pfn.proargtypes[1]))
1540 OR (pfn.pronargs > 2 AND
1541 NOT binary_coercible(p.proargtypes[1], pfn.proargtypes[2]))
1542 OR (pfn.pronargs > 3 AND
1543 NOT binary_coercible(p.proargtypes[2], pfn.proargtypes[3]))
1544 -- we could carry the check further, but 4 args is enough for now
1545 OR (pfn.pronargs > 4)
1547 aggfnoid | proname | oid | proname
1548 ----------+---------+-----+---------
1551 -- If transfn is strict then either initval should be non-NULL, or
1552 -- input type should match transtype so that the first non-null input
1553 -- can be assigned as the state value.
1554 SELECT a.aggfnoid::oid, p.proname, ptr.oid, ptr.proname
1555 FROM pg_aggregate AS a, pg_proc AS p, pg_proc AS ptr
1556 WHERE a.aggfnoid = p.oid AND
1557 a.aggtransfn = ptr.oid AND ptr.proisstrict AND
1558 a.agginitval IS NULL AND
1559 NOT binary_coercible(p.proargtypes[0], a.aggtranstype);
1560 aggfnoid | proname | oid | proname
1561 ----------+---------+-----+---------
1564 -- Check for inconsistent specifications of moving-aggregate columns.
1565 SELECT ctid, aggfnoid::oid
1566 FROM pg_aggregate as a
1567 WHERE aggmtranstype != 0 AND
1568 (aggmtransfn = 0 OR aggminvtransfn = 0);
1573 SELECT ctid, aggfnoid::oid
1574 FROM pg_aggregate as a
1575 WHERE aggmtranstype = 0 AND
1576 (aggmtransfn != 0 OR aggminvtransfn != 0 OR aggmfinalfn != 0 OR
1577 aggmtransspace != 0 OR aggminitval IS NOT NULL);
1582 -- If there is no mfinalfn then the output type must be the mtranstype.
1583 SELECT a.aggfnoid::oid, p.proname
1584 FROM pg_aggregate as a, pg_proc as p
1585 WHERE a.aggfnoid = p.oid AND
1586 a.aggmtransfn != 0 AND
1587 a.aggmfinalfn = 0 AND p.prorettype != a.aggmtranstype;
1589 ----------+---------
1592 -- Cross-check mtransfn (if present) against its entry in pg_proc.
1593 SELECT a.aggfnoid::oid, p.proname, ptr.oid, ptr.proname
1594 FROM pg_aggregate AS a, pg_proc AS p, pg_proc AS ptr
1595 WHERE a.aggfnoid = p.oid AND
1596 a.aggmtransfn = ptr.oid AND
1598 OR NOT (ptr.pronargs =
1599 CASE WHEN a.aggkind = 'n' THEN p.pronargs + 1
1600 ELSE greatest(p.pronargs - a.aggnumdirectargs, 1) + 1 END)
1601 OR NOT binary_coercible(ptr.prorettype, a.aggmtranstype)
1602 OR NOT binary_coercible(a.aggmtranstype, ptr.proargtypes[0])
1603 OR (p.pronargs > 0 AND
1604 NOT binary_coercible(p.proargtypes[0], ptr.proargtypes[1]))
1605 OR (p.pronargs > 1 AND
1606 NOT binary_coercible(p.proargtypes[1], ptr.proargtypes[2]))
1607 OR (p.pronargs > 2 AND
1608 NOT binary_coercible(p.proargtypes[2], ptr.proargtypes[3]))
1609 -- we could carry the check further, but 3 args is enough for now
1612 aggfnoid | proname | oid | proname
1613 ----------+---------+-----+---------
1616 -- Cross-check minvtransfn (if present) against its entry in pg_proc.
1617 SELECT a.aggfnoid::oid, p.proname, ptr.oid, ptr.proname
1618 FROM pg_aggregate AS a, pg_proc AS p, pg_proc AS ptr
1619 WHERE a.aggfnoid = p.oid AND
1620 a.aggminvtransfn = ptr.oid AND
1622 OR NOT (ptr.pronargs =
1623 CASE WHEN a.aggkind = 'n' THEN p.pronargs + 1
1624 ELSE greatest(p.pronargs - a.aggnumdirectargs, 1) + 1 END)
1625 OR NOT binary_coercible(ptr.prorettype, a.aggmtranstype)
1626 OR NOT binary_coercible(a.aggmtranstype, ptr.proargtypes[0])
1627 OR (p.pronargs > 0 AND
1628 NOT binary_coercible(p.proargtypes[0], ptr.proargtypes[1]))
1629 OR (p.pronargs > 1 AND
1630 NOT binary_coercible(p.proargtypes[1], ptr.proargtypes[2]))
1631 OR (p.pronargs > 2 AND
1632 NOT binary_coercible(p.proargtypes[2], ptr.proargtypes[3]))
1633 -- we could carry the check further, but 3 args is enough for now
1636 aggfnoid | proname | oid | proname
1637 ----------+---------+-----+---------
1640 -- Cross-check mfinalfn (if present) against its entry in pg_proc.
1641 SELECT a.aggfnoid::oid, p.proname, pfn.oid, pfn.proname
1642 FROM pg_aggregate AS a, pg_proc AS p, pg_proc AS pfn
1643 WHERE a.aggfnoid = p.oid AND
1644 a.aggmfinalfn = pfn.oid AND
1646 NOT binary_coercible(pfn.prorettype, p.prorettype) OR
1647 NOT binary_coercible(a.aggmtranstype, pfn.proargtypes[0]) OR
1648 CASE WHEN a.aggmfinalextra THEN pfn.pronargs != p.pronargs + 1
1649 ELSE pfn.pronargs != a.aggnumdirectargs + 1 END
1650 OR (pfn.pronargs > 1 AND
1651 NOT binary_coercible(p.proargtypes[0], pfn.proargtypes[1]))
1652 OR (pfn.pronargs > 2 AND
1653 NOT binary_coercible(p.proargtypes[1], pfn.proargtypes[2]))
1654 OR (pfn.pronargs > 3 AND
1655 NOT binary_coercible(p.proargtypes[2], pfn.proargtypes[3]))
1656 -- we could carry the check further, but 4 args is enough for now
1657 OR (pfn.pronargs > 4)
1659 aggfnoid | proname | oid | proname
1660 ----------+---------+-----+---------
1663 -- If mtransfn is strict then either minitval should be non-NULL, or
1664 -- input type should match mtranstype so that the first non-null input
1665 -- can be assigned as the state value.
1666 SELECT a.aggfnoid::oid, p.proname, ptr.oid, ptr.proname
1667 FROM pg_aggregate AS a, pg_proc AS p, pg_proc AS ptr
1668 WHERE a.aggfnoid = p.oid AND
1669 a.aggmtransfn = ptr.oid AND ptr.proisstrict AND
1670 a.aggminitval IS NULL AND
1671 NOT binary_coercible(p.proargtypes[0], a.aggmtranstype);
1672 aggfnoid | proname | oid | proname
1673 ----------+---------+-----+---------
1676 -- mtransfn and minvtransfn should have same strictness setting.
1677 SELECT a.aggfnoid::oid, p.proname, ptr.oid, ptr.proname, iptr.oid, iptr.proname
1678 FROM pg_aggregate AS a, pg_proc AS p, pg_proc AS ptr, pg_proc AS iptr
1679 WHERE a.aggfnoid = p.oid AND
1680 a.aggmtransfn = ptr.oid AND
1681 a.aggminvtransfn = iptr.oid AND
1682 ptr.proisstrict != iptr.proisstrict;
1683 aggfnoid | proname | oid | proname | oid | proname
1684 ----------+---------+-----+---------+-----+---------
1687 -- Check that all combine functions have signature
1688 -- combine(transtype, transtype) returns transtype
1689 SELECT a.aggfnoid, p.proname
1690 FROM pg_aggregate as a, pg_proc as p
1691 WHERE a.aggcombinefn = p.oid AND
1693 p.prorettype != p.proargtypes[0] OR
1694 p.prorettype != p.proargtypes[1] OR
1695 NOT binary_coercible(a.aggtranstype, p.proargtypes[0]));
1697 ----------+---------
1700 -- Check that no combine function for an INTERNAL transtype is strict.
1701 SELECT a.aggfnoid, p.proname
1702 FROM pg_aggregate as a, pg_proc as p
1703 WHERE a.aggcombinefn = p.oid AND
1704 a.aggtranstype = 'internal'::regtype AND p.proisstrict;
1706 ----------+---------
1709 -- serialize/deserialize functions should be specified only for aggregates
1710 -- with transtype internal and a combine function, and we should have both
1711 -- or neither of them.
1712 SELECT aggfnoid, aggtranstype, aggserialfn, aggdeserialfn
1714 WHERE (aggserialfn != 0 OR aggdeserialfn != 0)
1715 AND (aggtranstype != 'internal'::regtype OR aggcombinefn = 0 OR
1716 aggserialfn = 0 OR aggdeserialfn = 0);
1717 aggfnoid | aggtranstype | aggserialfn | aggdeserialfn
1718 ----------+--------------+-------------+---------------
1721 -- Check that all serialization functions have signature
1722 -- serialize(internal) returns bytea
1723 -- Also insist that they be strict; it's wasteful to run them on NULLs.
1724 SELECT a.aggfnoid, p.proname
1725 FROM pg_aggregate as a, pg_proc as p
1726 WHERE a.aggserialfn = p.oid AND
1727 (p.prorettype != 'bytea'::regtype OR p.pronargs != 1 OR
1728 p.proargtypes[0] != 'internal'::regtype OR
1731 ----------+---------
1734 -- Check that all deserialization functions have signature
1735 -- deserialize(bytea, internal) returns internal
1736 -- Also insist that they be strict; it's wasteful to run them on NULLs.
1737 SELECT a.aggfnoid, p.proname
1738 FROM pg_aggregate as a, pg_proc as p
1739 WHERE a.aggdeserialfn = p.oid AND
1740 (p.prorettype != 'internal'::regtype OR p.pronargs != 2 OR
1741 p.proargtypes[0] != 'bytea'::regtype OR
1742 p.proargtypes[1] != 'internal'::regtype OR
1745 ----------+---------
1748 -- Check that aggregates which have the same transition function also have
1749 -- the same combine, serialization, and deserialization functions.
1750 -- While that isn't strictly necessary, it's fishy if they don't.
1751 SELECT a.aggfnoid, a.aggcombinefn, a.aggserialfn, a.aggdeserialfn,
1752 b.aggfnoid, b.aggcombinefn, b.aggserialfn, b.aggdeserialfn
1754 pg_aggregate a, pg_aggregate b
1756 a.aggfnoid < b.aggfnoid AND a.aggtransfn = b.aggtransfn AND
1757 (a.aggcombinefn != b.aggcombinefn OR a.aggserialfn != b.aggserialfn
1758 OR a.aggdeserialfn != b.aggdeserialfn);
1759 aggfnoid | aggcombinefn | aggserialfn | aggdeserialfn | aggfnoid | aggcombinefn | aggserialfn | aggdeserialfn
1760 ----------+--------------+-------------+---------------+----------+--------------+-------------+---------------
1763 -- Cross-check aggsortop (if present) against pg_operator.
1764 -- We expect to find entries for bool_and, bool_or, every, max, and min.
1765 SELECT DISTINCT proname, oprname
1766 FROM pg_operator AS o, pg_aggregate AS a, pg_proc AS p
1767 WHERE a.aggfnoid = p.oid AND a.aggsortop = o.oid
1770 ----------+---------
1778 -- Check datatypes match
1779 SELECT a.aggfnoid::oid, o.oid
1780 FROM pg_operator AS o, pg_aggregate AS a, pg_proc AS p
1781 WHERE a.aggfnoid = p.oid AND a.aggsortop = o.oid AND
1782 (oprkind != 'b' OR oprresult != 'boolean'::regtype
1783 OR oprleft != p.proargtypes[0] OR oprright != p.proargtypes[0]);
1788 -- Check operator is a suitable btree opfamily member
1789 SELECT a.aggfnoid::oid, o.oid
1790 FROM pg_operator AS o, pg_aggregate AS a, pg_proc AS p
1791 WHERE a.aggfnoid = p.oid AND a.aggsortop = o.oid AND
1792 NOT EXISTS(SELECT 1 FROM pg_amop
1793 WHERE amopmethod = (SELECT oid FROM pg_am WHERE amname = 'btree')
1795 AND amoplefttype = o.oprleft
1796 AND amoprighttype = o.oprright);
1801 -- Check correspondence of btree strategies and names
1802 SELECT DISTINCT proname, oprname, amopstrategy
1803 FROM pg_operator AS o, pg_aggregate AS a, pg_proc AS p,
1805 WHERE a.aggfnoid = p.oid AND a.aggsortop = o.oid AND
1807 amopmethod = (SELECT oid FROM pg_am WHERE amname = 'btree')
1809 proname | oprname | amopstrategy
1810 ----------+---------+--------------
1818 -- Check that there are not aggregates with the same name and different
1819 -- numbers of arguments. While not technically wrong, we have a project policy
1820 -- to avoid this because it opens the door for confusion in connection with
1821 -- ORDER BY: novices frequently put the ORDER BY in the wrong place.
1822 -- See the fate of the single-argument form of string_agg() for history.
1823 -- (Note: we don't forbid users from creating such aggregates; the policy is
1824 -- just to think twice before creating built-in aggregates like this.)
1825 -- The only aggregates that should show up here are count(x) and count(*).
1826 SELECT p1.oid::regprocedure, p2.oid::regprocedure
1827 FROM pg_proc AS p1, pg_proc AS p2
1828 WHERE p1.oid < p2.oid AND p1.proname = p2.proname AND
1829 p1.prokind = 'a' AND p2.prokind = 'a' AND
1830 array_dims(p1.proargtypes) != array_dims(p2.proargtypes)
1833 --------------+---------
1834 count("any") | count()
1837 -- For the same reason, built-in aggregates with default arguments are no good.
1840 WHERE prokind = 'a' AND proargdefaults IS NOT NULL;
1845 -- For the same reason, we avoid creating built-in variadic aggregates, except
1846 -- that variadic ordered-set aggregates are OK (since they have special syntax
1847 -- that is not subject to the misplaced ORDER BY issue).
1848 SELECT p.oid, proname
1849 FROM pg_proc AS p JOIN pg_aggregate AS a ON a.aggfnoid = p.oid
1850 WHERE prokind = 'a' AND provariadic != 0 AND a.aggkind = 'n';
1855 -- **************** pg_opfamily ****************
1856 -- Look for illegal values in pg_opfamily fields
1858 FROM pg_opfamily as f
1859 WHERE f.opfmethod = 0 OR f.opfnamespace = 0;
1864 -- Look for opfamilies having no opclasses. While most validation of
1865 -- opfamilies is now handled by AM-specific amvalidate functions, that's
1866 -- driven from pg_opclass entries below, so an empty opfamily would not
1868 SELECT oid, opfname FROM pg_opfamily f
1869 WHERE NOT EXISTS (SELECT 1 FROM pg_opclass WHERE opcfamily = f.oid);
1874 -- **************** pg_opclass ****************
1875 -- Look for illegal values in pg_opclass fields
1877 FROM pg_opclass AS c1
1878 WHERE c1.opcmethod = 0 OR c1.opcnamespace = 0 OR c1.opcfamily = 0
1879 OR c1.opcintype = 0;
1884 -- opcmethod must match owning opfamily's opfmethod
1885 SELECT c1.oid, f1.oid
1886 FROM pg_opclass AS c1, pg_opfamily AS f1
1887 WHERE c1.opcfamily = f1.oid AND c1.opcmethod != f1.opfmethod;
1892 -- There should not be multiple entries in pg_opclass with opcdefault true
1893 -- and the same opcmethod/opcintype combination.
1894 SELECT c1.oid, c2.oid
1895 FROM pg_opclass AS c1, pg_opclass AS c2
1896 WHERE c1.oid != c2.oid AND
1897 c1.opcmethod = c2.opcmethod AND c1.opcintype = c2.opcintype AND
1898 c1.opcdefault AND c2.opcdefault;
1903 -- Ask access methods to validate opclasses
1904 -- (this replaces a lot of SQL-level checks that used to be done in this file)
1905 SELECT oid, opcname FROM pg_opclass WHERE NOT amvalidate(oid);
1910 -- **************** pg_am ****************
1911 -- Look for illegal values in pg_am fields
1912 SELECT a1.oid, a1.amname
1914 WHERE a1.amhandler = 0;
1919 -- Check for index amhandler functions with the wrong signature
1920 SELECT a1.oid, a1.amname, p1.oid, p1.proname
1921 FROM pg_am AS a1, pg_proc AS p1
1922 WHERE p1.oid = a1.amhandler AND a1.amtype = 'i' AND
1923 (p1.prorettype != 'index_am_handler'::regtype
1926 OR p1.proargtypes[0] != 'internal'::regtype);
1927 oid | amname | oid | proname
1928 -----+--------+-----+---------
1931 -- Check for table amhandler functions with the wrong signature
1932 SELECT a1.oid, a1.amname, p1.oid, p1.proname
1933 FROM pg_am AS a1, pg_proc AS p1
1934 WHERE p1.oid = a1.amhandler AND a1.amtype = 't' AND
1935 (p1.prorettype != 'table_am_handler'::regtype
1938 OR p1.proargtypes[0] != 'internal'::regtype);
1939 oid | amname | oid | proname
1940 -----+--------+-----+---------
1943 -- **************** pg_amop ****************
1944 -- Look for illegal values in pg_amop fields
1945 SELECT a1.amopfamily, a1.amopstrategy
1947 WHERE a1.amopfamily = 0 OR a1.amoplefttype = 0 OR a1.amoprighttype = 0
1948 OR a1.amopopr = 0 OR a1.amopmethod = 0 OR a1.amopstrategy < 1;
1949 amopfamily | amopstrategy
1950 ------------+--------------
1953 SELECT a1.amopfamily, a1.amopstrategy
1955 WHERE NOT ((a1.amoppurpose = 's' AND a1.amopsortfamily = 0) OR
1956 (a1.amoppurpose = 'o' AND a1.amopsortfamily <> 0));
1957 amopfamily | amopstrategy
1958 ------------+--------------
1961 -- amopmethod must match owning opfamily's opfmethod
1962 SELECT a1.oid, f1.oid
1963 FROM pg_amop AS a1, pg_opfamily AS f1
1964 WHERE a1.amopfamily = f1.oid AND a1.amopmethod != f1.opfmethod;
1969 -- Make a list of all the distinct operator names being used in particular
1970 -- strategy slots. This is a bit hokey, since the list might need to change
1971 -- in future releases, but it's an effective way of spotting mistakes such as
1972 -- swapping two operators within a family.
1973 SELECT DISTINCT amopmethod, amopstrategy, oprname
1974 FROM pg_amop a1 LEFT JOIN pg_operator o1 ON amopopr = o1.oid
1976 amopmethod | amopstrategy | oprname
1977 ------------+--------------+---------
2104 -- Check that all opclass search operators have selectivity estimators.
2105 -- This is not absolutely required, but it seems a reasonable thing
2106 -- to insist on for all standard datatypes.
2107 SELECT a1.amopfamily, a1.amopopr, o1.oid, o1.oprname
2108 FROM pg_amop AS a1, pg_operator AS o1
2109 WHERE a1.amopopr = o1.oid AND a1.amoppurpose = 's' AND
2110 (o1.oprrest = 0 OR o1.oprjoin = 0);
2111 amopfamily | amopopr | oid | oprname
2112 ------------+---------+-----+---------
2115 -- Check that each opclass in an opfamily has associated operators, that is
2116 -- ones whose oprleft matches opcintype (possibly by coercion).
2117 SELECT c1.opcname, c1.opcfamily
2118 FROM pg_opclass AS c1
2119 WHERE NOT EXISTS(SELECT 1 FROM pg_amop AS a1
2120 WHERE a1.amopfamily = c1.opcfamily
2121 AND binary_coercible(c1.opcintype, a1.amoplefttype));
2123 ---------+-----------
2126 -- Check that each operator listed in pg_amop has an associated opclass,
2127 -- that is one whose opcintype matches oprleft (possibly by coercion).
2128 -- Otherwise the operator is useless because it cannot be matched to an index.
2129 -- (In principle it could be useful to list such operators in multiple-datatype
2130 -- btree opfamilies, but in practice you'd expect there to be an opclass for
2131 -- every datatype the family knows about.)
2132 SELECT a1.amopfamily, a1.amopstrategy, a1.amopopr
2134 WHERE NOT EXISTS(SELECT 1 FROM pg_opclass AS c1
2135 WHERE c1.opcfamily = a1.amopfamily
2136 AND binary_coercible(c1.opcintype, a1.amoplefttype));
2137 amopfamily | amopstrategy | amopopr
2138 ------------+--------------+---------
2141 -- Operators that are primary members of opclasses must be immutable (else
2142 -- it suggests that the index ordering isn't fixed). Operators that are
2143 -- cross-type members need only be stable, since they are just shorthands
2144 -- for index probe queries.
2145 SELECT a1.amopfamily, a1.amopopr, o1.oprname, p1.prosrc
2146 FROM pg_amop AS a1, pg_operator AS o1, pg_proc AS p1
2147 WHERE a1.amopopr = o1.oid AND o1.oprcode = p1.oid AND
2148 a1.amoplefttype = a1.amoprighttype AND
2149 p1.provolatile != 'i';
2150 amopfamily | amopopr | oprname | prosrc
2151 ------------+---------+---------+--------
2154 SELECT a1.amopfamily, a1.amopopr, o1.oprname, p1.prosrc
2155 FROM pg_amop AS a1, pg_operator AS o1, pg_proc AS p1
2156 WHERE a1.amopopr = o1.oid AND o1.oprcode = p1.oid AND
2157 a1.amoplefttype != a1.amoprighttype AND
2158 p1.provolatile = 'v';
2159 amopfamily | amopopr | oprname | prosrc
2160 ------------+---------+---------+--------
2163 -- **************** pg_amproc ****************
2164 -- Look for illegal values in pg_amproc fields
2165 SELECT a1.amprocfamily, a1.amprocnum
2166 FROM pg_amproc as a1
2167 WHERE a1.amprocfamily = 0 OR a1.amproclefttype = 0 OR a1.amprocrighttype = 0
2168 OR a1.amprocnum < 0 OR a1.amproc = 0;
2169 amprocfamily | amprocnum
2170 --------------+-----------
2173 -- Support routines that are primary members of opfamilies must be immutable
2174 -- (else it suggests that the index ordering isn't fixed). But cross-type
2175 -- members need only be stable, since they are just shorthands
2176 -- for index probe queries.
2177 SELECT a1.amprocfamily, a1.amproc, p1.prosrc
2178 FROM pg_amproc AS a1, pg_proc AS p1
2179 WHERE a1.amproc = p1.oid AND
2180 a1.amproclefttype = a1.amprocrighttype AND
2181 p1.provolatile != 'i';
2182 amprocfamily | amproc | prosrc
2183 --------------+--------+--------
2186 SELECT a1.amprocfamily, a1.amproc, p1.prosrc
2187 FROM pg_amproc AS a1, pg_proc AS p1
2188 WHERE a1.amproc = p1.oid AND
2189 a1.amproclefttype != a1.amprocrighttype AND
2190 p1.provolatile = 'v';
2191 amprocfamily | amproc | prosrc
2192 --------------+--------+--------
2195 -- Almost all of the core distribution's Btree opclasses can use one of the
2196 -- two generic "equalimage" functions as their support function 4. Look for
2197 -- opclasses that don't allow deduplication unconditionally here.
2199 -- Newly added Btree opclasses don't have to support deduplication. It will
2200 -- usually be trivial to add support, though. Note that the expected output
2201 -- of this part of the test will need to be updated when a new opclass cannot
2202 -- support deduplication (by using btequalimage).
2203 SELECT amp.amproc::regproc AS proc, opf.opfname AS opfamily_name,
2204 opc.opcname AS opclass_name, opc.opcintype::regtype AS opcintype
2206 JOIN pg_opclass AS opc ON opc.opcmethod = am.oid
2207 JOIN pg_opfamily AS opf ON opc.opcfamily = opf.oid
2208 LEFT JOIN pg_amproc AS amp ON amp.amprocfamily = opf.oid AND
2209 amp.amproclefttype = opc.opcintype AND amp.amprocnum = 4
2210 WHERE am.amname = 'btree' AND
2211 amp.amproc IS DISTINCT FROM 'btequalimage'::regproc
2213 proc | opfamily_name | opclass_name | opcintype
2214 --------------------+------------------+------------------+------------------
2215 btvarstrequalimage | bpchar_ops | bpchar_ops | character
2216 btvarstrequalimage | text_ops | name_ops | name
2217 btvarstrequalimage | text_ops | text_ops | text
2218 btvarstrequalimage | text_ops | varchar_ops | text
2219 | array_ops | array_ops | anyarray
2220 | float_ops | float4_ops | real
2221 | float_ops | float8_ops | double precision
2222 | interval_ops | interval_ops | interval
2223 | jsonb_ops | jsonb_ops | jsonb
2224 | multirange_ops | multirange_ops | anymultirange
2225 | numeric_ops | numeric_ops | numeric
2226 | range_ops | range_ops | anyrange
2227 | record_image_ops | record_image_ops | record
2228 | record_ops | record_ops | record
2229 | tsquery_ops | tsquery_ops | tsquery
2230 | tsvector_ops | tsvector_ops | tsvector
2233 -- **************** pg_index ****************
2234 -- Look for illegal values in pg_index fields.
2235 SELECT indexrelid, indrelid
2237 WHERE indexrelid = 0 OR indrelid = 0 OR
2238 indnatts <= 0 OR indnatts > 32;
2239 indexrelid | indrelid
2240 ------------+----------
2243 -- oidvector and int2vector fields should be of length indnatts.
2244 SELECT indexrelid, indrelid
2246 WHERE array_lower(indkey, 1) != 0 OR array_upper(indkey, 1) != indnatts-1 OR
2247 array_lower(indclass, 1) != 0 OR array_upper(indclass, 1) != indnatts-1 OR
2248 array_lower(indcollation, 1) != 0 OR array_upper(indcollation, 1) != indnatts-1 OR
2249 array_lower(indoption, 1) != 0 OR array_upper(indoption, 1) != indnatts-1;
2250 indexrelid | indrelid
2251 ------------+----------
2254 -- Check that opclasses and collations match the underlying columns.
2255 -- (As written, this test ignores expression indexes.)
2256 SELECT indexrelid::regclass, indrelid::regclass, attname, atttypid::regtype, opcname
2257 FROM (SELECT indexrelid, indrelid, unnest(indkey) as ikey,
2258 unnest(indclass) as iclass, unnest(indcollation) as icoll
2262 WHERE a.attrelid = indrelid AND a.attnum = ikey AND opc.oid = iclass AND
2263 (NOT binary_coercible(atttypid, opcintype) OR icoll != attcollation);
2264 indexrelid | indrelid | attname | atttypid | opcname
2265 ------------+----------+---------+----------+---------
2268 -- For system catalogs, be even tighter: nearly all indexes should be
2269 -- exact type matches not binary-coercible matches. At this writing
2270 -- the only exception is an OID index on a regproc column.
2271 SELECT indexrelid::regclass, indrelid::regclass, attname, atttypid::regtype, opcname
2272 FROM (SELECT indexrelid, indrelid, unnest(indkey) as ikey,
2273 unnest(indclass) as iclass, unnest(indcollation) as icoll
2275 WHERE indrelid < 16384) ss,
2278 WHERE a.attrelid = indrelid AND a.attnum = ikey AND opc.oid = iclass AND
2279 (opcintype != atttypid OR icoll != attcollation)
2281 indexrelid | indrelid | attname | atttypid | opcname
2282 --------------------------+--------------+----------+----------+---------
2283 pg_aggregate_fnoid_index | pg_aggregate | aggfnoid | regproc | oid_ops
2286 -- Check for system catalogs with collation-sensitive ordering. This is not
2287 -- a representational error in pg_index, but simply wrong catalog design.
2288 -- It's bad because we expect to be able to clone template0 and assign the
2289 -- copy a different database collation. It would especially not work for
2291 SELECT relname, attname, attcollation
2292 FROM pg_class c, pg_attribute a
2293 WHERE c.oid = attrelid AND c.oid < 16384 AND
2294 c.relkind != 'v' AND -- we don't care about columns in views
2295 attcollation != 0 AND
2296 attcollation != (SELECT oid FROM pg_collation WHERE collname = 'C');
2297 relname | attname | attcollation
2298 ---------+---------+--------------
2301 -- Double-check that collation-sensitive indexes have "C" collation, too.
2302 SELECT indexrelid::regclass, indrelid::regclass, iclass, icoll
2303 FROM (SELECT indexrelid, indrelid,
2304 unnest(indclass) as iclass, unnest(indcollation) as icoll
2306 WHERE indrelid < 16384) ss
2307 WHERE icoll != 0 AND
2308 icoll != (SELECT oid FROM pg_collation WHERE collname = 'C');
2309 indexrelid | indrelid | iclass | icoll
2310 ------------+----------+--------+-------