📄 opr_sanity.sql
字号:
---- Sanity checks for common errors in making operator/procedure system tables:-- pg_operator, pg_proc, pg_aggregate, pg_am, pg_amop, pg_amproc, pg_opclass.---- None of the SELECTs here should ever find any matching entries,-- so the expected output is easy to maintain ;-).-- A test failure indicates someone messed up an entry in the system tables.---- NB: we assume the oidjoins test will have caught any dangling links,-- that is OID or REGPROC fields that are not zero and do not match some-- row in the linked-to table. However, if we want to enforce that a link-- field can't be 0, we have to check it here.---- NB: run this test earlier than the create_operator test, because-- that test creates some bogus operators...---- NOTE hardwired assumptions about standard types:-- type bool has OID 16-- type float8 has OID 701---- **************** pg_proc ****************-- Look for illegal values in pg_proc fields.SELECT p1.oid, p1.pronameFROM pg_proc as p1WHERE (p1.prolang = 0 OR p1.prorettype = 0 OR p1.pronargs < 0 OR p1.pronargs > 9) AND p1.proname !~ '^pl[^_]+_call_handler$';-- Look for conflicting proc definitions (same names and input datatypes).SELECT p1.oid, p1.proname, p2.oid, p2.pronameFROM pg_proc AS p1, pg_proc AS p2WHERE p1.oid != p2.oid AND p1.proname = p2.proname AND p1.pronargs = p2.pronargs AND p1.proargtypes = p2.proargtypes;-- Considering only built-in procs (prolang = 11), look for multiple uses-- of the same internal function (ie, matching prosrc fields). It's OK to-- have several entries with different pronames for the same internal function,-- but conflicts in the number of arguments and other critical items should-- be complained of.SELECT p1.oid, p1.proname, p2.oid, p2.pronameFROM pg_proc AS p1, pg_proc AS p2WHERE p1.oid != p2.oid AND p1.prosrc = p2.prosrc AND p1.prolang = 11 AND p2.prolang = 11 AND (p1.proisinh != p2.proisinh OR p1.proistrusted != p2.proistrusted OR p1.proiscachable != p2.proiscachable OR p1.pronargs != p2.pronargs OR p1.proretset != p2.proretset);-- Look for uses of different type OIDs in the argument/result type fields-- for different aliases of the same built-in function.-- This indicates that the types are being presumed to be binary-equivalent.-- That's not wrong, necessarily, but we make lists of all the types being-- so treated. Note that the expected output of this part of the test will-- need to be modified whenever new pairs of types are made binary-equivalent!SELECT DISTINCT p1.prorettype, p2.prorettypeFROM pg_proc AS p1, pg_proc AS p2WHERE p1.oid != p2.oid AND p1.prosrc = p2.prosrc AND p1.prolang = 11 AND p2.prolang = 11 AND (p1.prorettype < p2.prorettype);SELECT DISTINCT p1.proargtypes[0], p2.proargtypes[0]FROM pg_proc AS p1, pg_proc AS p2WHERE p1.oid != p2.oid AND p1.prosrc = p2.prosrc AND p1.prolang = 11 AND p2.prolang = 11 AND (p1.proargtypes[0] < p2.proargtypes[0]);SELECT DISTINCT p1.proargtypes[1], p2.proargtypes[1]FROM pg_proc AS p1, pg_proc AS p2WHERE p1.oid != p2.oid AND p1.prosrc = p2.prosrc AND p1.prolang = 11 AND p2.prolang = 11 AND (p1.proargtypes[1] < p2.proargtypes[1]);SELECT DISTINCT p1.proargtypes[2], p2.proargtypes[2]FROM pg_proc AS p1, pg_proc AS p2WHERE p1.oid != p2.oid AND p1.prosrc = p2.prosrc AND p1.prolang = 11 AND p2.prolang = 11 AND (p1.proargtypes[2] < p2.proargtypes[2]);SELECT DISTINCT p1.proargtypes[3], p2.proargtypes[3]FROM pg_proc AS p1, pg_proc AS p2WHERE p1.oid != p2.oid AND p1.prosrc = p2.prosrc AND p1.prolang = 11 AND p2.prolang = 11 AND (p1.proargtypes[3] < p2.proargtypes[3]);SELECT DISTINCT p1.proargtypes[4], p2.proargtypes[4]FROM pg_proc AS p1, pg_proc AS p2WHERE p1.oid != p2.oid AND p1.prosrc = p2.prosrc AND p1.prolang = 11 AND p2.prolang = 11 AND (p1.proargtypes[4] < p2.proargtypes[4]);SELECT DISTINCT p1.proargtypes[5], p2.proargtypes[5]FROM pg_proc AS p1, pg_proc AS p2WHERE p1.oid != p2.oid AND p1.prosrc = p2.prosrc AND p1.prolang = 11 AND p2.prolang = 11 AND (p1.proargtypes[5] < p2.proargtypes[5]);SELECT DISTINCT p1.proargtypes[6], p2.proargtypes[6]FROM pg_proc AS p1, pg_proc AS p2WHERE p1.oid != p2.oid AND p1.prosrc = p2.prosrc AND p1.prolang = 11 AND p2.prolang = 11 AND (p1.proargtypes[6] < p2.proargtypes[6]);SELECT DISTINCT p1.proargtypes[7], p2.proargtypes[7]FROM pg_proc AS p1, pg_proc AS p2WHERE p1.oid != p2.oid AND p1.prosrc = p2.prosrc AND p1.prolang = 11 AND p2.prolang = 11 AND (p1.proargtypes[7] < p2.proargtypes[7]);-- **************** pg_operator ****************-- Look for illegal values in pg_operator fields.SELECT p1.oid, p1.oprnameFROM pg_operator as p1WHERE (p1.oprkind != 'b' AND p1.oprkind != 'l' AND p1.oprkind != 'r') OR p1.oprresult = 0 OR p1.oprcode = 0;-- Look for missing or unwanted operand typesSELECT p1.oid, p1.oprnameFROM pg_operator as p1WHERE (p1.oprleft = 0 and p1.oprkind != 'l') OR (p1.oprleft != 0 and p1.oprkind = 'l') OR (p1.oprright = 0 and p1.oprkind != 'r') OR (p1.oprright != 0 and p1.oprkind = 'r');-- Look for conflicting operator definitions (same names and input datatypes).SELECT p1.oid, p1.oprcode, p2.oid, p2.oprcodeFROM pg_operator AS p1, pg_operator AS p2WHERE p1.oid != p2.oid AND p1.oprname = p2.oprname AND p1.oprkind = p2.oprkind AND p1.oprleft = p2.oprleft AND p1.oprright = p2.oprright;-- Look for commutative operators that don't commute.-- DEFINITIONAL NOTE: If A.oprcom = B, then x A y has the same result as y B x.-- We expect that B will always say that B.oprcom = A as well; that's not-- inherently essential, but it would be inefficient not to mark it so.SELECT p1.oid, p1.oprcode, p2.oid, p2.oprcodeFROM pg_operator AS p1, pg_operator AS p2WHERE p1.oprcom = p2.oid AND (p1.oprkind != 'b' OR p1.oprleft != p2.oprright OR p1.oprright != p2.oprleft OR p1.oprresult != p2.oprresult OR p1.oid != p2.oprcom);-- Look for negatory operators that don't agree.-- DEFINITIONAL NOTE: If A.oprnegate = B, then both A and B must yield-- boolean results, and (x A y) == ! (x B y), or the equivalent for-- single-operand operators.-- We expect that B will always say that B.oprnegate = A as well; that's not-- inherently essential, but it would be inefficient not to mark it so.SELECT p1.oid, p1.oprcode, p2.oid, p2.oprcodeFROM pg_operator AS p1, pg_operator AS p2WHERE p1.oprnegate = p2.oid AND (p1.oprkind != p2.oprkind OR p1.oprleft != p2.oprleft OR p1.oprright != p2.oprright OR p1.oprresult != 16 OR p2.oprresult != 16 OR p1.oid != p2.oprnegate);-- Look for mergejoin operators that don't match their links.-- A mergejoin link leads from an '=' operator to the-- sort operator ('<' operator) that's appropriate for-- its left-side or right-side data type.SELECT p1.oid, p1.oprcode, p2.oid, p2.oprcodeFROM pg_operator AS p1, pg_operator AS p2WHERE p1.oprlsortop = p2.oid AND (p1.oprname != '=' OR p2.oprname != '<' OR p1.oprkind != 'b' OR p2.oprkind != 'b' OR p1.oprleft != p2.oprleft OR p1.oprleft != p2.oprright OR p1.oprresult != 16 OR p2.oprresult != 16 OR p1.oprrsortop = 0);SELECT p1.oid, p1.oprcode, p2.oid, p2.oprcodeFROM pg_operator AS p1, pg_operator AS p2WHERE p1.oprrsortop = p2.oid AND (p1.oprname != '=' OR p2.oprname != '<' OR p1.oprkind != 'b' OR p2.oprkind != 'b' OR p1.oprright != p2.oprleft OR p1.oprright != p2.oprright OR p1.oprresult != 16 OR p2.oprresult != 16 OR p1.oprlsortop = 0);-- A mergejoinable = operator must have a commutator (usually itself)-- as well as corresponding < and > operators. Note that the "corresponding"-- operators have the same L and R input datatypes as the = operator,-- whereas the operators linked to by oprlsortop and oprrsortop have input-- datatypes L,L and R,R respectively.SELECT p1.oid, p1.oprname FROM pg_operator AS p1WHERE p1.oprlsortop != 0 AND p1.oprcom = 0;SELECT p1.oid, p1.oprname FROM pg_operator AS p1WHERE p1.oprlsortop != 0 AND NOT EXISTS(SELECT * FROM pg_operator AS p2 WHERE p2.oprname = '<' AND p2.oprleft = p1.oprleft AND p2.oprright = p1.oprright AND p2.oprkind = 'b');SELECT p1.oid, p1.oprname FROM pg_operator AS p1WHERE p1.oprlsortop != 0 AND NOT EXISTS(SELECT * FROM pg_operator AS p2 WHERE p2.oprname = '>' AND p2.oprleft = p1.oprleft AND p2.oprright = p1.oprright AND p2.oprkind = 'b');-- Hashing only works on simple equality operators "type = sametype",-- since the hash itself depends on the bitwise representation of the type.-- Check that allegedly hashable operators look like they might be "=".-- NOTE: in 6.5, this search finds int4eqoid and oideqint4. Until we have-- some cleaner way of dealing with binary-equivalent types, just leave-- those two tuples in the expected output.SELECT p1.oid, p1.oprnameFROM pg_operator AS p1WHERE p1.oprcanhash AND NOT (p1.oprkind = 'b' AND p1.oprresult = 16 AND p1.oprleft = p1.oprright AND p1.oprname = '=' AND p1.oprcom = p1.oid);-- Look for array equality operators that are hashable when the underlying-- type is not, or vice versa. This is presumably bogus.SELECT p1.oid, p1.oprcanhash, p2.oid, p2.oprcanhash, t1.typname, t2.typnameFROM pg_operator AS p1, pg_operator AS p2, pg_type AS t1, pg_type AS t2WHERE p1.oprname = '=' AND p1.oprleft = p1.oprright AND p2.oprname = '=' AND p2.oprleft = p2.oprright AND p1.oprleft = t1.oid AND p2.oprleft = t2.oid AND t1.typelem = t2.oid AND p1.oprcanhash != p2.oprcanhash;-- Check that each operator defined in pg_operator matches its oprcode entry-- in pg_proc. Easiest to do this separately for each oprkind.-- FIXME: want to check that argument/result types match, but how to do that-- in the face of binary-compatible types?SELECT p1.oid, p1.oprname, p2.oid, p2.pronameFROM pg_operator AS p1, pg_proc AS p2WHERE p1.oprcode = p2.oid AND p1.oprkind = 'b' AND (p2.pronargs != 2
⌨️ 快捷键说明
复制代码
Ctrl + C
搜索代码
Ctrl + F
全屏模式
F11
切换主题
Ctrl + Shift + D
显示快捷键
?
增大字号
Ctrl + =
减小字号
Ctrl + -