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