1--
2-- OPR_SANITY
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.
6--
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.
11--
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.
16--
17-- NB: run this test earlier than the create_operator test, because
18-- that test creates some bogus operators...
19
20
21-- **************** pg_proc ****************
22
23-- Look for illegal values in pg_proc fields.
24
25SELECT p1.oid, p1.proname
26FROM pg_proc as p1
27WHERE p1.prolang = 0 OR p1.prorettype = 0 OR
28       p1.pronargs < 0 OR
29       p1.pronargdefaults < 0 OR
30       p1.pronargdefaults > p1.pronargs OR
31       array_lower(p1.proargtypes, 1) != 0 OR
32       array_upper(p1.proargtypes, 1) != p1.pronargs-1 OR
33       0::oid = ANY (p1.proargtypes) OR
34       procost <= 0 OR
35       CASE WHEN proretset THEN prorows <= 0 ELSE prorows != 0 END OR
36       prokind NOT IN ('f', 'a', 'w', 'p') OR
37       provolatile NOT IN ('i', 's', 'v') OR
38       proparallel NOT IN ('s', 'r', 'u');
39
40-- prosrc should never be null; it can be empty only if prosqlbody isn't null
41SELECT p1.oid, p1.proname
42FROM pg_proc as p1
43WHERE prosrc IS NULL;
44SELECT p1.oid, p1.proname
45FROM pg_proc as p1
46WHERE (prosrc = '' OR prosrc = '-') AND prosqlbody IS NULL;
47
48-- proretset should only be set for normal functions
49SELECT p1.oid, p1.proname
50FROM pg_proc AS p1
51WHERE proretset AND prokind != 'f';
52
53-- currently, no built-in functions should be SECURITY DEFINER;
54-- this might change in future, but there will probably never be many.
55SELECT p1.oid, p1.proname
56FROM pg_proc AS p1
57WHERE prosecdef
58ORDER BY 1;
59
60-- pronargdefaults should be 0 iff proargdefaults is null
61SELECT p1.oid, p1.proname
62FROM pg_proc AS p1
63WHERE (pronargdefaults <> 0) != (proargdefaults IS NOT NULL);
64
65-- probin should be non-empty for C functions, null everywhere else
66SELECT p1.oid, p1.proname
67FROM pg_proc as p1
68WHERE prolang = 13 AND (probin IS NULL OR probin = '' OR probin = '-');
69
70SELECT p1.oid, p1.proname
71FROM pg_proc as p1
72WHERE prolang != 13 AND probin IS NOT NULL;
73
74-- Look for conflicting proc definitions (same names and input datatypes).
75-- (This test should be dead code now that we have the unique index
76-- pg_proc_proname_args_nsp_index, but I'll leave it in anyway.)
77
78SELECT p1.oid, p1.proname, p2.oid, p2.proname
79FROM pg_proc AS p1, pg_proc AS p2
80WHERE p1.oid != p2.oid AND
81    p1.proname = p2.proname AND
82    p1.pronargs = p2.pronargs AND
83    p1.proargtypes = p2.proargtypes;
84
85-- Considering only built-in procs (prolang = 12), look for multiple uses
86-- of the same internal function (ie, matching prosrc fields).  It's OK to
87-- have several entries with different pronames for the same internal function,
88-- but conflicts in the number of arguments and other critical items should
89-- be complained of.  (We don't check data types here; see next query.)
90-- Note: ignore aggregate functions here, since they all point to the same
91-- dummy built-in function.
92
93SELECT p1.oid, p1.proname, p2.oid, p2.proname
94FROM pg_proc AS p1, pg_proc AS p2
95WHERE p1.oid < p2.oid AND
96    p1.prosrc = p2.prosrc AND
97    p1.prolang = 12 AND p2.prolang = 12 AND
98    (p1.prokind != 'a' OR p2.prokind != 'a') AND
99    (p1.prolang != p2.prolang OR
100     p1.prokind != p2.prokind OR
101     p1.prosecdef != p2.prosecdef OR
102     p1.proleakproof != p2.proleakproof OR
103     p1.proisstrict != p2.proisstrict OR
104     p1.proretset != p2.proretset OR
105     p1.provolatile != p2.provolatile OR
106     p1.pronargs != p2.pronargs);
107
108-- Look for uses of different type OIDs in the argument/result type fields
109-- for different aliases of the same built-in function.
110-- This indicates that the types are being presumed to be binary-equivalent,
111-- or that the built-in function is prepared to deal with different types.
112-- That's not wrong, necessarily, but we make lists of all the types being
113-- so treated.  Note that the expected output of this part of the test will
114-- need to be modified whenever new pairs of types are made binary-equivalent,
115-- or when new polymorphic built-in functions are added!
116-- Note: ignore aggregate functions here, since they all point to the same
117-- dummy built-in function.  Likewise, ignore range and multirange constructor
118-- functions.
119
120SELECT DISTINCT p1.prorettype::regtype, p2.prorettype::regtype
121FROM pg_proc AS p1, pg_proc AS p2
122WHERE p1.oid != p2.oid AND
123    p1.prosrc = p2.prosrc AND
124    p1.prolang = 12 AND p2.prolang = 12 AND
125    p1.prokind != 'a' AND p2.prokind != 'a' AND
126    p1.prosrc NOT LIKE E'range\\_constructor_' AND
127    p2.prosrc NOT LIKE E'range\\_constructor_' AND
128    p1.prosrc NOT LIKE E'multirange\\_constructor_' AND
129    p2.prosrc NOT LIKE E'multirange\\_constructor_' AND
130    (p1.prorettype < p2.prorettype)
131ORDER BY 1, 2;
132
133SELECT DISTINCT p1.proargtypes[0]::regtype, p2.proargtypes[0]::regtype
134FROM pg_proc AS p1, pg_proc AS p2
135WHERE p1.oid != p2.oid AND
136    p1.prosrc = p2.prosrc AND
137    p1.prolang = 12 AND p2.prolang = 12 AND
138    p1.prokind != 'a' AND p2.prokind != 'a' AND
139    p1.prosrc NOT LIKE E'range\\_constructor_' AND
140    p2.prosrc NOT LIKE E'range\\_constructor_' AND
141    p1.prosrc NOT LIKE E'multirange\\_constructor_' AND
142    p2.prosrc NOT LIKE E'multirange\\_constructor_' AND
143    (p1.proargtypes[0] < p2.proargtypes[0])
144ORDER BY 1, 2;
145
146SELECT DISTINCT p1.proargtypes[1]::regtype, p2.proargtypes[1]::regtype
147FROM pg_proc AS p1, pg_proc AS p2
148WHERE p1.oid != p2.oid AND
149    p1.prosrc = p2.prosrc AND
150    p1.prolang = 12 AND p2.prolang = 12 AND
151    p1.prokind != 'a' AND p2.prokind != 'a' AND
152    p1.prosrc NOT LIKE E'range\\_constructor_' AND
153    p2.prosrc NOT LIKE E'range\\_constructor_' AND
154    p1.prosrc NOT LIKE E'multirange\\_constructor_' AND
155    p2.prosrc NOT LIKE E'multirange\\_constructor_' AND
156    (p1.proargtypes[1] < p2.proargtypes[1])
157ORDER BY 1, 2;
158
159SELECT DISTINCT p1.proargtypes[2]::regtype, p2.proargtypes[2]::regtype
160FROM pg_proc AS p1, pg_proc AS p2
161WHERE p1.oid != p2.oid AND
162    p1.prosrc = p2.prosrc AND
163    p1.prolang = 12 AND p2.prolang = 12 AND
164    p1.prokind != 'a' AND p2.prokind != 'a' AND
165    (p1.proargtypes[2] < p2.proargtypes[2])
166ORDER BY 1, 2;
167
168SELECT DISTINCT p1.proargtypes[3]::regtype, p2.proargtypes[3]::regtype
169FROM pg_proc AS p1, pg_proc AS p2
170WHERE p1.oid != p2.oid AND
171    p1.prosrc = p2.prosrc AND
172    p1.prolang = 12 AND p2.prolang = 12 AND
173    p1.prokind != 'a' AND p2.prokind != 'a' AND
174    (p1.proargtypes[3] < p2.proargtypes[3])
175ORDER BY 1, 2;
176
177SELECT DISTINCT p1.proargtypes[4]::regtype, p2.proargtypes[4]::regtype
178FROM pg_proc AS p1, pg_proc AS p2
179WHERE p1.oid != p2.oid AND
180    p1.prosrc = p2.prosrc AND
181    p1.prolang = 12 AND p2.prolang = 12 AND
182    p1.prokind != 'a' AND p2.prokind != 'a' AND
183    (p1.proargtypes[4] < p2.proargtypes[4])
184ORDER BY 1, 2;
185
186SELECT DISTINCT p1.proargtypes[5]::regtype, p2.proargtypes[5]::regtype
187FROM pg_proc AS p1, pg_proc AS p2
188WHERE 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.proargtypes[5] < p2.proargtypes[5])
193ORDER BY 1, 2;
194
195SELECT DISTINCT p1.proargtypes[6]::regtype, p2.proargtypes[6]::regtype
196FROM pg_proc AS p1, pg_proc AS p2
197WHERE p1.oid != p2.oid AND
198    p1.prosrc = p2.prosrc AND
199    p1.prolang = 12 AND p2.prolang = 12 AND
200    p1.prokind != 'a' AND p2.prokind != 'a' AND
201    (p1.proargtypes[6] < p2.proargtypes[6])
202ORDER BY 1, 2;
203
204SELECT DISTINCT p1.proargtypes[7]::regtype, p2.proargtypes[7]::regtype
205FROM pg_proc AS p1, pg_proc AS p2
206WHERE p1.oid != p2.oid AND
207    p1.prosrc = p2.prosrc AND
208    p1.prolang = 12 AND p2.prolang = 12 AND
209    p1.prokind != 'a' AND p2.prokind != 'a' AND
210    (p1.proargtypes[7] < p2.proargtypes[7])
211ORDER BY 1, 2;
212
213-- Look for functions that return type "internal" and do not have any
214-- "internal" argument.  Such a function would be a security hole since
215-- it might be used to call an internal function from an SQL command.
216-- As of 7.3 this query should find only internal_in, which is safe because
217-- it always throws an error when called.
218
219SELECT p1.oid, p1.proname
220FROM pg_proc as p1
221WHERE p1.prorettype = 'internal'::regtype AND NOT
222    'internal'::regtype = ANY (p1.proargtypes);
223
224-- Look for functions that return a polymorphic type and do not have any
225-- polymorphic argument.  Calls of such functions would be unresolvable
226-- at parse time.  As of 9.6 this query should find only some input functions
227-- and GiST support functions associated with these pseudotypes.
228
229SELECT p1.oid, p1.proname
230FROM pg_proc as p1
231WHERE p1.prorettype IN
232    ('anyelement'::regtype, 'anyarray'::regtype, 'anynonarray'::regtype,
233     'anyenum'::regtype)
234  AND NOT
235    ('anyelement'::regtype = ANY (p1.proargtypes) OR
236     'anyarray'::regtype = ANY (p1.proargtypes) OR
237     'anynonarray'::regtype = ANY (p1.proargtypes) OR
238     'anyenum'::regtype = ANY (p1.proargtypes) OR
239     'anyrange'::regtype = ANY (p1.proargtypes) OR
240     'anymultirange'::regtype = ANY (p1.proargtypes))
241ORDER BY 2;
242
243-- anyrange and anymultirange are tighter than the rest, can only resolve
244-- from each other
245
246SELECT p1.oid, p1.proname
247FROM pg_proc as p1
248WHERE p1.prorettype IN ('anyrange'::regtype, 'anymultirange'::regtype)
249  AND NOT
250    ('anyrange'::regtype = ANY (p1.proargtypes) OR
251      'anymultirange'::regtype = ANY (p1.proargtypes))
252ORDER BY 2;
253
254-- similarly for the anycompatible family
255
256SELECT p1.oid, p1.proname
257FROM pg_proc as p1
258WHERE p1.prorettype IN
259    ('anycompatible'::regtype, 'anycompatiblearray'::regtype,
260     'anycompatiblenonarray'::regtype)
261  AND NOT
262    ('anycompatible'::regtype = ANY (p1.proargtypes) OR
263     'anycompatiblearray'::regtype = ANY (p1.proargtypes) OR
264     'anycompatiblenonarray'::regtype = ANY (p1.proargtypes) OR
265     'anycompatiblerange'::regtype = ANY (p1.proargtypes))
266ORDER BY 2;
267
268SELECT p1.oid, p1.proname
269FROM pg_proc as p1
270WHERE p1.prorettype = 'anycompatiblerange'::regtype
271  AND NOT
272     'anycompatiblerange'::regtype = ANY (p1.proargtypes)
273ORDER BY 2;
274
275
276-- Look for functions that accept cstring and are neither datatype input
277-- functions nor encoding conversion functions.  It's almost never a good
278-- idea to use cstring input for a function meant to be called from SQL;
279-- text should be used instead, because cstring lacks suitable casts.
280-- As of 9.6 this query should find only cstring_out and cstring_send.
281-- However, we must manually exclude shell_in, which might or might not be
282-- rejected by the EXISTS clause depending on whether there are currently
283-- any shell types.
284
285SELECT p1.oid, p1.proname
286FROM pg_proc as p1
287WHERE 'cstring'::regtype = ANY (p1.proargtypes)
288    AND NOT EXISTS(SELECT 1 FROM pg_type WHERE typinput = p1.oid)
289    AND NOT EXISTS(SELECT 1 FROM pg_conversion WHERE conproc = p1.oid)
290    AND p1.oid != 'shell_in(cstring)'::regprocedure
291ORDER BY 1;
292
293-- Likewise, look for functions that return cstring and aren't datatype output
294-- functions nor typmod output functions.
295-- As of 9.6 this query should find only cstring_in and cstring_recv.
296-- However, we must manually exclude shell_out.
297
298SELECT p1.oid, p1.proname
299FROM pg_proc as p1
300WHERE  p1.prorettype = 'cstring'::regtype
301    AND NOT EXISTS(SELECT 1 FROM pg_type WHERE typoutput = p1.oid)
302    AND NOT EXISTS(SELECT 1 FROM pg_type WHERE typmodout = p1.oid)
303    AND p1.oid != 'shell_out(void)'::regprocedure
304ORDER BY 1;
305
306-- Check for length inconsistencies between the various argument-info arrays.
307
308SELECT p1.oid, p1.proname
309FROM pg_proc as p1
310WHERE proallargtypes IS NOT NULL AND
311    array_length(proallargtypes,1) < array_length(proargtypes,1);
312
313SELECT p1.oid, p1.proname
314FROM pg_proc as p1
315WHERE proargmodes IS NOT NULL AND
316    array_length(proargmodes,1) < array_length(proargtypes,1);
317
318SELECT p1.oid, p1.proname
319FROM pg_proc as p1
320WHERE proargnames IS NOT NULL AND
321    array_length(proargnames,1) < array_length(proargtypes,1);
322
323SELECT p1.oid, p1.proname
324FROM pg_proc as p1
325WHERE proallargtypes IS NOT NULL AND proargmodes IS NOT NULL AND
326    array_length(proallargtypes,1) <> array_length(proargmodes,1);
327
328SELECT p1.oid, p1.proname
329FROM pg_proc as p1
330WHERE proallargtypes IS NOT NULL AND proargnames IS NOT NULL AND
331    array_length(proallargtypes,1) <> array_length(proargnames,1);
332
333SELECT p1.oid, p1.proname
334FROM pg_proc as p1
335WHERE proargmodes IS NOT NULL AND proargnames IS NOT NULL AND
336    array_length(proargmodes,1) <> array_length(proargnames,1);
337
338-- Check that proallargtypes matches proargtypes
339SELECT p1.oid, p1.proname, p1.proargtypes, p1.proallargtypes, p1.proargmodes
340FROM pg_proc as p1
341WHERE proallargtypes IS NOT NULL AND
342  ARRAY(SELECT unnest(proargtypes)) <>
343  ARRAY(SELECT proallargtypes[i]
344        FROM generate_series(1, array_length(proallargtypes, 1)) g(i)
345        WHERE proargmodes IS NULL OR proargmodes[i] IN ('i', 'b', 'v'));
346
347-- Check for prosupport functions with the wrong signature
348SELECT p1.oid, p1.proname, p2.oid, p2.proname
349FROM pg_proc AS p1, pg_proc AS p2
350WHERE p2.oid = p1.prosupport AND
351    (p2.prorettype != 'internal'::regtype OR p2.proretset OR p2.pronargs != 1
352     OR p2.proargtypes[0] != 'internal'::regtype);
353
354-- Insist that all built-in pg_proc entries have descriptions
355SELECT p1.oid, p1.proname
356FROM pg_proc as p1 LEFT JOIN pg_description as d
357     ON p1.tableoid = d.classoid and p1.oid = d.objoid and d.objsubid = 0
358WHERE d.classoid IS NULL AND p1.oid <= 9999;
359
360-- List of built-in leakproof functions
361--
362-- Leakproof functions should only be added after carefully
363-- scrutinizing all possibly executed codepaths for possible
364-- information leaks. Don't add functions here unless you know what a
365-- leakproof function is. If unsure, don't mark it as such.
366
367-- temporarily disable fancy output, so catalog changes create less diff noise
368\a\t
369
370SELECT p1.oid::regprocedure
371FROM pg_proc p1 JOIN pg_namespace pn
372     ON pronamespace = pn.oid
373WHERE nspname = 'pg_catalog' AND proleakproof
374ORDER BY 1;
375
376-- restore normal output mode
377\a\t
378
379-- List of functions used by libpq's fe-lobj.c
380--
381-- If the output of this query changes, you probably broke libpq.
382-- lo_initialize() assumes that there will be at most one match for
383-- each listed name.
384select proname, oid from pg_catalog.pg_proc
385where proname in (
386  'lo_open',
387  'lo_close',
388  'lo_creat',
389  'lo_create',
390  'lo_unlink',
391  'lo_lseek',
392  'lo_lseek64',
393  'lo_tell',
394  'lo_tell64',
395  'lo_truncate',
396  'lo_truncate64',
397  'loread',
398  'lowrite')
399and pronamespace = (select oid from pg_catalog.pg_namespace
400                    where nspname = 'pg_catalog')
401order by 1;
402
403-- Check that all immutable functions are marked parallel safe
404SELECT p1.oid, p1.proname
405FROM pg_proc AS p1
406WHERE provolatile = 'i' AND proparallel = 'u';
407
408
409-- **************** pg_cast ****************
410
411-- Catch bogus values in pg_cast columns (other than cases detected by
412-- oidjoins test).
413
414SELECT *
415FROM pg_cast c
416WHERE castsource = 0 OR casttarget = 0 OR castcontext NOT IN ('e', 'a', 'i')
417    OR castmethod NOT IN ('f', 'b' ,'i');
418
419-- Check that castfunc is nonzero only for cast methods that need a function,
420-- and zero otherwise
421
422SELECT *
423FROM pg_cast c
424WHERE (castmethod = 'f' AND castfunc = 0)
425   OR (castmethod IN ('b', 'i') AND castfunc <> 0);
426
427-- Look for casts to/from the same type that aren't length coercion functions.
428-- (We assume they are length coercions if they take multiple arguments.)
429-- Such entries are not necessarily harmful, but they are useless.
430
431SELECT *
432FROM pg_cast c
433WHERE castsource = casttarget AND castfunc = 0;
434
435SELECT c.*
436FROM pg_cast c, pg_proc p
437WHERE c.castfunc = p.oid AND p.pronargs < 2 AND castsource = casttarget;
438
439-- Look for cast functions that don't have the right signature.  The
440-- argument and result types in pg_proc must be the same as, or binary
441-- compatible with, what it says in pg_cast.
442-- As a special case, we allow casts from CHAR(n) that use functions
443-- declared to take TEXT.  This does not pass the binary-coercibility test
444-- because CHAR(n)-to-TEXT normally invokes rtrim().  However, the results
445-- are the same, so long as the function is one that ignores trailing blanks.
446
447SELECT c.*
448FROM pg_cast c, pg_proc p
449WHERE c.castfunc = p.oid AND
450    (p.pronargs < 1 OR p.pronargs > 3
451     OR NOT (binary_coercible(c.castsource, p.proargtypes[0])
452             OR (c.castsource = 'character'::regtype AND
453                 p.proargtypes[0] = 'text'::regtype))
454     OR NOT binary_coercible(p.prorettype, c.casttarget));
455
456SELECT c.*
457FROM pg_cast c, pg_proc p
458WHERE c.castfunc = p.oid AND
459    ((p.pronargs > 1 AND p.proargtypes[1] != 'int4'::regtype) OR
460     (p.pronargs > 2 AND p.proargtypes[2] != 'bool'::regtype));
461
462-- Look for binary compatible casts that do not have the reverse
463-- direction registered as well, or where the reverse direction is not
464-- also binary compatible.  This is legal, but usually not intended.
465
466-- As of 7.4, this finds the casts from text and varchar to bpchar, because
467-- those are binary-compatible while the reverse way goes through rtrim().
468
469-- As of 8.2, this finds the cast from cidr to inet, because that is a
470-- trivial binary coercion while the other way goes through inet_to_cidr().
471
472-- As of 8.3, this finds the casts from xml to text, varchar, and bpchar,
473-- because those are binary-compatible while the reverse goes through
474-- texttoxml(), which does an XML syntax check.
475
476-- As of 9.1, this finds the cast from pg_node_tree to text, which we
477-- intentionally do not provide a reverse pathway for.
478
479SELECT castsource::regtype, casttarget::regtype, castfunc, castcontext
480FROM pg_cast c
481WHERE c.castmethod = 'b' AND
482    NOT EXISTS (SELECT 1 FROM pg_cast k
483                WHERE k.castmethod = 'b' AND
484                    k.castsource = c.casttarget AND
485                    k.casttarget = c.castsource);
486
487
488-- **************** pg_conversion ****************
489
490-- Look for illegal values in pg_conversion fields.
491
492SELECT p1.oid, p1.conname
493FROM pg_conversion as p1
494WHERE p1.conproc = 0 OR
495    pg_encoding_to_char(conforencoding) = '' OR
496    pg_encoding_to_char(contoencoding) = '';
497
498-- Look for conprocs that don't have the expected signature.
499
500SELECT p.oid, p.proname, c.oid, c.conname
501FROM pg_proc p, pg_conversion c
502WHERE p.oid = c.conproc AND
503    (p.prorettype != 'int4'::regtype OR p.proretset OR
504     p.pronargs != 6 OR
505     p.proargtypes[0] != 'int4'::regtype OR
506     p.proargtypes[1] != 'int4'::regtype OR
507     p.proargtypes[2] != 'cstring'::regtype OR
508     p.proargtypes[3] != 'internal'::regtype OR
509     p.proargtypes[4] != 'int4'::regtype OR
510     p.proargtypes[5] != 'bool'::regtype);
511
512-- Check for conprocs that don't perform the specific conversion that
513-- pg_conversion alleges they do, by trying to invoke each conversion
514-- on some simple ASCII data.  (The conproc should throw an error if
515-- it doesn't accept the encodings that are passed to it.)
516-- Unfortunately, we can't test non-default conprocs this way, because
517-- there is no way to ask convert() to invoke them, and we cannot call
518-- them directly from SQL.  But there are no non-default built-in
519-- conversions anyway.
520-- (Similarly, this doesn't cope with any search path issues.)
521
522SELECT p1.oid, p1.conname
523FROM pg_conversion as p1
524WHERE condefault AND
525    convert('ABC'::bytea, pg_encoding_to_char(conforencoding),
526            pg_encoding_to_char(contoencoding)) != 'ABC';
527
528
529-- **************** pg_operator ****************
530
531-- Look for illegal values in pg_operator fields.
532
533SELECT p1.oid, p1.oprname
534FROM pg_operator as p1
535WHERE (p1.oprkind != 'b' AND p1.oprkind != 'l') OR
536    p1.oprresult = 0 OR p1.oprcode = 0;
537
538-- Look for missing or unwanted operand types
539
540SELECT p1.oid, p1.oprname
541FROM pg_operator as p1
542WHERE (p1.oprleft = 0 and p1.oprkind != 'l') OR
543    (p1.oprleft != 0 and p1.oprkind = 'l') OR
544    p1.oprright = 0;
545
546-- Look for conflicting operator definitions (same names and input datatypes).
547
548SELECT p1.oid, p1.oprcode, p2.oid, p2.oprcode
549FROM pg_operator AS p1, pg_operator AS p2
550WHERE p1.oid != p2.oid AND
551    p1.oprname = p2.oprname AND
552    p1.oprkind = p2.oprkind AND
553    p1.oprleft = p2.oprleft AND
554    p1.oprright = p2.oprright;
555
556-- Look for commutative operators that don't commute.
557-- DEFINITIONAL NOTE: If A.oprcom = B, then x A y has the same result as y B x.
558-- We expect that B will always say that B.oprcom = A as well; that's not
559-- inherently essential, but it would be inefficient not to mark it so.
560
561SELECT p1.oid, p1.oprcode, p2.oid, p2.oprcode
562FROM pg_operator AS p1, pg_operator AS p2
563WHERE p1.oprcom = p2.oid AND
564    (p1.oprkind != 'b' OR
565     p1.oprleft != p2.oprright OR
566     p1.oprright != p2.oprleft OR
567     p1.oprresult != p2.oprresult OR
568     p1.oid != p2.oprcom);
569
570-- Look for negatory operators that don't agree.
571-- DEFINITIONAL NOTE: If A.oprnegate = B, then both A and B must yield
572-- boolean results, and (x A y) == ! (x B y), or the equivalent for
573-- single-operand operators.
574-- We expect that B will always say that B.oprnegate = A as well; that's not
575-- inherently essential, but it would be inefficient not to mark it so.
576-- Also, A and B had better not be the same operator.
577
578SELECT p1.oid, p1.oprcode, p2.oid, p2.oprcode
579FROM pg_operator AS p1, pg_operator AS p2
580WHERE p1.oprnegate = p2.oid AND
581    (p1.oprkind != p2.oprkind OR
582     p1.oprleft != p2.oprleft OR
583     p1.oprright != p2.oprright OR
584     p1.oprresult != 'bool'::regtype OR
585     p2.oprresult != 'bool'::regtype OR
586     p1.oid != p2.oprnegate OR
587     p1.oid = p2.oid);
588
589-- Make a list of the names of operators that are claimed to be commutator
590-- pairs.  This list will grow over time, but before accepting a new entry
591-- make sure you didn't link the wrong operators.
592
593SELECT DISTINCT o1.oprname AS op1, o2.oprname AS op2
594FROM pg_operator o1, pg_operator o2
595WHERE o1.oprcom = o2.oid AND o1.oprname <= o2.oprname
596ORDER BY 1, 2;
597
598-- Likewise for negator pairs.
599
600SELECT DISTINCT o1.oprname AS op1, o2.oprname AS op2
601FROM pg_operator o1, pg_operator o2
602WHERE o1.oprnegate = o2.oid AND o1.oprname <= o2.oprname
603ORDER BY 1, 2;
604
605-- A mergejoinable or hashjoinable operator must be binary, must return
606-- boolean, and must have a commutator (itself, unless it's a cross-type
607-- operator).
608
609SELECT p1.oid, p1.oprname FROM pg_operator AS p1
610WHERE (p1.oprcanmerge OR p1.oprcanhash) AND NOT
611    (p1.oprkind = 'b' AND p1.oprresult = 'bool'::regtype AND p1.oprcom != 0);
612
613-- What's more, the commutator had better be mergejoinable/hashjoinable too.
614
615SELECT p1.oid, p1.oprname, p2.oid, p2.oprname
616FROM pg_operator AS p1, pg_operator AS p2
617WHERE p1.oprcom = p2.oid AND
618    (p1.oprcanmerge != p2.oprcanmerge OR
619     p1.oprcanhash != p2.oprcanhash);
620
621-- Mergejoinable operators should appear as equality members of btree index
622-- opfamilies.
623
624SELECT p1.oid, p1.oprname
625FROM pg_operator AS p1
626WHERE p1.oprcanmerge AND NOT EXISTS
627  (SELECT 1 FROM pg_amop
628   WHERE amopmethod = (SELECT oid FROM pg_am WHERE amname = 'btree') AND
629         amopopr = p1.oid AND amopstrategy = 3);
630
631-- And the converse.
632
633SELECT p1.oid, p1.oprname, p.amopfamily
634FROM pg_operator AS p1, pg_amop p
635WHERE amopopr = p1.oid
636  AND amopmethod = (SELECT oid FROM pg_am WHERE amname = 'btree')
637  AND amopstrategy = 3
638  AND NOT p1.oprcanmerge;
639
640-- Hashable operators should appear as members of hash index opfamilies.
641
642SELECT p1.oid, p1.oprname
643FROM pg_operator AS p1
644WHERE p1.oprcanhash AND NOT EXISTS
645  (SELECT 1 FROM pg_amop
646   WHERE amopmethod = (SELECT oid FROM pg_am WHERE amname = 'hash') AND
647         amopopr = p1.oid AND amopstrategy = 1);
648
649-- And the converse.
650
651SELECT p1.oid, p1.oprname, p.amopfamily
652FROM pg_operator AS p1, pg_amop p
653WHERE amopopr = p1.oid
654  AND amopmethod = (SELECT oid FROM pg_am WHERE amname = 'hash')
655  AND NOT p1.oprcanhash;
656
657-- Check that each operator defined in pg_operator matches its oprcode entry
658-- in pg_proc.  Easiest to do this separately for each oprkind.
659
660SELECT p1.oid, p1.oprname, p2.oid, p2.proname
661FROM pg_operator AS p1, pg_proc AS p2
662WHERE p1.oprcode = p2.oid AND
663    p1.oprkind = 'b' AND
664    (p2.pronargs != 2
665     OR NOT binary_coercible(p2.prorettype, p1.oprresult)
666     OR NOT binary_coercible(p1.oprleft, p2.proargtypes[0])
667     OR NOT binary_coercible(p1.oprright, p2.proargtypes[1]));
668
669SELECT p1.oid, p1.oprname, p2.oid, p2.proname
670FROM pg_operator AS p1, pg_proc AS p2
671WHERE p1.oprcode = p2.oid AND
672    p1.oprkind = 'l' AND
673    (p2.pronargs != 1
674     OR NOT binary_coercible(p2.prorettype, p1.oprresult)
675     OR NOT binary_coercible(p1.oprright, p2.proargtypes[0])
676     OR p1.oprleft != 0);
677
678-- If the operator is mergejoinable or hashjoinable, its underlying function
679-- should not be volatile.
680
681SELECT p1.oid, p1.oprname, p2.oid, p2.proname
682FROM pg_operator AS p1, pg_proc AS p2
683WHERE p1.oprcode = p2.oid AND
684    (p1.oprcanmerge OR p1.oprcanhash) AND
685    p2.provolatile = 'v';
686
687-- If oprrest is set, the operator must return boolean,
688-- and it must link to a proc with the right signature
689-- to be a restriction selectivity estimator.
690-- The proc signature we want is: float8 proc(internal, oid, internal, int4)
691
692SELECT p1.oid, p1.oprname, p2.oid, p2.proname
693FROM pg_operator AS p1, pg_proc AS p2
694WHERE p1.oprrest = p2.oid AND
695    (p1.oprresult != 'bool'::regtype OR
696     p2.prorettype != 'float8'::regtype OR p2.proretset OR
697     p2.pronargs != 4 OR
698     p2.proargtypes[0] != 'internal'::regtype OR
699     p2.proargtypes[1] != 'oid'::regtype OR
700     p2.proargtypes[2] != 'internal'::regtype OR
701     p2.proargtypes[3] != 'int4'::regtype);
702
703-- If oprjoin is set, the operator must be a binary boolean op,
704-- and it must link to a proc with the right signature
705-- to be a join selectivity estimator.
706-- The proc signature we want is: float8 proc(internal, oid, internal, int2, internal)
707-- (Note: the old signature with only 4 args is still allowed, but no core
708-- estimator should be using it.)
709
710SELECT p1.oid, p1.oprname, p2.oid, p2.proname
711FROM pg_operator AS p1, pg_proc AS p2
712WHERE p1.oprjoin = p2.oid AND
713    (p1.oprkind != 'b' OR p1.oprresult != 'bool'::regtype OR
714     p2.prorettype != 'float8'::regtype OR p2.proretset OR
715     p2.pronargs != 5 OR
716     p2.proargtypes[0] != 'internal'::regtype OR
717     p2.proargtypes[1] != 'oid'::regtype OR
718     p2.proargtypes[2] != 'internal'::regtype OR
719     p2.proargtypes[3] != 'int2'::regtype OR
720     p2.proargtypes[4] != 'internal'::regtype);
721
722-- Insist that all built-in pg_operator entries have descriptions
723SELECT p1.oid, p1.oprname
724FROM pg_operator as p1 LEFT JOIN pg_description as d
725     ON p1.tableoid = d.classoid and p1.oid = d.objoid and d.objsubid = 0
726WHERE d.classoid IS NULL AND p1.oid <= 9999;
727
728-- Check that operators' underlying functions have suitable comments,
729-- namely 'implementation of XXX operator'.  (Note: it's not necessary to
730-- put such comments into pg_proc.dat; initdb will generate them as needed.)
731-- In some cases involving legacy names for operators, there are multiple
732-- operators referencing the same pg_proc entry, so ignore operators whose
733-- comments say they are deprecated.
734-- We also have a few functions that are both operator support and meant to
735-- be called directly; those should have comments matching their operator.
736WITH funcdescs AS (
737  SELECT p.oid as p_oid, proname, o.oid as o_oid,
738    pd.description as prodesc,
739    'implementation of ' || oprname || ' operator' as expecteddesc,
740    od.description as oprdesc
741  FROM pg_proc p JOIN pg_operator o ON oprcode = p.oid
742       LEFT JOIN pg_description pd ON
743         (pd.objoid = p.oid and pd.classoid = p.tableoid and pd.objsubid = 0)
744       LEFT JOIN pg_description od ON
745         (od.objoid = o.oid and od.classoid = o.tableoid and od.objsubid = 0)
746  WHERE o.oid <= 9999
747)
748SELECT * FROM funcdescs
749  WHERE prodesc IS DISTINCT FROM expecteddesc
750    AND oprdesc NOT LIKE 'deprecated%'
751    AND prodesc IS DISTINCT FROM oprdesc;
752
753-- Show all the operator-implementation functions that have their own
754-- comments.  This should happen only in cases where the function and
755-- operator syntaxes are both documented at the user level.
756-- This should be a pretty short list; it's mostly legacy cases.
757WITH funcdescs AS (
758  SELECT p.oid as p_oid, proname, o.oid as o_oid,
759    pd.description as prodesc,
760    'implementation of ' || oprname || ' operator' as expecteddesc,
761    od.description as oprdesc
762  FROM pg_proc p JOIN pg_operator o ON oprcode = p.oid
763       LEFT JOIN pg_description pd ON
764         (pd.objoid = p.oid and pd.classoid = p.tableoid and pd.objsubid = 0)
765       LEFT JOIN pg_description od ON
766         (od.objoid = o.oid and od.classoid = o.tableoid and od.objsubid = 0)
767  WHERE o.oid <= 9999
768)
769SELECT p_oid, proname, prodesc FROM funcdescs
770  WHERE prodesc IS DISTINCT FROM expecteddesc
771    AND oprdesc NOT LIKE 'deprecated%'
772ORDER BY 1;
773
774-- Operators that are commutator pairs should have identical volatility
775-- and leakproofness markings on their implementation functions.
776SELECT o1.oid, o1.oprcode, o2.oid, o2.oprcode
777FROM pg_operator AS o1, pg_operator AS o2, pg_proc AS p1, pg_proc AS p2
778WHERE o1.oprcom = o2.oid AND p1.oid = o1.oprcode AND p2.oid = o2.oprcode AND
779    (p1.provolatile != p2.provolatile OR
780     p1.proleakproof != p2.proleakproof);
781
782-- Likewise for negator pairs.
783SELECT o1.oid, o1.oprcode, o2.oid, o2.oprcode
784FROM pg_operator AS o1, pg_operator AS o2, pg_proc AS p1, pg_proc AS p2
785WHERE o1.oprnegate = o2.oid AND p1.oid = o1.oprcode AND p2.oid = o2.oprcode AND
786    (p1.provolatile != p2.provolatile OR
787     p1.proleakproof != p2.proleakproof);
788
789-- Btree comparison operators' functions should have the same volatility
790-- and leakproofness markings as the associated comparison support function.
791SELECT pp.oid::regprocedure as proc, pp.provolatile as vp, pp.proleakproof as lp,
792       po.oid::regprocedure as opr, po.provolatile as vo, po.proleakproof as lo
793FROM pg_proc pp, pg_proc po, pg_operator o, pg_amproc ap, pg_amop ao
794WHERE pp.oid = ap.amproc AND po.oid = o.oprcode AND o.oid = ao.amopopr AND
795    ao.amopmethod = (SELECT oid FROM pg_am WHERE amname = 'btree') AND
796    ao.amopfamily = ap.amprocfamily AND
797    ao.amoplefttype = ap.amproclefttype AND
798    ao.amoprighttype = ap.amprocrighttype AND
799    ap.amprocnum = 1 AND
800    (pp.provolatile != po.provolatile OR
801     pp.proleakproof != po.proleakproof)
802ORDER BY 1;
803
804
805-- **************** pg_aggregate ****************
806
807-- Look for illegal values in pg_aggregate fields.
808
809SELECT ctid, aggfnoid::oid
810FROM pg_aggregate as p1
811WHERE aggfnoid = 0 OR aggtransfn = 0 OR
812    aggkind NOT IN ('n', 'o', 'h') OR
813    aggnumdirectargs < 0 OR
814    (aggkind = 'n' AND aggnumdirectargs > 0) OR
815    aggfinalmodify NOT IN ('r', 's', 'w') OR
816    aggmfinalmodify NOT IN ('r', 's', 'w') OR
817    aggtranstype = 0 OR aggtransspace < 0 OR aggmtransspace < 0;
818
819-- Make sure the matching pg_proc entry is sensible, too.
820
821SELECT a.aggfnoid::oid, p.proname
822FROM pg_aggregate as a, pg_proc as p
823WHERE a.aggfnoid = p.oid AND
824    (p.prokind != 'a' OR p.proretset OR p.pronargs < a.aggnumdirectargs);
825
826-- Make sure there are no prokind = PROKIND_AGGREGATE pg_proc entries without matches.
827
828SELECT oid, proname
829FROM pg_proc as p
830WHERE p.prokind = 'a' AND
831    NOT EXISTS (SELECT 1 FROM pg_aggregate a WHERE a.aggfnoid = p.oid);
832
833-- If there is no finalfn then the output type must be the transtype.
834
835SELECT a.aggfnoid::oid, p.proname
836FROM pg_aggregate as a, pg_proc as p
837WHERE a.aggfnoid = p.oid AND
838    a.aggfinalfn = 0 AND p.prorettype != a.aggtranstype;
839
840-- Cross-check transfn against its entry in pg_proc.
841SELECT a.aggfnoid::oid, p.proname, ptr.oid, ptr.proname
842FROM pg_aggregate AS a, pg_proc AS p, pg_proc AS ptr
843WHERE a.aggfnoid = p.oid AND
844    a.aggtransfn = ptr.oid AND
845    (ptr.proretset
846     OR NOT (ptr.pronargs =
847             CASE WHEN a.aggkind = 'n' THEN p.pronargs + 1
848             ELSE greatest(p.pronargs - a.aggnumdirectargs, 1) + 1 END)
849     OR NOT binary_coercible(ptr.prorettype, a.aggtranstype)
850     OR NOT binary_coercible(a.aggtranstype, ptr.proargtypes[0])
851     OR (p.pronargs > 0 AND
852         NOT binary_coercible(p.proargtypes[0], ptr.proargtypes[1]))
853     OR (p.pronargs > 1 AND
854         NOT binary_coercible(p.proargtypes[1], ptr.proargtypes[2]))
855     OR (p.pronargs > 2 AND
856         NOT binary_coercible(p.proargtypes[2], ptr.proargtypes[3]))
857     -- we could carry the check further, but 3 args is enough for now
858     OR (p.pronargs > 3)
859    );
860
861-- Cross-check finalfn (if present) against its entry in pg_proc.
862
863SELECT a.aggfnoid::oid, p.proname, pfn.oid, pfn.proname
864FROM pg_aggregate AS a, pg_proc AS p, pg_proc AS pfn
865WHERE a.aggfnoid = p.oid AND
866    a.aggfinalfn = pfn.oid AND
867    (pfn.proretset OR
868     NOT binary_coercible(pfn.prorettype, p.prorettype) OR
869     NOT binary_coercible(a.aggtranstype, pfn.proargtypes[0]) OR
870     CASE WHEN a.aggfinalextra THEN pfn.pronargs != p.pronargs + 1
871          ELSE pfn.pronargs != a.aggnumdirectargs + 1 END
872     OR (pfn.pronargs > 1 AND
873         NOT binary_coercible(p.proargtypes[0], pfn.proargtypes[1]))
874     OR (pfn.pronargs > 2 AND
875         NOT binary_coercible(p.proargtypes[1], pfn.proargtypes[2]))
876     OR (pfn.pronargs > 3 AND
877         NOT binary_coercible(p.proargtypes[2], pfn.proargtypes[3]))
878     -- we could carry the check further, but 4 args is enough for now
879     OR (pfn.pronargs > 4)
880    );
881
882-- If transfn is strict then either initval should be non-NULL, or
883-- input type should match transtype so that the first non-null input
884-- can be assigned as the state value.
885
886SELECT a.aggfnoid::oid, p.proname, ptr.oid, ptr.proname
887FROM pg_aggregate AS a, pg_proc AS p, pg_proc AS ptr
888WHERE a.aggfnoid = p.oid AND
889    a.aggtransfn = ptr.oid AND ptr.proisstrict AND
890    a.agginitval IS NULL AND
891    NOT binary_coercible(p.proargtypes[0], a.aggtranstype);
892
893-- Check for inconsistent specifications of moving-aggregate columns.
894
895SELECT ctid, aggfnoid::oid
896FROM pg_aggregate as p1
897WHERE aggmtranstype != 0 AND
898    (aggmtransfn = 0 OR aggminvtransfn = 0);
899
900SELECT ctid, aggfnoid::oid
901FROM pg_aggregate as p1
902WHERE aggmtranstype = 0 AND
903    (aggmtransfn != 0 OR aggminvtransfn != 0 OR aggmfinalfn != 0 OR
904     aggmtransspace != 0 OR aggminitval IS NOT NULL);
905
906-- If there is no mfinalfn then the output type must be the mtranstype.
907
908SELECT a.aggfnoid::oid, p.proname
909FROM pg_aggregate as a, pg_proc as p
910WHERE a.aggfnoid = p.oid AND
911    a.aggmtransfn != 0 AND
912    a.aggmfinalfn = 0 AND p.prorettype != a.aggmtranstype;
913
914-- Cross-check mtransfn (if present) against its entry in pg_proc.
915SELECT a.aggfnoid::oid, p.proname, ptr.oid, ptr.proname
916FROM pg_aggregate AS a, pg_proc AS p, pg_proc AS ptr
917WHERE a.aggfnoid = p.oid AND
918    a.aggmtransfn = ptr.oid AND
919    (ptr.proretset
920     OR NOT (ptr.pronargs =
921             CASE WHEN a.aggkind = 'n' THEN p.pronargs + 1
922             ELSE greatest(p.pronargs - a.aggnumdirectargs, 1) + 1 END)
923     OR NOT binary_coercible(ptr.prorettype, a.aggmtranstype)
924     OR NOT binary_coercible(a.aggmtranstype, ptr.proargtypes[0])
925     OR (p.pronargs > 0 AND
926         NOT binary_coercible(p.proargtypes[0], ptr.proargtypes[1]))
927     OR (p.pronargs > 1 AND
928         NOT binary_coercible(p.proargtypes[1], ptr.proargtypes[2]))
929     OR (p.pronargs > 2 AND
930         NOT binary_coercible(p.proargtypes[2], ptr.proargtypes[3]))
931     -- we could carry the check further, but 3 args is enough for now
932     OR (p.pronargs > 3)
933    );
934
935-- Cross-check minvtransfn (if present) against its entry in pg_proc.
936SELECT a.aggfnoid::oid, p.proname, ptr.oid, ptr.proname
937FROM pg_aggregate AS a, pg_proc AS p, pg_proc AS ptr
938WHERE a.aggfnoid = p.oid AND
939    a.aggminvtransfn = ptr.oid AND
940    (ptr.proretset
941     OR NOT (ptr.pronargs =
942             CASE WHEN a.aggkind = 'n' THEN p.pronargs + 1
943             ELSE greatest(p.pronargs - a.aggnumdirectargs, 1) + 1 END)
944     OR NOT binary_coercible(ptr.prorettype, a.aggmtranstype)
945     OR NOT binary_coercible(a.aggmtranstype, ptr.proargtypes[0])
946     OR (p.pronargs > 0 AND
947         NOT binary_coercible(p.proargtypes[0], ptr.proargtypes[1]))
948     OR (p.pronargs > 1 AND
949         NOT binary_coercible(p.proargtypes[1], ptr.proargtypes[2]))
950     OR (p.pronargs > 2 AND
951         NOT binary_coercible(p.proargtypes[2], ptr.proargtypes[3]))
952     -- we could carry the check further, but 3 args is enough for now
953     OR (p.pronargs > 3)
954    );
955
956-- Cross-check mfinalfn (if present) against its entry in pg_proc.
957
958SELECT a.aggfnoid::oid, p.proname, pfn.oid, pfn.proname
959FROM pg_aggregate AS a, pg_proc AS p, pg_proc AS pfn
960WHERE a.aggfnoid = p.oid AND
961    a.aggmfinalfn = pfn.oid AND
962    (pfn.proretset OR
963     NOT binary_coercible(pfn.prorettype, p.prorettype) OR
964     NOT binary_coercible(a.aggmtranstype, pfn.proargtypes[0]) OR
965     CASE WHEN a.aggmfinalextra THEN pfn.pronargs != p.pronargs + 1
966          ELSE pfn.pronargs != a.aggnumdirectargs + 1 END
967     OR (pfn.pronargs > 1 AND
968         NOT binary_coercible(p.proargtypes[0], pfn.proargtypes[1]))
969     OR (pfn.pronargs > 2 AND
970         NOT binary_coercible(p.proargtypes[1], pfn.proargtypes[2]))
971     OR (pfn.pronargs > 3 AND
972         NOT binary_coercible(p.proargtypes[2], pfn.proargtypes[3]))
973     -- we could carry the check further, but 4 args is enough for now
974     OR (pfn.pronargs > 4)
975    );
976
977-- If mtransfn is strict then either minitval should be non-NULL, or
978-- input type should match mtranstype so that the first non-null input
979-- can be assigned as the state value.
980
981SELECT a.aggfnoid::oid, p.proname, ptr.oid, ptr.proname
982FROM pg_aggregate AS a, pg_proc AS p, pg_proc AS ptr
983WHERE a.aggfnoid = p.oid AND
984    a.aggmtransfn = ptr.oid AND ptr.proisstrict AND
985    a.aggminitval IS NULL AND
986    NOT binary_coercible(p.proargtypes[0], a.aggmtranstype);
987
988-- mtransfn and minvtransfn should have same strictness setting.
989
990SELECT a.aggfnoid::oid, p.proname, ptr.oid, ptr.proname, iptr.oid, iptr.proname
991FROM pg_aggregate AS a, pg_proc AS p, pg_proc AS ptr, pg_proc AS iptr
992WHERE a.aggfnoid = p.oid AND
993    a.aggmtransfn = ptr.oid AND
994    a.aggminvtransfn = iptr.oid AND
995    ptr.proisstrict != iptr.proisstrict;
996
997-- Check that all combine functions have signature
998-- combine(transtype, transtype) returns transtype
999
1000SELECT a.aggfnoid, p.proname
1001FROM pg_aggregate as a, pg_proc as p
1002WHERE a.aggcombinefn = p.oid AND
1003    (p.pronargs != 2 OR
1004     p.prorettype != p.proargtypes[0] OR
1005     p.prorettype != p.proargtypes[1] OR
1006     NOT binary_coercible(a.aggtranstype, p.proargtypes[0]));
1007
1008-- Check that no combine function for an INTERNAL transtype is strict.
1009
1010SELECT a.aggfnoid, p.proname
1011FROM pg_aggregate as a, pg_proc as p
1012WHERE a.aggcombinefn = p.oid AND
1013    a.aggtranstype = 'internal'::regtype AND p.proisstrict;
1014
1015-- serialize/deserialize functions should be specified only for aggregates
1016-- with transtype internal and a combine function, and we should have both
1017-- or neither of them.
1018
1019SELECT aggfnoid, aggtranstype, aggserialfn, aggdeserialfn
1020FROM pg_aggregate
1021WHERE (aggserialfn != 0 OR aggdeserialfn != 0)
1022  AND (aggtranstype != 'internal'::regtype OR aggcombinefn = 0 OR
1023       aggserialfn = 0 OR aggdeserialfn = 0);
1024
1025-- Check that all serialization functions have signature
1026-- serialize(internal) returns bytea
1027-- Also insist that they be strict; it's wasteful to run them on NULLs.
1028
1029SELECT a.aggfnoid, p.proname
1030FROM pg_aggregate as a, pg_proc as p
1031WHERE a.aggserialfn = p.oid AND
1032    (p.prorettype != 'bytea'::regtype OR p.pronargs != 1 OR
1033     p.proargtypes[0] != 'internal'::regtype OR
1034     NOT p.proisstrict);
1035
1036-- Check that all deserialization functions have signature
1037-- deserialize(bytea, internal) returns internal
1038-- Also insist that they be strict; it's wasteful to run them on NULLs.
1039
1040SELECT a.aggfnoid, p.proname
1041FROM pg_aggregate as a, pg_proc as p
1042WHERE a.aggdeserialfn = p.oid AND
1043    (p.prorettype != 'internal'::regtype OR p.pronargs != 2 OR
1044     p.proargtypes[0] != 'bytea'::regtype OR
1045     p.proargtypes[1] != 'internal'::regtype OR
1046     NOT p.proisstrict);
1047
1048-- Check that aggregates which have the same transition function also have
1049-- the same combine, serialization, and deserialization functions.
1050-- While that isn't strictly necessary, it's fishy if they don't.
1051
1052SELECT a.aggfnoid, a.aggcombinefn, a.aggserialfn, a.aggdeserialfn,
1053       b.aggfnoid, b.aggcombinefn, b.aggserialfn, b.aggdeserialfn
1054FROM
1055    pg_aggregate a, pg_aggregate b
1056WHERE
1057    a.aggfnoid < b.aggfnoid AND a.aggtransfn = b.aggtransfn AND
1058    (a.aggcombinefn != b.aggcombinefn OR a.aggserialfn != b.aggserialfn
1059     OR a.aggdeserialfn != b.aggdeserialfn);
1060
1061-- Cross-check aggsortop (if present) against pg_operator.
1062-- We expect to find entries for bool_and, bool_or, every, max, and min.
1063
1064SELECT DISTINCT proname, oprname
1065FROM pg_operator AS o, pg_aggregate AS a, pg_proc AS p
1066WHERE a.aggfnoid = p.oid AND a.aggsortop = o.oid
1067ORDER BY 1, 2;
1068
1069-- Check datatypes match
1070
1071SELECT a.aggfnoid::oid, o.oid
1072FROM pg_operator AS o, pg_aggregate AS a, pg_proc AS p
1073WHERE a.aggfnoid = p.oid AND a.aggsortop = o.oid AND
1074    (oprkind != 'b' OR oprresult != 'boolean'::regtype
1075     OR oprleft != p.proargtypes[0] OR oprright != p.proargtypes[0]);
1076
1077-- Check operator is a suitable btree opfamily member
1078
1079SELECT a.aggfnoid::oid, o.oid
1080FROM pg_operator AS o, pg_aggregate AS a, pg_proc AS p
1081WHERE a.aggfnoid = p.oid AND a.aggsortop = o.oid AND
1082    NOT EXISTS(SELECT 1 FROM pg_amop
1083               WHERE amopmethod = (SELECT oid FROM pg_am WHERE amname = 'btree')
1084                     AND amopopr = o.oid
1085                     AND amoplefttype = o.oprleft
1086                     AND amoprighttype = o.oprright);
1087
1088-- Check correspondence of btree strategies and names
1089
1090SELECT DISTINCT proname, oprname, amopstrategy
1091FROM pg_operator AS o, pg_aggregate AS a, pg_proc AS p,
1092     pg_amop as ao
1093WHERE a.aggfnoid = p.oid AND a.aggsortop = o.oid AND
1094    amopopr = o.oid AND
1095    amopmethod = (SELECT oid FROM pg_am WHERE amname = 'btree')
1096ORDER BY 1, 2;
1097
1098-- Check that there are not aggregates with the same name and different
1099-- numbers of arguments.  While not technically wrong, we have a project policy
1100-- to avoid this because it opens the door for confusion in connection with
1101-- ORDER BY: novices frequently put the ORDER BY in the wrong place.
1102-- See the fate of the single-argument form of string_agg() for history.
1103-- (Note: we don't forbid users from creating such aggregates; the policy is
1104-- just to think twice before creating built-in aggregates like this.)
1105-- The only aggregates that should show up here are count(x) and count(*).
1106
1107SELECT p1.oid::regprocedure, p2.oid::regprocedure
1108FROM pg_proc AS p1, pg_proc AS p2
1109WHERE p1.oid < p2.oid AND p1.proname = p2.proname AND
1110    p1.prokind = 'a' AND p2.prokind = 'a' AND
1111    array_dims(p1.proargtypes) != array_dims(p2.proargtypes)
1112ORDER BY 1;
1113
1114-- For the same reason, built-in aggregates with default arguments are no good.
1115
1116SELECT oid, proname
1117FROM pg_proc AS p
1118WHERE prokind = 'a' AND proargdefaults IS NOT NULL;
1119
1120-- For the same reason, we avoid creating built-in variadic aggregates, except
1121-- that variadic ordered-set aggregates are OK (since they have special syntax
1122-- that is not subject to the misplaced ORDER BY issue).
1123
1124SELECT p.oid, proname
1125FROM pg_proc AS p JOIN pg_aggregate AS a ON a.aggfnoid = p.oid
1126WHERE prokind = 'a' AND provariadic != 0 AND a.aggkind = 'n';
1127
1128
1129-- **************** pg_opfamily ****************
1130
1131-- Look for illegal values in pg_opfamily fields
1132
1133SELECT p1.oid
1134FROM pg_opfamily as p1
1135WHERE p1.opfmethod = 0 OR p1.opfnamespace = 0;
1136
1137-- Look for opfamilies having no opclasses.  While most validation of
1138-- opfamilies is now handled by AM-specific amvalidate functions, that's
1139-- driven from pg_opclass entries below, so an empty opfamily would not
1140-- get noticed.
1141
1142SELECT oid, opfname FROM pg_opfamily f
1143WHERE NOT EXISTS (SELECT 1 FROM pg_opclass WHERE opcfamily = f.oid);
1144
1145
1146-- **************** pg_opclass ****************
1147
1148-- Look for illegal values in pg_opclass fields
1149
1150SELECT p1.oid
1151FROM pg_opclass AS p1
1152WHERE p1.opcmethod = 0 OR p1.opcnamespace = 0 OR p1.opcfamily = 0
1153    OR p1.opcintype = 0;
1154
1155-- opcmethod must match owning opfamily's opfmethod
1156
1157SELECT p1.oid, p2.oid
1158FROM pg_opclass AS p1, pg_opfamily AS p2
1159WHERE p1.opcfamily = p2.oid AND p1.opcmethod != p2.opfmethod;
1160
1161-- There should not be multiple entries in pg_opclass with opcdefault true
1162-- and the same opcmethod/opcintype combination.
1163
1164SELECT p1.oid, p2.oid
1165FROM pg_opclass AS p1, pg_opclass AS p2
1166WHERE p1.oid != p2.oid AND
1167    p1.opcmethod = p2.opcmethod AND p1.opcintype = p2.opcintype AND
1168    p1.opcdefault AND p2.opcdefault;
1169
1170-- Ask access methods to validate opclasses
1171-- (this replaces a lot of SQL-level checks that used to be done in this file)
1172
1173SELECT oid, opcname FROM pg_opclass WHERE NOT amvalidate(oid);
1174
1175
1176-- **************** pg_am ****************
1177
1178-- Look for illegal values in pg_am fields
1179
1180SELECT p1.oid, p1.amname
1181FROM pg_am AS p1
1182WHERE p1.amhandler = 0;
1183
1184-- Check for index amhandler functions with the wrong signature
1185
1186SELECT p1.oid, p1.amname, p2.oid, p2.proname
1187FROM pg_am AS p1, pg_proc AS p2
1188WHERE p2.oid = p1.amhandler AND p1.amtype = 'i' AND
1189    (p2.prorettype != 'index_am_handler'::regtype
1190     OR p2.proretset
1191     OR p2.pronargs != 1
1192     OR p2.proargtypes[0] != 'internal'::regtype);
1193
1194-- Check for table amhandler functions with the wrong signature
1195
1196SELECT p1.oid, p1.amname, p2.oid, p2.proname
1197FROM pg_am AS p1, pg_proc AS p2
1198WHERE p2.oid = p1.amhandler AND p1.amtype = 's' AND
1199    (p2.prorettype != 'table_am_handler'::regtype
1200     OR p2.proretset
1201     OR p2.pronargs != 1
1202     OR p2.proargtypes[0] != 'internal'::regtype);
1203
1204-- **************** pg_amop ****************
1205
1206-- Look for illegal values in pg_amop fields
1207
1208SELECT p1.amopfamily, p1.amopstrategy
1209FROM pg_amop as p1
1210WHERE p1.amopfamily = 0 OR p1.amoplefttype = 0 OR p1.amoprighttype = 0
1211    OR p1.amopopr = 0 OR p1.amopmethod = 0 OR p1.amopstrategy < 1;
1212
1213SELECT p1.amopfamily, p1.amopstrategy
1214FROM pg_amop as p1
1215WHERE NOT ((p1.amoppurpose = 's' AND p1.amopsortfamily = 0) OR
1216           (p1.amoppurpose = 'o' AND p1.amopsortfamily <> 0));
1217
1218-- amopmethod must match owning opfamily's opfmethod
1219
1220SELECT p1.oid, p2.oid
1221FROM pg_amop AS p1, pg_opfamily AS p2
1222WHERE p1.amopfamily = p2.oid AND p1.amopmethod != p2.opfmethod;
1223
1224-- Make a list of all the distinct operator names being used in particular
1225-- strategy slots.  This is a bit hokey, since the list might need to change
1226-- in future releases, but it's an effective way of spotting mistakes such as
1227-- swapping two operators within a family.
1228
1229SELECT DISTINCT amopmethod, amopstrategy, oprname
1230FROM pg_amop p1 LEFT JOIN pg_operator p2 ON amopopr = p2.oid
1231ORDER BY 1, 2, 3;
1232
1233-- Check that all opclass search operators have selectivity estimators.
1234-- This is not absolutely required, but it seems a reasonable thing
1235-- to insist on for all standard datatypes.
1236
1237SELECT p1.amopfamily, p1.amopopr, p2.oid, p2.oprname
1238FROM pg_amop AS p1, pg_operator AS p2
1239WHERE p1.amopopr = p2.oid AND p1.amoppurpose = 's' AND
1240    (p2.oprrest = 0 OR p2.oprjoin = 0);
1241
1242-- Check that each opclass in an opfamily has associated operators, that is
1243-- ones whose oprleft matches opcintype (possibly by coercion).
1244
1245SELECT p1.opcname, p1.opcfamily
1246FROM pg_opclass AS p1
1247WHERE NOT EXISTS(SELECT 1 FROM pg_amop AS p2
1248                 WHERE p2.amopfamily = p1.opcfamily
1249                   AND binary_coercible(p1.opcintype, p2.amoplefttype));
1250
1251-- Check that each operator listed in pg_amop has an associated opclass,
1252-- that is one whose opcintype matches oprleft (possibly by coercion).
1253-- Otherwise the operator is useless because it cannot be matched to an index.
1254-- (In principle it could be useful to list such operators in multiple-datatype
1255-- btree opfamilies, but in practice you'd expect there to be an opclass for
1256-- every datatype the family knows about.)
1257
1258SELECT p1.amopfamily, p1.amopstrategy, p1.amopopr
1259FROM pg_amop AS p1
1260WHERE NOT EXISTS(SELECT 1 FROM pg_opclass AS p2
1261                 WHERE p2.opcfamily = p1.amopfamily
1262                   AND binary_coercible(p2.opcintype, p1.amoplefttype));
1263
1264-- Operators that are primary members of opclasses must be immutable (else
1265-- it suggests that the index ordering isn't fixed).  Operators that are
1266-- cross-type members need only be stable, since they are just shorthands
1267-- for index probe queries.
1268
1269SELECT p1.amopfamily, p1.amopopr, p2.oprname, p3.prosrc
1270FROM pg_amop AS p1, pg_operator AS p2, pg_proc AS p3
1271WHERE p1.amopopr = p2.oid AND p2.oprcode = p3.oid AND
1272    p1.amoplefttype = p1.amoprighttype AND
1273    p3.provolatile != 'i';
1274
1275SELECT p1.amopfamily, p1.amopopr, p2.oprname, p3.prosrc
1276FROM pg_amop AS p1, pg_operator AS p2, pg_proc AS p3
1277WHERE p1.amopopr = p2.oid AND p2.oprcode = p3.oid AND
1278    p1.amoplefttype != p1.amoprighttype AND
1279    p3.provolatile = 'v';
1280
1281
1282-- **************** pg_amproc ****************
1283
1284-- Look for illegal values in pg_amproc fields
1285
1286SELECT p1.amprocfamily, p1.amprocnum
1287FROM pg_amproc as p1
1288WHERE p1.amprocfamily = 0 OR p1.amproclefttype = 0 OR p1.amprocrighttype = 0
1289    OR p1.amprocnum < 0 OR p1.amproc = 0;
1290
1291-- Support routines that are primary members of opfamilies must be immutable
1292-- (else it suggests that the index ordering isn't fixed).  But cross-type
1293-- members need only be stable, since they are just shorthands
1294-- for index probe queries.
1295
1296SELECT p1.amprocfamily, p1.amproc, p2.prosrc
1297FROM pg_amproc AS p1, pg_proc AS p2
1298WHERE p1.amproc = p2.oid AND
1299    p1.amproclefttype = p1.amprocrighttype AND
1300    p2.provolatile != 'i';
1301
1302SELECT p1.amprocfamily, p1.amproc, p2.prosrc
1303FROM pg_amproc AS p1, pg_proc AS p2
1304WHERE p1.amproc = p2.oid AND
1305    p1.amproclefttype != p1.amprocrighttype AND
1306    p2.provolatile = 'v';
1307
1308-- Almost all of the core distribution's Btree opclasses can use one of the
1309-- two generic "equalimage" functions as their support function 4.  Look for
1310-- opclasses that don't allow deduplication unconditionally here.
1311--
1312-- Newly added Btree opclasses don't have to support deduplication.  It will
1313-- usually be trivial to add support, though.  Note that the expected output
1314-- of this part of the test will need to be updated when a new opclass cannot
1315-- support deduplication (by using btequalimage).
1316SELECT amp.amproc::regproc AS proc, opf.opfname AS opfamily_name,
1317       opc.opcname AS opclass_name, opc.opcintype::regtype AS opcintype
1318FROM pg_am AS am
1319JOIN pg_opclass AS opc ON opc.opcmethod = am.oid
1320JOIN pg_opfamily AS opf ON opc.opcfamily = opf.oid
1321LEFT JOIN pg_amproc AS amp ON amp.amprocfamily = opf.oid AND
1322    amp.amproclefttype = opc.opcintype AND amp.amprocnum = 4
1323WHERE am.amname = 'btree' AND
1324    amp.amproc IS DISTINCT FROM 'btequalimage'::regproc
1325ORDER BY 1, 2, 3;
1326
1327-- **************** pg_index ****************
1328
1329-- Look for illegal values in pg_index fields.
1330
1331SELECT p1.indexrelid, p1.indrelid
1332FROM pg_index as p1
1333WHERE p1.indexrelid = 0 OR p1.indrelid = 0 OR
1334      p1.indnatts <= 0 OR p1.indnatts > 32;
1335
1336-- oidvector and int2vector fields should be of length indnatts.
1337
1338SELECT p1.indexrelid, p1.indrelid
1339FROM pg_index as p1
1340WHERE array_lower(indkey, 1) != 0 OR array_upper(indkey, 1) != indnatts-1 OR
1341    array_lower(indclass, 1) != 0 OR array_upper(indclass, 1) != indnatts-1 OR
1342    array_lower(indcollation, 1) != 0 OR array_upper(indcollation, 1) != indnatts-1 OR
1343    array_lower(indoption, 1) != 0 OR array_upper(indoption, 1) != indnatts-1;
1344
1345-- Check that opclasses and collations match the underlying columns.
1346-- (As written, this test ignores expression indexes.)
1347
1348SELECT indexrelid::regclass, indrelid::regclass, attname, atttypid::regtype, opcname
1349FROM (SELECT indexrelid, indrelid, unnest(indkey) as ikey,
1350             unnest(indclass) as iclass, unnest(indcollation) as icoll
1351      FROM pg_index) ss,
1352      pg_attribute a,
1353      pg_opclass opc
1354WHERE a.attrelid = indrelid AND a.attnum = ikey AND opc.oid = iclass AND
1355      (NOT binary_coercible(atttypid, opcintype) OR icoll != attcollation);
1356
1357-- For system catalogs, be even tighter: nearly all indexes should be
1358-- exact type matches not binary-coercible matches.  At this writing
1359-- the only exception is an OID index on a regproc column.
1360
1361SELECT indexrelid::regclass, indrelid::regclass, attname, atttypid::regtype, opcname
1362FROM (SELECT indexrelid, indrelid, unnest(indkey) as ikey,
1363             unnest(indclass) as iclass, unnest(indcollation) as icoll
1364      FROM pg_index
1365      WHERE indrelid < 16384) ss,
1366      pg_attribute a,
1367      pg_opclass opc
1368WHERE a.attrelid = indrelid AND a.attnum = ikey AND opc.oid = iclass AND
1369      (opcintype != atttypid OR icoll != attcollation)
1370ORDER BY 1;
1371
1372-- Check for system catalogs with collation-sensitive ordering.  This is not
1373-- a representational error in pg_index, but simply wrong catalog design.
1374-- It's bad because we expect to be able to clone template0 and assign the
1375-- copy a different database collation.  It would especially not work for
1376-- shared catalogs.
1377
1378SELECT relname, attname, attcollation
1379FROM pg_class c, pg_attribute a
1380WHERE c.oid = attrelid AND c.oid < 16384 AND
1381    c.relkind != 'v' AND  -- we don't care about columns in views
1382    attcollation != 0 AND
1383    attcollation != (SELECT oid FROM pg_collation WHERE collname = 'C');
1384
1385-- Double-check that collation-sensitive indexes have "C" collation, too.
1386
1387SELECT indexrelid::regclass, indrelid::regclass, iclass, icoll
1388FROM (SELECT indexrelid, indrelid,
1389             unnest(indclass) as iclass, unnest(indcollation) as icoll
1390      FROM pg_index
1391      WHERE indrelid < 16384) ss
1392WHERE icoll != 0 AND
1393    icoll != (SELECT oid FROM pg_collation WHERE collname = 'C');
1394