-- allowed.
-- This should match IsBinaryCoercible() in parse_coerce.c.
create function binary_coercible(oid, oid) returns bool as $$
-SELECT ($1 = $2) OR
- EXISTS(select 1 from pg_catalog.pg_cast where
- castsource = $1 and casttarget = $2 and
- castmethod = 'b' and castcontext = 'i') OR
- ($2 = 'pg_catalog.any'::pg_catalog.regtype) OR
- ($2 = 'pg_catalog.anyarray'::pg_catalog.regtype AND
- EXISTS(select 1 from pg_catalog.pg_type where
- oid = $1 and typelem != 0 and typlen = -1)) OR
- ($2 = 'pg_catalog.anyrange'::pg_catalog.regtype AND
- (select typtype from pg_catalog.pg_type where oid = $1) = 'r')
-$$ language sql strict stable;
+begin
+ if $1 = $2 then return true; end if;
+ if EXISTS(select 1 from pg_catalog.pg_cast where
+ castsource = $1 and casttarget = $2 and
+ castmethod = 'b' and castcontext = 'i')
+ then return true; end if;
+ if $2 = 'pg_catalog.any'::pg_catalog.regtype then return true; end if;
+ if $2 = 'pg_catalog.anyarray'::pg_catalog.regtype then
+ if EXISTS(select 1 from pg_catalog.pg_type where
+ oid = $1 and typelem != 0 and typlen = -1)
+ then return true; end if;
+ end if;
+ if $2 = 'pg_catalog.anyrange'::pg_catalog.regtype then
+ if (select typtype from pg_catalog.pg_type where oid = $1) = 'r'
+ then return true; end if;
+ end if;
+ return false;
+end
+$$ language plpgsql strict stable;
-- This one ignores castcontext, so it considers only physical equivalence
-- and not whether the coercion can be invoked implicitly.
create function physically_coercible(oid, oid) returns bool as $$
-SELECT ($1 = $2) OR
- EXISTS(select 1 from pg_catalog.pg_cast where
- castsource = $1 and casttarget = $2 and
- castmethod = 'b') OR
- ($2 = 'pg_catalog.any'::pg_catalog.regtype) OR
- ($2 = 'pg_catalog.anyarray'::pg_catalog.regtype AND
- EXISTS(select 1 from pg_catalog.pg_type where
- oid = $1 and typelem != 0 and typlen = -1)) OR
- ($2 = 'pg_catalog.anyrange'::pg_catalog.regtype AND
- (select typtype from pg_catalog.pg_type where oid = $1) = 'r')
-$$ language sql strict stable;
+begin
+ if $1 = $2 then return true; end if;
+ if EXISTS(select 1 from pg_catalog.pg_cast where
+ castsource = $1 and casttarget = $2 and
+ castmethod = 'b')
+ then return true; end if;
+ if $2 = 'pg_catalog.any'::pg_catalog.regtype then return true; end if;
+ if $2 = 'pg_catalog.anyarray'::pg_catalog.regtype then
+ if EXISTS(select 1 from pg_catalog.pg_type where
+ oid = $1 and typelem != 0 and typlen = -1)
+ then return true; end if;
+ end if;
+ if $2 = 'pg_catalog.anyrange'::pg_catalog.regtype then
+ if (select typtype from pg_catalog.pg_type where oid = $1) = 'r'
+ then return true; end if;
+ end if;
+ return false;
+end
+$$ language plpgsql strict stable;
-- **************** pg_proc ****************
-- Look for illegal values in pg_proc fields.
SELECT p1.oid, p1.proname
-- be called directly; those should have comments matching their operator.
WITH funcdescs AS (
SELECT p.oid as p_oid, proname, o.oid as o_oid,
- obj_description(p.oid, 'pg_proc') as prodesc,
+ pd.description as prodesc,
'implementation of ' || oprname || ' operator' as expecteddesc,
- obj_description(o.oid, 'pg_operator') as oprdesc
+ od.description as oprdesc
FROM pg_proc p JOIN pg_operator o ON oprcode = p.oid
+ LEFT JOIN pg_description pd ON
+ (pd.objoid = p.oid and pd.classoid = p.tableoid and pd.objsubid = 0)
+ LEFT JOIN pg_description od ON
+ (od.objoid = o.oid and od.classoid = o.tableoid and od.objsubid = 0)
WHERE o.oid <= 9999
)
SELECT * FROM funcdescs
-- This should be a pretty short list; it's mostly legacy cases.
WITH funcdescs AS (
SELECT p.oid as p_oid, proname, o.oid as o_oid,
- obj_description(p.oid, 'pg_proc') as prodesc,
+ pd.description as prodesc,
'implementation of ' || oprname || ' operator' as expecteddesc,
- obj_description(o.oid, 'pg_operator') as oprdesc
+ od.description as oprdesc
FROM pg_proc p JOIN pg_operator o ON oprcode = p.oid
+ LEFT JOIN pg_description pd ON
+ (pd.objoid = p.oid and pd.classoid = p.tableoid and pd.objsubid = 0)
+ LEFT JOIN pg_description od ON
+ (od.objoid = o.oid and od.classoid = o.tableoid and od.objsubid = 0)
WHERE o.oid <= 9999
)
SELECT p_oid, proname, prodesc FROM funcdescs
-- This should match IsBinaryCoercible() in parse_coerce.c.
create function binary_coercible(oid, oid) returns bool as $$
-SELECT ($1 = $2) OR
- EXISTS(select 1 from pg_catalog.pg_cast where
- castsource = $1 and casttarget = $2 and
- castmethod = 'b' and castcontext = 'i') OR
- ($2 = 'pg_catalog.any'::pg_catalog.regtype) OR
- ($2 = 'pg_catalog.anyarray'::pg_catalog.regtype AND
- EXISTS(select 1 from pg_catalog.pg_type where
- oid = $1 and typelem != 0 and typlen = -1)) OR
- ($2 = 'pg_catalog.anyrange'::pg_catalog.regtype AND
- (select typtype from pg_catalog.pg_type where oid = $1) = 'r')
-$$ language sql strict stable;
+begin
+ if $1 = $2 then return true; end if;
+ if EXISTS(select 1 from pg_catalog.pg_cast where
+ castsource = $1 and casttarget = $2 and
+ castmethod = 'b' and castcontext = 'i')
+ then return true; end if;
+ if $2 = 'pg_catalog.any'::pg_catalog.regtype then return true; end if;
+ if $2 = 'pg_catalog.anyarray'::pg_catalog.regtype then
+ if EXISTS(select 1 from pg_catalog.pg_type where
+ oid = $1 and typelem != 0 and typlen = -1)
+ then return true; end if;
+ end if;
+ if $2 = 'pg_catalog.anyrange'::pg_catalog.regtype then
+ if (select typtype from pg_catalog.pg_type where oid = $1) = 'r'
+ then return true; end if;
+ end if;
+ return false;
+end
+$$ language plpgsql strict stable;
-- This one ignores castcontext, so it considers only physical equivalence
-- and not whether the coercion can be invoked implicitly.
create function physically_coercible(oid, oid) returns bool as $$
-SELECT ($1 = $2) OR
- EXISTS(select 1 from pg_catalog.pg_cast where
- castsource = $1 and casttarget = $2 and
- castmethod = 'b') OR
- ($2 = 'pg_catalog.any'::pg_catalog.regtype) OR
- ($2 = 'pg_catalog.anyarray'::pg_catalog.regtype AND
- EXISTS(select 1 from pg_catalog.pg_type where
- oid = $1 and typelem != 0 and typlen = -1)) OR
- ($2 = 'pg_catalog.anyrange'::pg_catalog.regtype AND
- (select typtype from pg_catalog.pg_type where oid = $1) = 'r')
-$$ language sql strict stable;
+begin
+ if $1 = $2 then return true; end if;
+ if EXISTS(select 1 from pg_catalog.pg_cast where
+ castsource = $1 and casttarget = $2 and
+ castmethod = 'b')
+ then return true; end if;
+ if $2 = 'pg_catalog.any'::pg_catalog.regtype then return true; end if;
+ if $2 = 'pg_catalog.anyarray'::pg_catalog.regtype then
+ if EXISTS(select 1 from pg_catalog.pg_type where
+ oid = $1 and typelem != 0 and typlen = -1)
+ then return true; end if;
+ end if;
+ if $2 = 'pg_catalog.anyrange'::pg_catalog.regtype then
+ if (select typtype from pg_catalog.pg_type where oid = $1) = 'r'
+ then return true; end if;
+ end if;
+ return false;
+end
+$$ language plpgsql strict stable;
-- **************** pg_proc ****************
-- be called directly; those should have comments matching their operator.
WITH funcdescs AS (
SELECT p.oid as p_oid, proname, o.oid as o_oid,
- obj_description(p.oid, 'pg_proc') as prodesc,
+ pd.description as prodesc,
'implementation of ' || oprname || ' operator' as expecteddesc,
- obj_description(o.oid, 'pg_operator') as oprdesc
+ od.description as oprdesc
FROM pg_proc p JOIN pg_operator o ON oprcode = p.oid
+ LEFT JOIN pg_description pd ON
+ (pd.objoid = p.oid and pd.classoid = p.tableoid and pd.objsubid = 0)
+ LEFT JOIN pg_description od ON
+ (od.objoid = o.oid and od.classoid = o.tableoid and od.objsubid = 0)
WHERE o.oid <= 9999
)
SELECT * FROM funcdescs
-- This should be a pretty short list; it's mostly legacy cases.
WITH funcdescs AS (
SELECT p.oid as p_oid, proname, o.oid as o_oid,
- obj_description(p.oid, 'pg_proc') as prodesc,
+ pd.description as prodesc,
'implementation of ' || oprname || ' operator' as expecteddesc,
- obj_description(o.oid, 'pg_operator') as oprdesc
+ od.description as oprdesc
FROM pg_proc p JOIN pg_operator o ON oprcode = p.oid
+ LEFT JOIN pg_description pd ON
+ (pd.objoid = p.oid and pd.classoid = p.tableoid and pd.objsubid = 0)
+ LEFT JOIN pg_description od ON
+ (od.objoid = o.oid and od.classoid = o.tableoid and od.objsubid = 0)
WHERE o.oid <= 9999
)
SELECT p_oid, proname, prodesc FROM funcdescs