#3092, Slow performance of geometry_columns

git-svn-id: http://svn.osgeo.org/postgis/trunk@13443 b70326c6-7e19-0410-871a-916f4a2858ee
This commit is contained in:
Paul Ramsey 2015-04-24 17:50:00 +00:00
parent a0885952a8
commit 75a88c1a6c
2 changed files with 105 additions and 30 deletions

1
NEWS
View file

@ -82,6 +82,7 @@ PostGIS 2.2.0
and no NODATA specified
- #2906, Update tiger geocoder to handle tiger 2014 data
- #3048, Speed up geometry simplification (J.Santana @ CartoDB)
- #3092, Slow performance of geometry_columns with many tables
* Bug Fixes *

View file

@ -4983,38 +4983,112 @@ SELECT replace(split_part(s.consrc, '''', 2), ')', '')::varchar
$$
LANGUAGE 'sql' STABLE STRICT;
CREATE OR REPLACE FUNCTION postgis_constraint_array_srid(constraints text[])
RETURNS integer AS
$$
DECLARE
constr TEXT;
matches TEXT[];
BEGIN
FOREACH constr IN ARRAY $1
LOOP
matches := regexp_matches(constr, E'srid\\(.+\\) = (\\d+)', 'i');
IF matches[1] IS NOT NULL THEN
RETURN matches[1];
END IF;
END LOOP;
RETURN NULL;
END;
$$
LANGUAGE 'plpgsql' STABLE STRICT;
CREATE OR REPLACE FUNCTION postgis_constraint_array_dims(constraints text[])
RETURNS integer AS
$$
DECLARE
constr TEXT;
matches TEXT[];
BEGIN
FOREACH constr IN ARRAY $1
LOOP
matches := regexp_matches(constr, E'ndims\\(.+\\) = (\\d+)', 'i');
IF matches[1] IS NOT NULL THEN
RETURN matches[1];
END IF;
END LOOP;
RETURN NULL;
END;
$$
LANGUAGE 'plpgsql' STABLE STRICT;
CREATE OR REPLACE FUNCTION postgis_constraint_array_type(constraints text[])
RETURNS text AS
$$
DECLARE
constr TEXT;
matches TEXT[];
BEGIN
FOREACH constr IN ARRAY $1
LOOP
matches := regexp_matches(constr, E'geometrytype\\(.+\\) = ''(ST_)?(\\S+)''', 'i');
IF matches[2] IS NOT NULL THEN
RETURN upper(matches[2]);
END IF;
END LOOP;
RETURN NULL;
END;
$$
LANGUAGE 'plpgsql' STABLE STRICT;
CREATE OR REPLACE VIEW geometry_columns AS
SELECT current_database()::varchar(256) AS f_table_catalog,
n.nspname::varchar(256) AS f_table_schema,
c.relname::varchar(256) AS f_table_name,
a.attname::varchar(256) AS f_geometry_column,
COALESCE(postgis_typmod_dims(a.atttypmod),
postgis_constraint_dims(n.nspname, c.relname, a.attname),
2) AS coord_dimension, -- should it be 0 instead ?
COALESCE(NULLIF(postgis_typmod_srid(a.atttypmod),0),
postgis_constraint_srid(n.nspname, c.relname, a.attname),
0) AS srid,
-- force to be uppercase with no ZM so is backwards compatible
-- with old geometry_columns
WITH raw AS
(SELECT
n.nspname
,c.relname
,a.attname
,t.typname
,a.atttypmod
,array_agg(s.consrc::text) as constraints
FROM pg_class c
JOIN pg_attribute a ON a.attrelid = c.oid AND NOT a.attisdropped
JOIN pg_namespace n ON c.relnamespace = n.oid
JOIN pg_type t ON a.atttypid = t.oid
LEFT JOIN pg_constraint s ON s.connamespace = n.oid
AND s.conrelid = c.oid
AND a.attnum = ANY (s.conkey)
AND (s.consrc ILIKE '%geometrytype(% = %' OR s.consrc ILIKE '%ndims(% = %' OR s.consrc ILIKE '%srid(% = %')
WHERE c.relkind IN ('r'::"char", 'v'::"char", 'm'::"char", 'f'::"char")
AND NOT ( n.nspname = 'public' AND c.relname = 'raster_columns' )
AND t.typname = 'geometry'::name
AND NOT pg_is_other_temp_schema(c.relnamespace)
AND has_table_privilege( c.oid, 'SELECT'::text )
GROUP BY n.nspname, c.relname, a.attname, t.typname, a.atttypmod
)
SELECT
current_database()::varchar(256) AS f_table_catalog,
nspname::varchar(256) AS f_table_schema,
relname::varchar(256) AS f_table_name,
attname::varchar(256) AS f_geometry_column,
COALESCE(postgis_typmod_dims(atttypmod),
postgis_constraint_array_dims(constraints),
2) AS coord_dimension,
COALESCE(NULLIF(postgis_typmod_srid(atttypmod),0),
postgis_constraint_array_srid(constraints),
0) AS srid,
-- force to be uppercase with no ZM so is backwards compatible
-- with old geometry_columns
replace(
replace(
replace(
COALESCE(
NULLIF(upper(postgis_typmod_type(a.atttypmod)::text), 'GEOMETRY'),
postgis_constraint_type(n.nspname, c.relname, a.attname),
'GEOMETRY'
), 'ZM', ''
), 'Z', ''
)::varchar(30) AS type
FROM pg_class c, pg_attribute a, pg_type t, pg_namespace n
WHERE t.typname = 'geometry'::name
AND a.attisdropped = false
AND a.atttypid = t.oid
AND a.attrelid = c.oid
AND c.relnamespace = n.oid
AND (c.relkind = 'r'::"char" OR c.relkind = 'v'::"char" OR c.relkind = 'm'::"char" OR c.relkind = 'f'::"char")
AND NOT pg_is_other_temp_schema(c.relnamespace)
AND NOT ( n.nspname = 'public' AND c.relname = 'raster_columns' )
AND has_table_privilege( c.oid, 'SELECT'::text );
COALESCE(
NULLIF(upper(postgis_typmod_type(atttypmod)::text), 'GEOMETRY'),
postgis_constraint_array_type(constraints),
'GEOMETRY'
), 'ZM', ''
), 'Z', ''
)::varchar(30) AS type
FROM raw;
-- TODO: support RETURNING and raise a WARNING
CREATE OR REPLACE RULE geometry_columns_insert AS