Micro-optimize some slower queries in the opr_sanity regression test.

Convert the binary_coercible() and physically_coercible() functions from
SQL to plpgsql.  It's not that plpgsql is inherently better at doing
queries; if you simply convert the previous single SQL query into one
RETURN expression, it's no faster.  The problem with the existing code
is that it fools the plancache into deciding that it's worth re-planning
the query every time, since constant-folding with a concrete value for $2
allows elimination of at least one sub-SELECT.  In reality that's using the
planner to do the equivalent of a few runtime boolean tests, causing the
function to run much slower than it should.  Splitting the AND/OR logic
into separate plpgsql statements allows each if-expression to acquire a
static plan.

Also, get rid of some uses of obj_description() in favor of explicitly
joining to pg_description, allowing the joins to be optimized better.
(Someday we might improve the SQL-function-inlining logic enough that
this happens automatically, but today is not that day.)

Together, these changes reduce the runtime of the opr_sanity regression
test by about a factor of two on one of my slower machines.  They don't
seem to help as much on a fast machine, but this should at least benefit
the buildfarm.
This commit is contained in:
Tom Lane 2017-04-29 20:14:52 -04:00
parent bc920bee29
commit c23844212d
2 changed files with 100 additions and 52 deletions

View File

@ -20,31 +20,47 @@
-- 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
@ -1190,10 +1206,14 @@ WHERE d.classoid IS NULL AND p1.oid <= 9999;
-- 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
@ -1210,10 +1230,14 @@ 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

View File

@ -23,32 +23,48 @@
-- 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 ****************
@ -725,10 +741,14 @@ WHERE d.classoid IS NULL AND p1.oid <= 9999;
-- 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
@ -742,10 +762,14 @@ 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