proj4text varchar(2048)\r
);\r
\r
--------------------------------------------------------------------\r
--- GEOMETRY_COLUMNS\r
--------------------------------------------------------------------\r
-CREATE TABLE geometry_columns (\r
- f_table_catalog varchar(256) not null,\r
- f_table_schema varchar(256) not null,\r
- f_table_name varchar(256) not null,\r
- f_geometry_column varchar(256) not null,\r
- coord_dimension integer not null,\r
- srid integer not null,\r
- type varchar(30) not null,\r
- CONSTRAINT geometry_columns_pk primary key (\r
- f_table_catalog,\r
- f_table_schema,\r
- f_table_name,\r
- f_geometry_column )\r
-) WITH OIDS;\r
-\r
-\r
------------------------------------------------------------------------\r
--- RENAME_GEOMETRY_TABLE_CONSTRAINTS()\r
------------------------------------------------------------------------\r
--- This function has been obsoleted for the difficulty in\r
--- finding attribute on which the constraint is applied.\r
--- AddGeometryColumn will name the constraints in a meaningful\r
--- way, but nobody can rely on it since old postgis versions did\r
--- not do that.\r
------------------------------------------------------------------------\r
-CREATE OR REPLACE FUNCTION rename_geometry_table_constraints() RETURNS text\r
-AS\r
-$$\r
-SELECT 'rename_geometry_table_constraint() is obsoleted'::text\r
-$$\r
-LANGUAGE 'SQL' IMMUTABLE;\r
-\r
------------------------------------------------------------------------\r
--- FIX_GEOMETRY_COLUMNS()\r
------------------------------------------------------------------------\r
--- This function will:\r
---\r
--- o try to fix the schema of records with an integer one\r
--- (for PG>=73)\r
---\r
--- o link records to system tables through attrelid and varattnum\r
--- (for PG<75)\r
---\r
--- o delete all records for which no linking was possible\r
--- (for PG<75)\r
---\r
---\r
------------------------------------------------------------------------\r
-CREATE OR REPLACE FUNCTION fix_geometry_columns() RETURNS text\r
-AS\r
-$$\r
-DECLARE\r
- mislinked record;\r
- result text;\r
- linked integer;\r
- deleted integer;\r
- foundschema integer;\r
-BEGIN\r
-\r
- -- Since 7.3 schema support has been added.\r
- -- Previous postgis versions used to put the database name in\r
- -- the schema column. This needs to be fixed, so we try to\r
- -- set the correct schema for each geometry_colums record\r
- -- looking at table, column, type and srid.\r
- UPDATE geometry_columns SET f_table_schema = n.nspname\r
- FROM pg_namespace n, pg_class c, pg_attribute a,\r
- pg_constraint sridcheck, pg_constraint typecheck\r
- WHERE ( f_table_schema is NULL\r
- OR f_table_schema = ''\r
- OR f_table_schema NOT IN (\r
- SELECT nspname::varchar\r
- FROM pg_namespace nn, pg_class cc, pg_attribute aa\r
- WHERE cc.relnamespace = nn.oid\r
- AND cc.relname = f_table_name::name\r
- AND aa.attrelid = cc.oid\r
- AND aa.attname = f_geometry_column::name))\r
- AND f_table_name::name = c.relname\r
- AND c.oid = a.attrelid\r
- AND c.relnamespace = n.oid\r
- AND f_geometry_column::name = a.attname\r
-\r
- AND sridcheck.conrelid = c.oid\r
- AND sridcheck.consrc LIKE '(%srid(% = %)'\r
- AND sridcheck.consrc ~ textcat(' = ', srid::text)\r
-\r
- AND typecheck.conrelid = c.oid\r
- AND typecheck.consrc LIKE\r
- '((geometrytype(%) = ''%''::text) OR (% IS NULL))'\r
- AND typecheck.consrc ~ textcat(' = ''', type::text)\r
-\r
- AND NOT EXISTS (\r
- SELECT oid FROM geometry_columns gc\r
- WHERE c.relname::varchar = gc.f_table_name\r
- AND n.nspname::varchar = gc.f_table_schema\r
- AND a.attname::varchar = gc.f_geometry_column\r
- );\r
-\r
- GET DIAGNOSTICS foundschema = ROW_COUNT;\r
-\r
- -- no linkage to system table needed\r
- return 'fixed:'||foundschema::text;\r
-\r
-END;\r
-$$\r
-LANGUAGE 'plpgsql' VOLATILE;\r
\r
-----------------------------------------------------------------------\r
-- POPULATE_GEOMETRY_COLUMNS()\r
-- appropriate spatial contraints (for tables) and exists in the\r
-- geometry_columns table.\r
-- Availability: 1.4.0\r
+-- Revised: 2.0.0 -- no longer deletes from geometry_columns\r
+-- Has new use_typmod option taht defaults to true. \r
+-- If use typmod is set to false will use old constraint behavior.\r
+-- Will only touch table missing typmod or geometry constraints\r
-----------------------------------------------------------------------\r
-CREATE OR REPLACE FUNCTION populate_geometry_columns()\r
+CREATE OR REPLACE FUNCTION populate_geometry_columns(use_typmod boolean DEFAULT true)\r
RETURNS text AS\r
$$\r
DECLARE\r
SELECT count(*) INTO oldcount FROM geometry_columns;\r
inserted := 0;\r
\r
- EXECUTE 'TRUNCATE geometry_columns';\r
-\r
-- Count the number of geometry columns in all tables and views\r
SELECT count(DISTINCT c.oid) INTO probed\r
FROM pg_class c,\r
AND n.nspname NOT ILIKE 'pg_temp%'\r
LOOP\r
\r
- inserted := inserted + populate_geometry_columns(gcs.oid);\r
+ inserted := inserted + populate_geometry_columns(gcs.oid, use_typmod);\r
END LOOP;\r
\r
-- Add views to geometry columns table\r
AND c.relnamespace = n.oid\r
LOOP\r
\r
- inserted := inserted + populate_geometry_columns(gcs.oid);\r
+ inserted := inserted + populate_geometry_columns(gcs.oid, use_typmod);\r
END LOOP;\r
\r
IF oldcount > inserted THEN\r
- stale = oldcount-inserted;\r
+ stale = oldcount-inserted;\r
ELSE\r
- stale = 0;\r
+ stale = 0;\r
END IF;\r
\r
RETURN 'probed:' ||probed|| ' inserted:'||inserted|| ' conflicts:'||probed-inserted|| ' deleted:'||stale;\r
-- table.\r
-- Availability: 1.4.0\r
-----------------------------------------------------------------------\r
-CREATE OR REPLACE FUNCTION populate_geometry_columns(tbl_oid oid)\r
+CREATE OR REPLACE FUNCTION populate_geometry_columns(tbl_oid oid, use_typmod boolean DEFAULT true)\r
RETURNS integer AS\r
$$\r
DECLARE\r
gcs RECORD;\r
gc RECORD;\r
+ gc_old RECORD;\r
gsrid integer;\r
gndims integer;\r
gtype text;\r
AND c.oid = tbl_oid\r
LOOP\r
\r
- RAISE DEBUG 'Processing table %.%.%', gcs.nspname, gcs.relname, gcs.attname;\r
-\r
- DELETE FROM geometry_columns\r
- WHERE f_table_schema = gcs.nspname\r
- AND f_table_name = gcs.relname\r
- AND f_geometry_column = gcs.attname;\r
-\r
- gc_is_valid := true;\r
-\r
- -- Try to find srid check from system tables (pg_constraint)\r
- gsrid :=\r
- (SELECT replace(replace(split_part(s.consrc, ' = ', 2), ')', ''), '(', '')\r
- FROM pg_class c, pg_namespace n, pg_attribute a, pg_constraint s\r
- WHERE n.nspname = gcs.nspname\r
- AND c.relname = gcs.relname\r
- AND a.attname = gcs.attname\r
- AND a.attrelid = c.oid\r
- AND s.connamespace = n.oid\r
- AND s.conrelid = c.oid\r
- AND a.attnum = ANY (s.conkey)\r
- AND s.consrc LIKE '%srid(% = %');\r
- IF (gsrid IS NULL) THEN\r
- -- Try to find srid from the geometry itself\r
- EXECUTE 'SELECT st_srid(' || quote_ident(gcs.attname) || ') As srid\r
- FROM ONLY ' || quote_ident(gcs.nspname) || '.' || quote_ident(gcs.relname) || '\r
- WHERE ' || quote_ident(gcs.attname) || ' IS NOT NULL LIMIT 1'\r
- INTO gc;\r
- gsrid := gc.srid;\r
-\r
- -- Try to apply srid check to column\r
- IF (gsrid IS NOT NULL) THEN\r
- BEGIN\r
- EXECUTE 'ALTER TABLE ONLY ' || quote_ident(gcs.nspname) || '.' || quote_ident(gcs.relname) || '\r
- ADD CONSTRAINT ' || quote_ident('enforce_srid_' || gcs.attname) || '\r
- CHECK (st_srid(' || quote_ident(gcs.attname) || ') = ' || gsrid || ')';\r
- EXCEPTION\r
- WHEN check_violation THEN\r
- RAISE WARNING 'Not inserting ''%'' in ''%.%'' into geometry_columns: could not apply constraint CHECK (st_srid(%) = %)', quote_ident(gcs.attname), quote_ident(gcs.nspname), quote_ident(gcs.relname), quote_ident(gcs.attname), gsrid;\r
- gc_is_valid := false;\r
- END;\r
- END IF;\r
- END IF;\r
-\r
- -- Try to find ndims check from system tables (pg_constraint)\r
- gndims :=\r
- (SELECT replace(split_part(s.consrc, ' = ', 2), ')', '')\r
- FROM pg_class c, pg_namespace n, pg_attribute a, pg_constraint s\r
- WHERE n.nspname = gcs.nspname\r
- AND c.relname = gcs.relname\r
- AND a.attname = gcs.attname\r
- AND a.attrelid = c.oid\r
- AND s.connamespace = n.oid\r
- AND s.conrelid = c.oid\r
- AND a.attnum = ANY (s.conkey)\r
- AND s.consrc LIKE '%ndims(% = %');\r
- IF (gndims IS NULL) THEN\r
- -- Try to find ndims from the geometry itself\r
- EXECUTE 'SELECT st_ndims(' || quote_ident(gcs.attname) || ') As ndims\r
- FROM ONLY ' || quote_ident(gcs.nspname) || '.' || quote_ident(gcs.relname) || '\r
- WHERE ' || quote_ident(gcs.attname) || ' IS NOT NULL LIMIT 1'\r
- INTO gc;\r
- gndims := gc.ndims;\r
-\r
- -- Try to apply ndims check to column\r
- IF (gndims IS NOT NULL) THEN\r
- BEGIN\r
- EXECUTE 'ALTER TABLE ONLY ' || quote_ident(gcs.nspname) || '.' || quote_ident(gcs.relname) || '\r
- ADD CONSTRAINT ' || quote_ident('enforce_dims_' || gcs.attname) || '\r
- CHECK (st_ndims(' || quote_ident(gcs.attname) || ') = '||gndims||')';\r
- EXCEPTION\r
- WHEN check_violation THEN\r
- RAISE WARNING 'Not inserting ''%'' in ''%.%'' into geometry_columns: could not apply constraint CHECK (st_ndims(%) = %)', quote_ident(gcs.attname), quote_ident(gcs.nspname), quote_ident(gcs.relname), quote_ident(gcs.attname), gndims;\r
- gc_is_valid := false;\r
- END;\r
- END IF;\r
- END IF;\r
-\r
- -- Try to find geotype check from system tables (pg_constraint)\r
- gtype :=\r
- (SELECT replace(split_part(s.consrc, '''', 2), ')', '')\r
- FROM pg_class c, pg_namespace n, pg_attribute a, pg_constraint s\r
- WHERE n.nspname = gcs.nspname\r
- AND c.relname = gcs.relname\r
- AND a.attname = gcs.attname\r
- AND a.attrelid = c.oid\r
- AND s.connamespace = n.oid\r
- AND s.conrelid = c.oid\r
- AND a.attnum = ANY (s.conkey)\r
- AND s.consrc LIKE '%geometrytype(% = %');\r
- IF (gtype IS NULL) THEN\r
- -- Try to find geotype from the geometry itself\r
- EXECUTE 'SELECT geometrytype(' || quote_ident(gcs.attname) || ')\r
- FROM ONLY ' || quote_ident(gcs.nspname) || '.' || quote_ident(gcs.relname) || '\r
- WHERE ' || quote_ident(gcs.attname) || ' IS NOT NULL LIMIT 1'\r
- INTO gc;\r
- gtype := gc.geometrytype;\r
- --IF (gtype IS NULL) THEN\r
- -- gtype := 'GEOMETRY';\r
- --END IF;\r
-\r
- -- Try to apply geometrytype check to column\r
- IF (gtype IS NOT NULL) THEN\r
- BEGIN\r
- EXECUTE 'ALTER TABLE ONLY ' || quote_ident(gcs.nspname) || '.' || quote_ident(gcs.relname) || '\r
- ADD CONSTRAINT ' || quote_ident('enforce_geotype_' || gcs.attname) || '\r
- CHECK ((geometrytype(' || quote_ident(gcs.attname) || ') = ' || quote_literal(gtype) || ') OR (' || quote_ident(gcs.attname) || ' IS NULL))';\r
- EXCEPTION\r
- WHEN check_violation THEN\r
- -- No geometry check can be applied. This column contains a number of geometry types.\r
- RAISE WARNING 'Could not add geometry type check (%) to table column: %.%.%', gtype, quote_ident(gcs.nspname),quote_ident(gcs.relname),quote_ident(gcs.attname);\r
- END;\r
- END IF;\r
- END IF;\r
+ RAISE DEBUG 'Processing table %.%.%', gcs.nspname, gcs.relname, gcs.attname;\r
+ \r
+ gc_is_valid := true;\r
+ -- Find the srid, coord_dimension, and type of current geometry\r
+ -- in geometry_columns -- which is now a view\r
+ \r
+ SELECT type, srid, coord_dimension INTO gc_old \r
+ FROM geometry_columns \r
+ WHERE f_table_schema = gcs.nspname AND f_table_name = gcs.relname AND f_geometry_column = gcs.attname; \r
+ \r
+ IF upper(gc_old.type) = 'GEOMETRY' THEN\r
+ -- This is an unconstrained geometry we need to do something\r
+ -- We need to figure out what to set the type by inspecting the data\r
+ EXECUTE 'SELECT st_srid(' || quote_ident(gcs.attname) || ') As srid, GeometryType(' || quote_ident(gcs.attname) || ') As type, ST_NDims(' || quote_ident(gcs.attname) || ') As dims ' ||\r
+ ' FROM ONLY ' || quote_ident(gcs.nspname) || '.' || quote_ident(gcs.relname) || \r
+ ' WHERE ' || quote_ident(gcs.attname) || ' IS NOT NULL LIMIT 1;'\r
+ INTO gc;\r
+ gsrid := gc.srid; gtype := gc.type; gndims := gc.dims;\r
+ \r
+ IF use_typmod THEN\r
+ BEGIN\r
+ EXECUTE 'ALTER TABLE ' || quote_ident(gcs.nspname) || '.' || quote_ident(gcs.relname) || ' ALTER COLUMN ' || quote_ident(gcs.attname) || \r
+ ' TYPE geometry(' || postgis_type_name(gtype, gndims, true) || ', ' || gsrid::text || ') ';\r
+ inserted := inserted + 1;\r
+ EXCEPTION\r
+ WHEN check_violation THEN\r
+ RAISE WARNING 'Could not convert ''%'' in ''%.%'' to use typmod with srid ', quote_ident(gcs.attname), quote_ident(gcs.nspname), quote_ident(gcs.relname), quote_ident(gcs.attname), gsrid;\r
+ gc_is_valid := false;\r
+ END;\r
+ \r
+ ELSE\r
+ -- Try to apply srid check to column\r
+ IF (gsrid > 0) THEN\r
+ BEGIN\r
+ EXECUTE 'ALTER TABLE ONLY ' || quote_ident(gcs.nspname) || '.' || quote_ident(gcs.relname) || \r
+ ' ADD CONSTRAINT ' || quote_ident('enforce_srid_' || gcs.attname) || \r
+ ' CHECK (st_srid(' || quote_ident(gcs.attname) || ') = ' || gsrid || ')';\r
+ EXCEPTION\r
+ WHEN check_violation THEN\r
+ RAISE WARNING 'Not inserting ''%'' in ''%.%'' into geometry_columns: could not apply constraint CHECK (st_srid(%) = %)', quote_ident(gcs.attname), quote_ident(gcs.nspname), quote_ident(gcs.relname), quote_ident(gcs.attname), gsrid;\r
+ gc_is_valid := false;\r
+ END;\r
+ END IF;\r
+ \r
+ -- Try to apply ndims check to column\r
+ IF (gndims IS NOT NULL) THEN\r
+ BEGIN\r
+ EXECUTE 'ALTER TABLE ONLY ' || quote_ident(gcs.nspname) || '.' || quote_ident(gcs.relname) || '\r
+ ADD CONSTRAINT ' || quote_ident('enforce_dims_' || gcs.attname) || '\r
+ CHECK (st_ndims(' || quote_ident(gcs.attname) || ') = '||gndims||')';\r
+ EXCEPTION\r
+ WHEN check_violation THEN\r
+ RAISE WARNING 'Not inserting ''%'' in ''%.%'' into geometry_columns: could not apply constraint CHECK (st_ndims(%) = %)', quote_ident(gcs.attname), quote_ident(gcs.nspname), quote_ident(gcs.relname), quote_ident(gcs.attname), gndims;\r
+ gc_is_valid := false;\r
+ END;\r
+ END IF;\r
+ \r
+ -- Try to apply geometrytype check to column\r
+ IF (gtype IS NOT NULL) THEN\r
+ BEGIN\r
+ EXECUTE 'ALTER TABLE ONLY ' || quote_ident(gcs.nspname) || '.' || quote_ident(gcs.relname) || '\r
+ ADD CONSTRAINT ' || quote_ident('enforce_geotype_' || gcs.attname) || '\r
+ CHECK ((geometrytype(' || quote_ident(gcs.attname) || ') = ' || quote_literal(gtype) || ') OR (' || quote_ident(gcs.attname) || ' IS NULL))';\r
+ EXCEPTION\r
+ WHEN check_violation THEN\r
+ -- No geometry check can be applied. This column contains a number of geometry types.\r
+ RAISE WARNING 'Could not add geometry type check (%) to table column: %.%.%', gtype, quote_ident(gcs.nspname),quote_ident(gcs.relname),quote_ident(gcs.attname);\r
+ END;\r
+ END IF;\r
+ inserted := inserted + 1;\r
+ END IF; \r
+ END IF;\r
\r
- IF (gsrid IS NULL) THEN\r
- RAISE WARNING 'Not inserting ''%'' in ''%.%'' into geometry_columns: could not determine the srid', quote_ident(gcs.attname), quote_ident(gcs.nspname), quote_ident(gcs.relname);\r
- ELSIF (gndims IS NULL) THEN\r
- RAISE WARNING 'Not inserting ''%'' in ''%.%'' into geometry_columns: could not determine the number of dimensions', quote_ident(gcs.attname), quote_ident(gcs.nspname), quote_ident(gcs.relname);\r
- ELSIF (gtype IS NULL) THEN\r
- RAISE WARNING 'Not inserting ''%'' in ''%.%'' into geometry_columns: could not determine the geometry type', quote_ident(gcs.attname), quote_ident(gcs.nspname), quote_ident(gcs.relname);\r
- ELSE\r
- -- Only insert into geometry_columns if table constraints could be applied.\r
- IF (gc_is_valid) THEN\r
- INSERT INTO geometry_columns (f_table_catalog,f_table_schema, f_table_name, f_geometry_column, coord_dimension, srid, type)\r
- VALUES ('', gcs.nspname, gcs.relname, gcs.attname, gndims, gsrid, gtype);\r
- inserted := inserted + 1;\r
- END IF;\r
- END IF;\r
- END LOOP;\r
-\r
- -- Add views to geometry columns table\r
- FOR gcs IN\r
- SELECT n.nspname, c.relname, a.attname\r
- FROM pg_class c,\r
- pg_attribute a,\r
- pg_type t,\r
- pg_namespace n\r
- WHERE c.relkind = 'v'\r
- AND t.typname = 'geometry'\r
- AND a.attisdropped = false\r
- AND a.atttypid = t.oid\r
- AND a.attrelid = c.oid\r
- AND c.relnamespace = n.oid\r
- AND n.nspname NOT ILIKE 'pg_temp%'\r
- AND c.oid = tbl_oid\r
- LOOP\r
- \r
- DELETE FROM geometry_columns\r
- WHERE f_table_schema = gcs.nspname\r
- AND f_table_name = gcs.relname\r
- AND f_geometry_column = gcs.attname;\r
- \r
- RAISE DEBUG 'Processing view %.%.%', gcs.nspname, gcs.relname, gcs.attname;\r
-\r
- EXECUTE 'SELECT st_ndims(' || quote_ident(gcs.attname) || ') As ndims\r
- FROM ' || quote_ident(gcs.nspname) || '.' || quote_ident(gcs.relname) || '\r
- WHERE ' || quote_ident(gcs.attname) || ' IS NOT NULL LIMIT 1'\r
- INTO gc;\r
- gndims := gc.ndims;\r
-\r
- EXECUTE 'SELECT st_srid(' || quote_ident(gcs.attname) || ') As srid\r
- FROM ' || quote_ident(gcs.nspname) || '.' || quote_ident(gcs.relname) || '\r
- WHERE ' || quote_ident(gcs.attname) || ' IS NOT NULL LIMIT 1'\r
- INTO gc;\r
- gsrid := gc.srid;\r
-\r
- EXECUTE 'SELECT geometrytype(' || quote_ident(gcs.attname) || ')\r
- FROM ' || quote_ident(gcs.nspname) || '.' || quote_ident(gcs.relname) || '\r
- WHERE ' || quote_ident(gcs.attname) || ' IS NOT NULL LIMIT 1'\r
- INTO gc;\r
- gtype := gc.geometrytype;\r
-\r
- IF (gndims IS NULL) THEN\r
- RAISE WARNING 'Not inserting ''%'' in ''%.%'' into geometry_columns: could not determine ndims', quote_ident(gcs.attname), quote_ident(gcs.nspname), quote_ident(gcs.relname);\r
- ELSIF (gsrid IS NULL) THEN\r
- RAISE WARNING 'Not inserting ''%'' in ''%.%'' into geometry_columns: could not determine srid', quote_ident(gcs.attname), quote_ident(gcs.nspname), quote_ident(gcs.relname);\r
- ELSIF (gtype IS NULL) THEN\r
- RAISE WARNING 'Not inserting ''%'' in ''%.%'' into geometry_columns: could not determine gtype', quote_ident(gcs.attname), quote_ident(gcs.nspname), quote_ident(gcs.relname);\r
- ELSE\r
- query := 'INSERT INTO geometry_columns (f_table_catalog,f_table_schema, f_table_name, f_geometry_column, coord_dimension, srid, type) ' ||\r
- 'VALUES ('''', ' || quote_literal(gcs.nspname) || ',' || quote_literal(gcs.relname) || ',' || quote_literal(gcs.attname) || ',' || gndims || ',' || gsrid || ',' || quote_literal(gtype) || ')';\r
- EXECUTE query;\r
- inserted := inserted + 1;\r
- END IF;\r
END LOOP;\r
\r
RETURN inserted;\r
$$\r
LANGUAGE 'plpgsql' VOLATILE;\r
\r
-\r
------------------------------------------------------------------------\r
--- PROBE_GEOMETRY_COLUMNS()\r
------------------------------------------------------------------------\r
--- Fill the geometry_columns table with values probed from the system\r
--- catalogues. This is done by simply looking up constraints previously\r
--- added to a geometry column. If geometry constraints are missing, no\r
--- attempt is made to add the necessary constraints to the geometry\r
--- column, nor is it recorded in the geometry_columns table.\r
--- 3d flag cannot be probed, it defaults to 2\r
---\r
--- Note that bogus records already in geometry_columns are not\r
--- overridden (a check for schema.table.column is performed), so\r
--- to have a fresh probe backup your geometry_columns, delete from\r
--- it and probe.\r
------------------------------------------------------------------------\r
-CREATE OR REPLACE FUNCTION probe_geometry_columns() RETURNS text AS\r
-$$\r
-DECLARE\r
- inserted integer;\r
- oldcount integer;\r
- probed integer;\r
- stale integer;\r
-BEGIN\r
-\r
- SELECT count(*) INTO oldcount FROM geometry_columns;\r
-\r
- SELECT count(*) INTO probed\r
- FROM pg_class c, pg_attribute a, pg_type t,\r
- pg_namespace n,\r
- pg_constraint sridcheck, pg_constraint typecheck\r
-\r
- WHERE t.typname = 'geometry'\r
- AND a.atttypid = t.oid\r
- AND a.attrelid = c.oid\r
- AND c.relnamespace = n.oid\r
- AND sridcheck.connamespace = n.oid\r
- AND typecheck.connamespace = n.oid\r
- AND sridcheck.conrelid = c.oid\r
- AND sridcheck.consrc LIKE '(%srid('||a.attname||') = %)'\r
- AND typecheck.conrelid = c.oid\r
- AND typecheck.consrc LIKE\r
- '((geometrytype('||a.attname||') = ''%''::text) OR (% IS NULL))'\r
- ;\r
-\r
- INSERT INTO geometry_columns SELECT\r
- ''::varchar as f_table_catalogue,\r
- n.nspname::varchar as f_table_schema,\r
- c.relname::varchar as f_table_name,\r
- a.attname::varchar as f_geometry_column,\r
- 2 as coord_dimension,\r
- trim(both ' =)' from\r
- replace(replace(split_part(\r
- sridcheck.consrc, ' = ', 2), ')', ''), '(', ''))::integer AS srid,\r
- trim(both ' =)''' from substr(typecheck.consrc,\r
- strpos(typecheck.consrc, '='),\r
- strpos(typecheck.consrc, '::')-\r
- strpos(typecheck.consrc, '=')\r
- ))::varchar as type\r
- FROM pg_class c, pg_attribute a, pg_type t,\r
- pg_namespace n,\r
- pg_constraint sridcheck, pg_constraint typecheck\r
- WHERE t.typname = 'geometry'\r
- AND a.atttypid = t.oid\r
- AND a.attrelid = c.oid\r
- AND c.relnamespace = n.oid\r
- AND sridcheck.connamespace = n.oid\r
- AND typecheck.connamespace = n.oid\r
- AND sridcheck.conrelid = c.oid\r
- AND sridcheck.consrc LIKE '(%srid('||a.attname||') = %)'\r
- AND typecheck.conrelid = c.oid\r
- AND typecheck.consrc LIKE\r
- '((geometrytype('||a.attname||') = ''%''::text) OR (% IS NULL))'\r
-\r
- AND NOT EXISTS (\r
- SELECT oid FROM geometry_columns gc\r
- WHERE c.relname::varchar = gc.f_table_name\r
- AND n.nspname::varchar = gc.f_table_schema\r
- AND a.attname::varchar = gc.f_geometry_column\r
- );\r
-\r
- GET DIAGNOSTICS inserted = ROW_COUNT;\r
-\r
- IF oldcount > probed THEN\r
- stale = oldcount-probed;\r
- ELSE\r
- stale = 0;\r
- END IF;\r
-\r
- RETURN 'probed:'||probed::text||\r
- ' inserted:'||inserted::text||\r
- ' conflicts:'||(probed-inserted)::text||\r
- ' stale:'||stale::text;\r
-END\r
-\r
-$$\r
-LANGUAGE 'plpgsql' VOLATILE;\r
-\r
-----------------------------------------------------------------------\r
-- ADDGEOMETRYCOLUMN\r
-- <catalogue>, <schema>, <table>, <column>, <srid>, <type>, <dim>\r
-- Should also check the precision grid (future expansion).\r
--\r
-----------------------------------------------------------------------\r
-CREATE OR REPLACE FUNCTION AddGeometryColumn(varchar,varchar,varchar,varchar,integer,varchar,integer)\r
+CREATE OR REPLACE FUNCTION AddGeometryColumn(catalog_name varchar,schema_name varchar,table_name varchar,column_name varchar,new_srid integer,new_type varchar,new_dim integer, use_typmod boolean DEFAULT true)\r
RETURNS text\r
AS\r
$$\r
DECLARE\r
- catalog_name alias for $1;\r
- schema_name alias for $2;\r
- table_name alias for $3;\r
- column_name alias for $4;\r
- new_srid alias for $5;\r
- new_type alias for $6;\r
- new_dim alias for $7;\r
rec RECORD;\r
sr varchar;\r
real_schema name;\r
BEGIN\r
\r
-- Verify geometry type\r
- IF ( NOT ( (new_type = 'GEOMETRY') OR\r
- (new_type = 'GEOMETRYCOLLECTION') OR\r
- (new_type = 'POINT') OR\r
- (new_type = 'MULTIPOINT') OR\r
- (new_type = 'POLYGON') OR\r
- (new_type = 'MULTIPOLYGON') OR\r
- (new_type = 'LINESTRING') OR\r
- (new_type = 'MULTILINESTRING') OR\r
- (new_type = 'GEOMETRYCOLLECTIONM') OR\r
- (new_type = 'POINTM') OR\r
- (new_type = 'MULTIPOINTM') OR\r
- (new_type = 'POLYGONM') OR\r
- (new_type = 'MULTIPOLYGONM') OR\r
- (new_type = 'LINESTRINGM') OR\r
- (new_type = 'MULTILINESTRINGM') OR\r
- (new_type = 'CIRCULARSTRING') OR\r
- (new_type = 'CIRCULARSTRINGM') OR\r
- (new_type = 'COMPOUNDCURVE') OR\r
- (new_type = 'COMPOUNDCURVEM') OR\r
- (new_type = 'CURVEPOLYGON') OR\r
- (new_type = 'CURVEPOLYGONM') OR\r
- (new_type = 'MULTICURVE') OR\r
- (new_type = 'MULTICURVEM') OR\r
- (new_type = 'MULTISURFACE') OR\r
- (new_type = 'MULTISURFACEM') OR\r
- (new_type = 'TRIANGLE') OR\r
- (new_type = 'TRIANGLEM') OR\r
- (new_type = 'POLYHEDRALSURFACE') OR\r
- (new_type = 'POLYHEDRALSURFACEM') OR\r
- (new_type = 'TIN') OR\r
- (new_type = 'TINM')) )\r
+ IF (postgis_type_name(new_type,new_dim) IS NULL )\r
THEN\r
RAISE EXCEPTION 'Invalid type name - valid ones are:\r
POINT, MULTIPOINT,\r
\r
\r
-- Verify SRID\r
- IF ( new_srid != -1 ) THEN\r
+ IF ( new_srid != 0 AND new_srid != -1) THEN\r
SELECT SRID INTO sr FROM spatial_ref_sys WHERE SRID = new_srid;\r
IF NOT FOUND THEN\r
RAISE EXCEPTION 'AddGeometryColumns() - invalid SRID';\r
\r
\r
-- Add geometry column to table\r
- sql := 'ALTER TABLE ' ||\r
- quote_ident(real_schema) || '.' || quote_ident(table_name)\r
- || ' ADD COLUMN ' || quote_ident(column_name) ||\r
- ' geometry ';\r
- RAISE DEBUG '%', sql;\r
- EXECUTE sql;\r
-\r
-\r
- -- Delete stale record in geometry_columns (if any)\r
- sql := 'DELETE FROM geometry_columns WHERE\r
- f_table_catalog = ' || quote_literal('') ||\r
- ' AND f_table_schema = ' ||\r
- quote_literal(real_schema) ||\r
- ' AND f_table_name = ' || quote_literal(table_name) ||\r
- ' AND f_geometry_column = ' || quote_literal(column_name);\r
- RAISE DEBUG '%', sql;\r
- EXECUTE sql;\r
-\r
-\r
- -- Add record in geometry_columns\r
- sql := 'INSERT INTO geometry_columns (f_table_catalog,f_table_schema,f_table_name,' ||\r
- 'f_geometry_column,coord_dimension,srid,type)' ||\r
- ' VALUES (' ||\r
- quote_literal('') || ',' ||\r
- quote_literal(real_schema) || ',' ||\r
- quote_literal(table_name) || ',' ||\r
- quote_literal(column_name) || ',' ||\r
- new_dim::text || ',' ||\r
- new_srid::text || ',' ||\r
- quote_literal(new_type) || ')';\r
- RAISE DEBUG '%', sql;\r
- EXECUTE sql;\r
-\r
-\r
- -- Add table CHECKs\r
- sql := 'ALTER TABLE ' ||\r
- quote_ident(real_schema) || '.' || quote_ident(table_name)\r
- || ' ADD CONSTRAINT '\r
- || quote_ident('enforce_srid_' || column_name)\r
- || ' CHECK (st_srid(' || quote_ident(column_name) ||\r
- ') = ' || new_srid::text || ')' ;\r
- RAISE DEBUG '%', sql;\r
- EXECUTE sql;\r
-\r
- sql := 'ALTER TABLE ' ||\r
- quote_ident(real_schema) || '.' || quote_ident(table_name)\r
- || ' ADD CONSTRAINT '\r
- || quote_ident('enforce_dims_' || column_name)\r
- || ' CHECK (st_ndims(' || quote_ident(column_name) ||\r
- ') = ' || new_dim::text || ')' ;\r
- RAISE DEBUG '%', sql;\r
+ IF use_typmod THEN\r
+ sql := 'ALTER TABLE ' ||\r
+ quote_ident(real_schema) || '.' || quote_ident(table_name)\r
+ || ' ADD COLUMN ' || quote_ident(column_name) ||\r
+ ' geometry(' || postgis_type_name(new_type, new_dim) || ', ' || new_srid::text || ')';\r
+ RAISE DEBUG '%', sql;\r
+ ELSE\r
+ sql := 'ALTER TABLE ' ||\r
+ quote_ident(real_schema) || '.' || quote_ident(table_name)\r
+ || ' ADD COLUMN ' || quote_ident(column_name) ||\r
+ ' geometry ';\r
+ RAISE DEBUG '%', sql;\r
+ END IF;\r
EXECUTE sql;\r
\r
- IF ( NOT (new_type = 'GEOMETRY')) THEN\r
- sql := 'ALTER TABLE ' ||\r
- quote_ident(real_schema) || '.' || quote_ident(table_name) || ' ADD CONSTRAINT ' ||\r
- quote_ident('enforce_geotype_' || column_name) ||\r
- ' CHECK (GeometryType(' ||\r
- quote_ident(column_name) || ')=' ||\r
- quote_literal(new_type) || ' OR (' ||\r
- quote_ident(column_name) || ') is null)';\r
- RAISE DEBUG '%', sql;\r
- EXECUTE sql;\r
- END IF;\r
+ IF NOT use_typmod THEN\r
+ -- Add table CHECKs\r
+ sql := 'ALTER TABLE ' ||\r
+ quote_ident(real_schema) || '.' || quote_ident(table_name)\r
+ || ' ADD CONSTRAINT '\r
+ || quote_ident('enforce_srid_' || column_name)\r
+ || ' CHECK (st_srid(' || quote_ident(column_name) ||\r
+ ') = ' || new_srid::text || ')' ;\r
+ RAISE DEBUG '%', sql;\r
+ EXECUTE sql;\r
+ \r
+ sql := 'ALTER TABLE ' ||\r
+ quote_ident(real_schema) || '.' || quote_ident(table_name)\r
+ || ' ADD CONSTRAINT '\r
+ || quote_ident('enforce_dims_' || column_name)\r
+ || ' CHECK (st_ndims(' || quote_ident(column_name) ||\r
+ ') = ' || new_dim::text || ')' ;\r
+ RAISE DEBUG '%', sql;\r
+ EXECUTE sql;\r
+ \r
+ IF ( NOT (new_type = 'GEOMETRY')) THEN\r
+ sql := 'ALTER TABLE ' ||\r
+ quote_ident(real_schema) || '.' || quote_ident(table_name) || ' ADD CONSTRAINT ' ||\r
+ quote_ident('enforce_geotype_' || column_name) ||\r
+ ' CHECK (GeometryType(' ||\r
+ quote_ident(column_name) || ')=' ||\r
+ quote_literal(new_type) || ' OR (' ||\r
+ quote_ident(column_name) || ') is null)';\r
+ RAISE DEBUG '%', sql;\r
+ EXECUTE sql;\r
+ END IF;\r
+ END IF;\r
\r
RETURN\r
real_schema || '.' ||\r
-- when catalogue is undefined\r
--\r
----------------------------------------------------------------------------\r
-CREATE OR REPLACE FUNCTION AddGeometryColumn(varchar,varchar,varchar,integer,varchar,integer) RETURNS text AS $$\r
+CREATE OR REPLACE FUNCTION AddGeometryColumn(schema_name varchar,table_name varchar,column_name varchar,new_srid integer,new_type varchar,new_dim integer, use_typmod boolean DEFAULT true) RETURNS text AS $$\r
DECLARE\r
ret text;\r
BEGIN\r
- SELECT AddGeometryColumn('',$1,$2,$3,$4,$5,$6) into ret;\r
+ SELECT AddGeometryColumn('',$1,$2,$3,$4,$5,$6,$7) into ret;\r
RETURN ret;\r
END;\r
$$\r
-- when catalogue and schema are undefined\r
--\r
----------------------------------------------------------------------------\r
-CREATE OR REPLACE FUNCTION AddGeometryColumn(varchar,varchar,integer,varchar,integer) RETURNS text AS $$\r
+CREATE OR REPLACE FUNCTION AddGeometryColumn(table_name varchar,column_name varchar,new_srid integer,new_type varchar,new_dim integer, use_typmod boolean DEFAULT true) RETURNS text AS $$\r
DECLARE\r
ret text;\r
BEGIN\r
- SELECT AddGeometryColumn('','',$1,$2,$3,$4,$5) into ret;\r
+ SELECT AddGeometryColumn('','',$1,$2,$3,$4,$5, $6) into ret;\r
RETURN ret;\r
END;\r
$$\r
-- Make some silly enforcements on it for pgsql < 73\r
--\r
-----------------------------------------------------------------------\r
-CREATE OR REPLACE FUNCTION DropGeometryColumn(varchar, varchar,varchar,varchar)\r
+CREATE OR REPLACE FUNCTION DropGeometryColumn(catalog_name varchar, schema_name varchar,table_name varchar,column_name varchar)\r
RETURNS text\r
AS\r
$$\r
DECLARE\r
- catalog_name alias for $1;\r
- schema_name alias for $2;\r
- table_name alias for $3;\r
- column_name alias for $4;\r
myrec RECORD;\r
okay boolean;\r
real_schema name;\r
\r
-- Find, check or fix schema_name\r
IF ( schema_name != '' ) THEN\r
- okay = 'f';\r
+ okay = false;\r
\r
FOR myrec IN SELECT nspname FROM pg_namespace WHERE text(nspname) = schema_name LOOP\r
- okay := 't';\r
+ okay := true;\r
END LOOP;\r
\r
- IF ( okay <> 't' ) THEN\r
+ IF ( okay <> true ) THEN\r
RAISE NOTICE 'Invalid schema name - using current_schema()';\r
SELECT current_schema() into real_schema;\r
ELSE\r
END IF;\r
\r
-- Find out if the column is in the geometry_columns table\r
- okay = 'f';\r
+ okay = false;\r
FOR myrec IN SELECT * from geometry_columns where f_table_schema = text(real_schema) and f_table_name = table_name and f_geometry_column = column_name LOOP\r
- okay := 't';\r
+ okay := true;\r
END LOOP;\r
- IF (okay <> 't') THEN\r
+ IF (okay <> true) THEN\r
RAISE EXCEPTION 'column not found in geometry_columns table';\r
- RETURN 'f';\r
+ RETURN false;\r
END IF;\r
\r
- -- Remove ref from geometry_columns table\r
- EXECUTE 'delete from geometry_columns where f_table_schema = ' ||\r
- quote_literal(real_schema) || ' and f_table_name = ' ||\r
- quote_literal(table_name) || ' and f_geometry_column = ' ||\r
- quote_literal(column_name);\r
-\r
-- Remove table column\r
EXECUTE 'ALTER TABLE ' || quote_ident(real_schema) || '.' ||\r
quote_ident(table_name) || ' DROP COLUMN ' ||\r
-- when catalogue is undefined\r
--\r
-----------------------------------------------------------------------\r
-CREATE OR REPLACE FUNCTION DropGeometryColumn(varchar,varchar,varchar)\r
+CREATE OR REPLACE FUNCTION DropGeometryColumn(schema_name varchar, table_name varchar,column_name varchar)\r
RETURNS text\r
AS\r
$$\r
real_schema = schema_name;\r
END IF;\r
\r
+ -- TODO: Should we warn if table doesn't exist probably instead just saying dropped\r
-- Remove table\r
EXECUTE 'DROP TABLE IF EXISTS '\r
|| quote_ident(real_schema) || '.' ||\r
-- Change SRID of all features in a spatially-enabled table\r
--\r
-----------------------------------------------------------------------\r
-CREATE OR REPLACE FUNCTION UpdateGeometrySRID(varchar,varchar,varchar,varchar,integer)\r
+CREATE OR REPLACE FUNCTION UpdateGeometrySRID(catalogn_name varchar,schema_name varchar,table_name varchar,column_name varchar,new_srid integer)\r
RETURNS text\r
AS\r
$$\r
DECLARE\r
- catalog_name alias for $1;\r
- schema_name alias for $2;\r
- table_name alias for $3;\r
- column_name alias for $4;\r
- new_srid alias for $5;\r
myrec RECORD;\r
okay boolean;\r
cname varchar;\r
\r
-- Find, check or fix schema_name\r
IF ( schema_name != '' ) THEN\r
- okay = 'f';\r
+ okay = false;\r
\r
FOR myrec IN SELECT nspname FROM pg_namespace WHERE text(nspname) = schema_name LOOP\r
- okay := 't';\r
+ okay := true;\r
END LOOP;\r
\r
- IF ( okay <> 't' ) THEN\r
+ IF ( okay <> true ) THEN\r
RAISE EXCEPTION 'Invalid schema name';\r
ELSE\r
real_schema = schema_name;\r
END IF;\r
\r
-- Find out if the column is in the geometry_columns table\r
- okay = 'f';\r
- FOR myrec IN SELECT * from geometry_columns where f_table_schema = text(real_schema) and f_table_name = table_name and f_geometry_column = column_name LOOP\r
- okay := 't';\r
+ okay = false;\r
+ FOR myrec IN SELECT type, coord_dimension FROM geometry_columns WHERE f_table_schema = text(real_schema) and f_table_name = table_name and f_geometry_column = column_name LOOP\r
+ okay := true;\r
END LOOP;\r
- IF (okay <> 't') THEN\r
+ IF (NOT okay) THEN\r
RAISE EXCEPTION 'column not found in geometry_columns table';\r
- RETURN 'f';\r
+ RETURN false;\r
END IF;\r
\r
- -- Update ref from geometry_columns table\r
- EXECUTE 'UPDATE geometry_columns SET SRID = ' || new_srid::text ||\r
- ' where f_table_schema = ' ||\r
- quote_literal(real_schema) || ' and f_table_name = ' ||\r
- quote_literal(table_name) || ' and f_geometry_column = ' ||\r
- quote_literal(column_name);\r
-\r
- -- Make up constraint name\r
- cname = 'enforce_srid_' || column_name;\r
-\r
- -- Drop enforce_srid constraint\r
- EXECUTE 'ALTER TABLE ' || quote_ident(real_schema) ||\r
- '.' || quote_ident(table_name) ||\r
- ' DROP constraint ' || quote_ident(cname);\r
-\r
- -- Update geometries SRID\r
- EXECUTE 'UPDATE ' || quote_ident(real_schema) ||\r
- '.' || quote_ident(table_name) ||\r
- ' SET ' || quote_ident(column_name) ||\r
- ' = ST_SetSRID(' || quote_ident(column_name) ||\r
- ', ' || new_srid::text || ')';\r
-\r
- -- Reset enforce_srid constraint\r
- EXECUTE 'ALTER TABLE ' || quote_ident(real_schema) ||\r
- '.' || quote_ident(table_name) ||\r
- ' ADD constraint ' || quote_ident(cname) ||\r
- ' CHECK (st_srid(' || quote_ident(column_name) ||\r
- ') = ' || new_srid::text || ')';\r
+ IF postgis_constaint_srid(schema_name, table_name, column_name) > 0 THEN \r
+ -- srid was enforced with constraints before, keep it that way\r
+ -- Make up constraint name\r
+ cname = 'enforce_srid_' || column_name;\r
+ \r
+ -- Drop enforce_srid constraint\r
+ EXECUTE 'ALTER TABLE ' || quote_ident(real_schema) ||\r
+ '.' || quote_ident(table_name) ||\r
+ ' DROP constraint ' || quote_ident(cname);\r
+ \r
+ -- Update geometries SRID\r
+ EXECUTE 'UPDATE ' || quote_ident(real_schema) ||\r
+ '.' || quote_ident(table_name) ||\r
+ ' SET ' || quote_ident(column_name) ||\r
+ ' = ST_SetSRID(' || quote_ident(column_name) ||\r
+ ', ' || new_srid::text || ')';\r
+ \r
+ -- Reset enforce_srid constraint\r
+ EXECUTE 'ALTER TABLE ' || quote_ident(real_schema) ||\r
+ '.' || quote_ident(table_name) ||\r
+ ' ADD constraint ' || quote_ident(cname) ||\r
+ ' CHECK (st_srid(' || quote_ident(column_name) ||\r
+ ') = ' || new_srid::text || ')';\r
+ ELSE \r
+ -- We will use typmod to enforce if no srid constraints\r
+ -- We are using postgis_type_name to lookup the new name \r
+ -- (in case Paul changes his mind and flips geometry_columns to return old upper case name) \r
+ EXECUTE 'ALTER TABLE ' || quote_ident(real_schema) || '.' || quote_ident(table_name) || \r
+ ' ALTER COLUMN ' || quote_ident(column_name) || ' TYPE geometry(' || postgis_type_name(myrec.type, myrec.coord_dimension, true) || ', ' || new_srid::text || ');' ;\r
+ END IF;\r
\r
RETURN real_schema || '.' || table_name || '.' || column_name ||' SRID changed to ' || new_srid::text;\r
\r
('COMPOUNDCURVE', 'CompoundCurveZ',3) ,\r
('COMPOUNDCURVEM', 'CompoundCurveM',3) ,\r
('COMPOUNDCURVE', 'CompoundCurveZM',4) ,\r
- ('CURVEPOLYGON', 'CompundPolygon',2) ,\r
- ('CURVEPOLYGON', 'CompundPolygonZ',3) ,\r
- ('CURVEPOLYGONM', 'CompundPolygonM',3) ,\r
- ('CURVEPOLYGON', 'CompundPolygonZM',4) ,\r
+ ('CURVEPOLYGON', 'CurvePolygon',2) ,\r
+ ('CURVEPOLYGON', 'CurvePolygonZ',3) ,\r
+ ('CURVEPOLYGONM', 'CurvePolygonM',3) ,\r
+ ('CURVEPOLYGON', 'CurvePolygonZM',4) ,\r
('MULTICURVE', 'MultiCurve',2 ) ,\r
('MULTICURVE', 'MultiCurveZ',3 ) ,\r
('MULTICURVEM', 'MultiCurveM',3 ) ,\r
$$\r
LANGUAGE 'sql' STABLE STRICT;\r
\r
-CREATE OR REPLACE VIEW geometry_columns_v AS \r
+CREATE OR REPLACE VIEW geometry_columns AS \r
SELECT current_database()::varchar(256) AS f_table_catalog, \r
n.nspname::varchar(256) AS f_table_schema, \r
c.relname::varchar(256) AS f_table_name, \r