From: Sandro Santilli Date: Tue, 23 Dec 2003 09:00:12 +0000 (+0000) Subject: AddGeometryColumn, DropGeometryColum moved to version-specific scripts. X-Git-Tag: pgis_0_8_1~7 X-Git-Url: https://granicus.if.org/sourcecode?a=commitdiff_plain;h=18de82079ef6a06fa8ba701378fe00a54efc0f32;p=postgis AddGeometryColumn, DropGeometryColum moved to version-specific scripts. Schema support enabled for version 73 and 74. git-svn-id: http://svn.osgeo.org/postgis/trunk@414 b70326c6-7e19-0410-871a-916f4a2858ee --- diff --git a/Attic/postgis_sql_71_end.sql.in b/Attic/postgis_sql_71_end.sql.in index dc001ba79..09b421649 100644 --- a/Attic/postgis_sql_71_end.sql.in +++ b/Attic/postgis_sql_71_end.sql.in @@ -12,6 +12,10 @@ -- -- - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - -- $Log$ +-- Revision 1.4 2003/12/23 09:00:12 strk +-- AddGeometryColumn, DropGeometryColum moved to version-specific scripts. +-- Schema support enabled for version 73 and 74. +-- -- Revision 1.3 2003/12/18 18:07:06 strk -- Changed fix_geometry_columns() for PG >= 73 so to set f_table_schema to -- the empty string if its value is not a valid pg namespace. @@ -209,5 +213,168 @@ END; ' LANGUAGE 'plpgsql' ; +-- - - - - - - - - - - - - - - - - - - - - - - - - - - - +-- ADDGEOMETRYCOLUMN ( +-- , , , , +-- , , ) +-- +-- Type can be one of geometry, GEOMETRYCOLLECTION, POINT, MULTIPOINT, POLYGON, +-- MULTIPOLYGON, LINESTRING, or MULTILINESTRING. +-- +-- Types (except geometry) are checked for consistency using a CHECK constraint +-- uses SQL ALTER TABLE command to add the geometry column to the table. +-- Addes a row to geometry_columns. +-- Addes a constraint on the table that all the geometries MUST have the same +-- SRID. Checks the coord_dimension to make sure its between 0 and 3. +-- Should also check the precision grid (future expansion). +-- Calls fix_geometry_columns() at the end. +-- +CREATE FUNCTION AddGeometryColumn(varchar,varchar,varchar,varchar,integer,varchar,integer) + RETURNS text + AS +' +DECLARE + catalog_name alias for $1; + schema_name alias for $2; + table_name alias for $3; + column_name alias for $4; + new_srid alias for $5; + new_type alias for $6; + new_dim alias for $7; + +BEGIN + + IF ( not ( (new_type =''GEOMETRY'') or + (new_type =''GEOMETRYCOLLECTION'') or + (new_type =''POINT'') or + (new_type =''MULTIPOINT'') or + (new_type =''POLYGON'') or + (new_type =''MULTIPOLYGON'') or + (new_type =''LINESTRING'') or + (new_type =''MULTILINESTRING'')) ) + THEN + RAISE EXCEPTION ''Invalid type name - valid ones are: + GEOMETRY, GEOMETRYCOLLECTION, POINT, + MULTIPOINT, POLYGON, MULTIPOLYGON, + LINESTRING, or MULTILINESTRING ''; + return ''fail''; + END IF; + + IF ( (new_dim >3) or (new_dim <0) ) THEN + RAISE EXCEPTION ''invalid dimension''; + return ''fail''; + END IF; + + EXECUTE ''ALTER TABLE '' || quote_ident(table_name) || + '' ADD COLUMN '' || quote_ident(column_name) || + '' geometry ''; + + EXECUTE ''INSERT INTO geometry_columns VALUES ('' || + quote_literal('''') || '','' || + quote_literal('''') || '','' || + quote_literal(table_name) || '','' || + quote_literal(column_name) || '','' || + new_dim || '','' || new_srid || '','' || + quote_literal(new_type) || '')''; + + EXECUTE ''select fix_geometry_columns()''; + + EXECUTE ''ALTER TABLE '' || quote_ident(table_name) || + '' ADD CHECK (SRID('' || quote_ident(column_name) || + '') = '' || new_srid || '')'' ; + + IF (not(new_type = ''GEOMETRY'')) THEN + EXECUTE ''ALTER TABLE '' || quote_ident(table_name) || + '' ADD CHECK (geometrytype('' || + quote_ident(column_name) || '')='' || + quote_literal(new_type) || '' OR ('' || + quote_ident(column_name) || '') is null)''; + END IF; + + return ''Geometry column '' || column_name || '' added to table '' + || table_name || '' WITH a SRID of '' || new_srid || + '' and type '' || new_type; +END; +' LANGUAGE 'plpgsql' WITH (isstrict); + +-- - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - +-- ADDGEOMETRYCOLUMN ( ,
, , , , ) +-- - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - +CREATE FUNCTION AddGeometryColumn(varchar,varchar,varchar,integer,varchar,integer) RETURNS text AS ' +DECLARE + ret text; +BEGIN + SELECT AddGeometryColumn('''',$1,$2,$3,$4,$5,$6) into ret; + RETURN ret; +END; +' LANGUAGE 'plpgsql' WITH (isstrict); + +-- - - - - - - - - - - - - - - - - - - - - - - - - - - - +-- DROPGEOMETRYCOLUMN( ,
, ) +-- +-- There is no ALTER TABLE DROP COLUMN command in postgresql +-- There is no ALTER TABLE DROP CONSTRAINT command in postgresql +-- So, we: +-- 1. remove the unwanted geom column reference from the +-- geometry_columns table +-- 2. update the table so that the geometry column is all NULLS +-- This is okay since the CHECK srid(geometry) = is not +-- checked if geometry is NULL (the isstrict attribute on srid()) +-- 3. add another constraint that the geometry column must be NULL +-- This, effectively kills the geometry column +-- (a) its not in the geometry_column table +-- (b) it only has nulls in it +-- (c) you cannot add anything to the geom column because it must be NULL +-- +-- This will screw up if you put a NOT NULL constraint on the geometry +-- column, so the first thing we must do is remove this constraint (its a +-- modification of the pg_attribute system table) +-- +-- We also check to see if the table/column exists in the geometry_columns +-- table + +CREATE FUNCTION DropGeometryColumn(varchar,varchar,varchar) + RETURNS text + AS +' +DECLARE + schema_name alias for $1; + table_name alias for $2; + column_name alias for $3; + myrec RECORD; + okay boolean; +BEGIN + -- first we find out if the column is in the geometry_columns table + okay = ''f''; + FOR myrec IN SELECT * from geometry_columns where f_table_schema = schema_name and f_table_name = table_name and f_geometry_column = column_name LOOP + okay := ''t''; + END LOOP; + IF (okay <> ''t'') THEN + RAISE EXCEPTION ''column not found in geometry_columns table''; + return ''f''; + END IF; + + -- ensure the geometry column does not have a NOT NULL attribute + EXECUTE ''update pg_attribute set attnotnull = false from pg_class where pg_attribute.attrelid = pg_class.oid and pg_class.relname = '' || quote_literal(table_name) ||'' and pg_attribute.attname = '' || quote_literal(column_name); + + -- remove ref from geometry_columns table + EXECUTE ''delete from geometry_columns where f_table_schema = '' || quote_literal(database_name) || + '' and f_table_name = '' || quote_literal(table_name) || + '' and f_geometry_column = '' || quote_literal(column_name ); + + -- update the given table/column so that it it all NULLS + + EXECUTE ''update "''||table_name||''" set "''||column_name||''"= NULL''; + + -- add = NULL constraint to given table/column + + EXECUTE ''ALTER TABLE "''||table_name||''" ADD CHECK ("''||column_name||''" IS NULL)''; + + RETURN table_name || ''.'' || column_name ||'' effectively removed.''; + +END; +' +LANGUAGE 'plpgsql' WITH (isstrict); + END TRANSACTION; diff --git a/Attic/postgis_sql_72_end.sql.in b/Attic/postgis_sql_72_end.sql.in index 60619434c..bc434abd3 100644 --- a/Attic/postgis_sql_72_end.sql.in +++ b/Attic/postgis_sql_72_end.sql.in @@ -12,6 +12,10 @@ -- -- - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - -- $Log$ +-- Revision 1.5 2003/12/23 09:00:12 strk +-- AddGeometryColumn, DropGeometryColum moved to version-specific scripts. +-- Schema support enabled for version 73 and 74. +-- -- Revision 1.4 2003/12/18 18:07:06 strk -- Changed fix_geometry_columns() for PG >= 73 so to set f_table_schema to -- the empty string if its value is not a valid pg namespace. @@ -323,5 +327,167 @@ END; ' LANGUAGE 'plpgsql' ; +-- - - - - - - - - - - - - - - - - - - - - - - - - - - - +-- ADDGEOMETRYCOLUMN ( +-- , ,
, , +-- , , ) +-- +-- Type can be one of geometry, GEOMETRYCOLLECTION, POINT, MULTIPOINT, POLYGON, +-- MULTIPOLYGON, LINESTRING, or MULTILINESTRING. +-- +-- Types (except geometry) are checked for consistency using a CHECK constraint +-- uses SQL ALTER TABLE command to add the geometry column to the table. +-- Addes a row to geometry_columns. +-- Addes a constraint on the table that all the geometries MUST have the same +-- SRID. Checks the coord_dimension to make sure its between 0 and 3. +-- Should also check the precision grid (future expansion). +-- Calls fix_geometry_columns() at the end. +-- +CREATE FUNCTION AddGeometryColumn(varchar,varchar,varchar,varchar,integer,varchar,integer) + RETURNS text + AS +' +DECLARE + catalog_name alias for $1; + schema_name alias for $2; + table_name alias for $3; + column_name alias for $4; + new_srid alias for $5; + new_type alias for $6; + new_dim alias for $7; + +BEGIN + + IF ( not ( (new_type =''GEOMETRY'') or + (new_type =''GEOMETRYCOLLECTION'') or + (new_type =''POINT'') or + (new_type =''MULTIPOINT'') or + (new_type =''POLYGON'') or + (new_type =''MULTIPOLYGON'') or + (new_type =''LINESTRING'') or + (new_type =''MULTILINESTRING'')) ) + THEN + RAISE EXCEPTION ''Invalid type name - valid ones are: + GEOMETRY, GEOMETRYCOLLECTION, POINT, + MULTIPOINT, POLYGON, MULTIPOLYGON, + LINESTRING, or MULTILINESTRING ''; + return ''fail''; + END IF; + + IF ( (new_dim >3) or (new_dim <0) ) THEN + RAISE EXCEPTION ''invalid dimension''; + return ''fail''; + END IF; + + EXECUTE ''ALTER TABLE '' || quote_ident(table_name) || + '' ADD COLUMN '' || quote_ident(column_name) || + '' geometry ''; + + EXECUTE ''INSERT INTO geometry_columns VALUES ('' || + quote_literal('''') || '','' || + quote_literal('''') || '','' || + quote_literal(table_name) || '','' || + quote_literal(column_name) || '','' || + new_dim || '','' || new_srid || '','' || + quote_literal(new_type) || '')''; + + EXECUTE ''select fix_geometry_columns()''; + + EXECUTE ''ALTER TABLE '' || quote_ident(table_name) || + '' ADD CHECK (SRID('' || quote_ident(column_name) || + '') = '' || new_srid || '')'' ; + + IF (not(new_type = ''GEOMETRY'')) THEN + EXECUTE ''ALTER TABLE '' || quote_ident(table_name) || + '' ADD CHECK (geometrytype('' || + quote_ident(column_name) || '')='' || + quote_literal(new_type) || '' OR ('' || + quote_ident(column_name) || '') is null)''; + END IF; + + return ''Geometry column '' || column_name || '' added to table '' + || table_name || '' WITH a SRID of '' || new_srid || + '' and type '' || new_type; +END; +' LANGUAGE 'plpgsql' WITH (isstrict); + +-- - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - +-- ADDGEOMETRYCOLUMN ( ,
, , , , ) +-- - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - +CREATE FUNCTION AddGeometryColumn(varchar,varchar,varchar,integer,varchar,integer) RETURNS text AS ' +DECLARE + ret text; +BEGIN + SELECT AddGeometryColumn('''',$1,$2,$3,$4,$5,$6) into ret; + RETURN ret; +END; +' LANGUAGE 'plpgsql' WITH (isstrict); + +-- - - - - - - - - - - - - - - - - - - - - - - - - - - - +-- DROPGEOMETRYCOLUMN( ,
, ) +-- +-- There is no ALTER TABLE DROP COLUMN command in postgresql +-- There is no ALTER TABLE DROP CONSTRAINT command in postgresql +-- So, we: +-- 1. remove the unwanted geom column reference from the +-- geometry_columns table +-- 2. update the table so that the geometry column is all NULLS +-- This is okay since the CHECK srid(geometry) = is not +-- checked if geometry is NULL (the isstrict attribute on srid()) +-- 3. add another constraint that the geometry column must be NULL +-- This, effectively kills the geometry column +-- (a) its not in the geometry_column table +-- (b) it only has nulls in it +-- (c) you cannot add anything to the geom column because it must be NULL +-- +-- This will screw up if you put a NOT NULL constraint on the geometry +-- column, so the first thing we must do is remove this constraint (its a +-- modification of the pg_attribute system table) +-- +-- We also check to see if the table/column exists in the geometry_columns +-- table + +CREATE FUNCTION DropGeometryColumn(varchar,varchar,varchar) + RETURNS text + AS +' +DECLARE + schema_name alias for $1; + table_name alias for $2; + column_name alias for $3; + myrec RECORD; + okay boolean; +BEGIN + -- first we find out if the column is in the geometry_columns table + okay = ''f''; + FOR myrec IN SELECT * from geometry_columns where f_table_schema = schema_name and f_table_name = table_name and f_geometry_column = column_name LOOP + okay := ''t''; + END LOOP; + IF (okay <> ''t'') THEN + RAISE EXCEPTION ''column not found in geometry_columns table''; + return ''f''; + END IF; + + -- ensure the geometry column does not have a NOT NULL attribute + EXECUTE ''update pg_attribute set attnotnull = false from pg_class where pg_attribute.attrelid = pg_class.oid and pg_class.relname = '' || quote_literal(table_name) ||'' and pg_attribute.attname = '' || quote_literal(column_name); + + -- remove ref from geometry_columns table + EXECUTE ''delete from geometry_columns where f_table_schema = '' || quote_literal(database_name) || + '' and f_table_name = '' || quote_literal(table_name) || + '' and f_geometry_column = '' || quote_literal(column_name ); + + -- update the given table/column so that it it all NULLS + + EXECUTE ''update "''||table_name||''" set "''||column_name||''"= NULL''; + + -- add = NULL constraint to given table/column + + EXECUTE ''ALTER TABLE "''||table_name||''" ADD CHECK ("''||column_name||''" IS NULL)''; + + RETURN table_name || ''.'' || column_name ||'' effectively removed.''; + +END; +' +LANGUAGE 'plpgsql' WITH (isstrict); END TRANSACTION; diff --git a/Attic/postgis_sql_73_end.sql.in b/Attic/postgis_sql_73_end.sql.in index 1785181aa..396b1931a 100644 --- a/Attic/postgis_sql_73_end.sql.in +++ b/Attic/postgis_sql_73_end.sql.in @@ -12,6 +12,10 @@ -- -- - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - -- $Log$ +-- Revision 1.7 2003/12/23 09:00:12 strk +-- AddGeometryColumn, DropGeometryColum moved to version-specific scripts. +-- Schema support enabled for version 73 and 74. +-- -- Revision 1.6 2003/12/18 18:07:06 strk -- Changed fix_geometry_columns() for PG >= 73 so to set f_table_schema to -- the empty string if its value is not a valid pg namespace. @@ -219,5 +223,222 @@ END; ' LANGUAGE 'plpgsql' ; +-- - - - - - - - - - - - - - - - - - - - - - - - - - - - +-- ADDGEOMETRYCOLUMN ( +-- , ,
, , +-- , , ) +-- +-- Type can be one of geometry, GEOMETRYCOLLECTION, POINT, MULTIPOINT, POLYGON, +-- MULTIPOLYGON, LINESTRING, or MULTILINESTRING. +-- +-- Types (except geometry) are checked for consistency using a CHECK constraint +-- uses SQL ALTER TABLE command to add the geometry column to the table. +-- Addes a row to geometry_columns. +-- Addes a constraint on the table that all the geometries MUST have the same +-- SRID. Checks the coord_dimension to make sure its between 0 and 3. +-- Should also check the precision grid (future expansion). +-- Calls fix_geometry_columns() at the end. +-- +CREATE FUNCTION AddGeometryColumn(varchar,varchar,varchar,varchar,integer,varchar,integer) + RETURNS text + AS +' +DECLARE + catalog_name alias for $1; + schema_name alias for $2; + table_name alias for $3; + column_name alias for $4; + new_srid alias for $5; + new_type alias for $6; + new_dim alias for $7; + + rec RECORD; + schema_ok bool; + real_schema name; +BEGIN + + IF ( not ( (new_type =''GEOMETRY'') or + (new_type =''GEOMETRYCOLLECTION'') or + (new_type =''POINT'') or + (new_type =''MULTIPOINT'') or + (new_type =''POLYGON'') or + (new_type =''MULTIPOLYGON'') or + (new_type =''LINESTRING'') or + (new_type =''MULTILINESTRING'')) ) + THEN + RAISE EXCEPTION ''Invalid type name - valid ones are: + GEOMETRY, GEOMETRYCOLLECTION, POINT, + MULTIPOINT, POLYGON, MULTIPOLYGON, + LINESTRING, or MULTILINESTRING ''; + RETURN ''fail''; + END IF; + + IF ( (new_dim >3) or (new_dim <0) ) THEN + RAISE EXCEPTION ''invalid dimension''; + RETURN ''fail''; + END IF; + + IF ( schema_name != '''' ) THEN + schema_ok = ''f''; + FOR rec IN SELECT nspname FROM pg_namespace WHERE text(nspname) = schema_name LOOP + schema_ok := ''t''; + END LOOP; + + if ( schema_ok <> ''t'' ) THEN + RAISE NOTICE ''Invalid schema name - using current_schema()''; + SELECT current_schema() into real_schema; + ELSE + real_schema = schema_name; + END IF; + + ELSE + SELECT current_schema() into real_schema; + END IF; + + EXECUTE ''ALTER TABLE '' || quote_ident(real_schema) || + ''.'' || quote_ident(table_name) || + '' ADD COLUMN '' || quote_ident(column_name) || + '' geometry ''; + + EXECUTE ''ALTER TABLE '' || quote_ident(real_schema) || + ''.'' || quote_ident(table_name) || + '' ADD CHECK (SRID('' || quote_ident(column_name) || + '') = '' || new_srid || '')'' ; + + IF (not(new_type = ''GEOMETRY'')) THEN + EXECUTE ''ALTER TABLE '' || quote_ident(real_schema) || + ''.'' || quote_ident(table_name) || + '' ADD CHECK (geometrytype('' || + quote_ident(column_name) || '')='' || + quote_literal(new_type) || '' OR ('' || + quote_ident(column_name) || '') is null)''; + END IF; + + EXECUTE ''INSERT INTO geometry_columns VALUES ('' || + quote_literal('''') || '','' || + quote_literal(real_schema) || '','' || + quote_literal(table_name) || '','' || + quote_literal(column_name) || '','' || + new_dim || '','' || new_srid || '','' || + quote_literal(new_type) || '')''; + + EXECUTE ''select fix_geometry_columns()''; + --SELECT fix_geometry_columns(); + + return ''Geometry column '' || column_name || '' added to table '' + || real_schema || ''.'' || table_name || '' WITH a SRID of '' || new_srid || + '' and type '' || new_type; +END; +' LANGUAGE 'plpgsql' WITH (isstrict); +-- - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - +-- ADDGEOMETRYCOLUMN ( ,
, , , , ) +-- - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - +CREATE FUNCTION AddGeometryColumn(varchar,varchar,varchar,integer,varchar,integer) RETURNS text AS ' +DECLARE + ret text; +BEGIN + SELECT AddGeometryColumn('''',$1,$2,$3,$4,$5,$6) into ret; + RETURN ret; +END; +' LANGUAGE 'plpgsql' WITH (isstrict); + +-- - - - - - - - - - - - - - - - - - - - - - - - - - - - +-- DROPGEOMETRYCOLUMN( ,
, ) +-- +-- There is no ALTER TABLE DROP COLUMN command in postgresql +-- There is no ALTER TABLE DROP CONSTRAINT command in postgresql +-- So, we: +-- 1. remove the unwanted geom column reference from the +-- geometry_columns table +-- 2. update the table so that the geometry column is all NULLS +-- This is okay since the CHECK srid(geometry) = is not +-- checked if geometry is NULL (the isstrict attribute on srid()) +-- 3. add another constraint that the geometry column must be NULL +-- This, effectively kills the geometry column +-- (a) its not in the geometry_column table +-- (b) it only has nulls in it +-- (c) you cannot add anything to the geom column because it must be NULL +-- +-- This will screw up if you put a NOT NULL constraint on the geometry +-- column, so the first thing we must do is remove this constraint (its a +-- modification of the pg_attribute system table) +-- +-- We also check to see if the table/column exists in the geometry_columns +-- table +CREATE FUNCTION DropGeometryColumn(varchar,varchar,varchar) + RETURNS text + AS +' +DECLARE + schema_name alias for $1; + table_name alias for $2; + column_name alias for $3; + + myrec RECORD; + real_schema name; + okay boolean; + query text; + +BEGIN + + + -- Find, check or fix schema_name + IF ( schema_name != '''' ) THEN + okay = ''f''; + + FOR myrec IN SELECT nspname FROM pg_namespace WHERE text(nspname) = schema_name LOOP + okay := ''t''; + END LOOP; + + IF ( okay <> ''t'' ) THEN + RAISE NOTICE ''Invalid schema name - using current_schema()''; + SELECT current_schema() into real_schema; + ELSE + real_schema = schema_name; + END IF; + ELSE + SELECT current_schema() into real_schema; + END IF; + + -- first we find out if the column is in the geometry_columns table + okay = ''f''; + 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 + okay := ''t''; + END LOOP; + IF (okay <> ''t'') THEN + RAISE EXCEPTION ''column not found in geometry_columns table''; + RETURN ''f''; + END IF; + + + -- ensure the geometry column does not have a NOT NULL attribute + query = ''update pg_attribute set attnotnull = false from pg_class, pg_namespace where pg_attribute.attrelid = pg_class.oid and pg_class.relname = '' || quote_literal(table_name) ||'' and pg_attribute.attname = '' || quote_literal(column_name) || '' and pg_class.relnamespace = pg_namespace.oid and pg_namespace.nspname = '' || quote_literal(real_schema); + EXECUTE query; + + -- remove ref from geometry_columns table + EXECUTE ''delete from geometry_columns where f_table_schema = '' || + quote_literal(real_schema) || '' and f_table_name = '' || + quote_literal(table_name) || '' and f_geometry_column = '' || + quote_literal(column_name); + + -- update the given table/column so that it it all NULLS + + EXECUTE ''UPDATE '' || quote_ident(real_schema) || ''.'' || + quote_ident(table_name) || '' set '' || quote_ident(column_name) || + '' = NULL''; + + -- add = NULL constraint to given table/column + + EXECUTE ''ALTER TABLE '' || quote_ident(real_schema) || ''.'' || + quote_ident(table_name) || '' ADD CHECK ('' || + quote_ident(column_name) || '' IS NULL)''; + + RETURN real_schema || ''.'' || table_name || ''.'' || column_name ||'' effectively removed.''; + +END; +' +LANGUAGE 'plpgsql' WITH (isstrict); + + END TRANSACTION; diff --git a/Attic/postgis_sql_74_end.sql.in b/Attic/postgis_sql_74_end.sql.in index ecd235e0f..0f167bc2f 100644 --- a/Attic/postgis_sql_74_end.sql.in +++ b/Attic/postgis_sql_74_end.sql.in @@ -12,6 +12,10 @@ -- -- - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - -- $Log$ +-- Revision 1.6 2003/12/23 09:00:12 strk +-- AddGeometryColumn, DropGeometryColum moved to version-specific scripts. +-- Schema support enabled for version 73 and 74. +-- -- Revision 1.5 2003/12/18 18:07:06 strk -- Changed fix_geometry_columns() for PG >= 73 so to set f_table_schema to -- the empty string if its value is not a valid pg namespace. @@ -252,4 +256,5 @@ END; ' LANGUAGE 'plpgsql' ; + END TRANSACTION; diff --git a/Attic/postgis_sql_common.sql.in b/Attic/postgis_sql_common.sql.in index 90319d373..96f1d50c9 100644 --- a/Attic/postgis_sql_common.sql.in +++ b/Attic/postgis_sql_common.sql.in @@ -12,6 +12,10 @@ -- -- - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - -- $Log$ +-- Revision 1.26 2003/12/23 09:00:12 strk +-- AddGeometryColumn, DropGeometryColum moved to version-specific scripts. +-- Schema support enabled for version 73 and 74. +-- -- Revision 1.25 2003/12/18 18:07:06 strk -- Changed fix_geometry_columns() for PG >= 73 so to set f_table_schema to -- the empty string if its value is not a valid pg namespace. @@ -168,161 +172,6 @@ CREATE FUNCTION get_proj4_from_srid(integer) RETURNS text AS 'SELECT proj4text::text FROM spatial_ref_sys WHERE srid= $1' LANGUAGE 'sql' WITH (iscachable,isstrict); --- - - - - - - - - - - - - - - - - - - - - - - - - - - - --- DROPGEOMETRYCOLUMN( ,
, ) --- --- There is no ALTER TABLE DROP COLUMN command in postgresql --- There is no ALTER TABLE DROP CONSTRAINT command in postgresql --- So, we: --- 1. remove the unwanted geom column reference from the --- geometry_columns table --- 2. update the table so that the geometry column is all NULLS --- This is okay since the CHECK srid(geometry) = is not --- checked if geometry is NULL (the isstrict attribute on srid()) --- 3. add another constraint that the geometry column must be NULL --- This, effectively kills the geometry column --- (a) its not in the geometry_column table --- (b) it only has nulls in it --- (c) you cannot add anything to the geom column because it must be NULL --- --- This will screw up if you put a NOT NULL constraint on the geometry --- column, so the first thing we must do is remove this constraint (its a --- modification of the pg_attribute system table) --- --- We also check to see if the table/column exists in the geometry_columns --- table - -CREATE FUNCTION DropGeometryColumn(varchar,varchar,varchar) - RETURNS text - AS -' -DECLARE - database_name alias for $1; - table_name alias for $2; - column_name alias for $3; - myrec RECORD; - okay boolean; -BEGIN - -- first we find out if the column is in the geometry_columns table - okay = ''f''; - FOR myrec IN SELECT * from geometry_columns where f_table_schema = database_name and f_table_name = table_name and f_geometry_column = column_name LOOP - okay := ''t''; - END LOOP; - IF (okay <> ''t'') THEN - RAISE EXCEPTION ''column not found in geometry_columns table''; - return ''f''; - END IF; - - -- ensure the geometry column does not have a NOT NULL attribute - EXECUTE ''update pg_attribute set attnotnull = false from pg_class where pg_attribute.attrelid = pg_class.oid and pg_class.relname = '' || quote_literal(table_name) ||'' and pg_attribute.attname = '' || quote_literal(column_name); - - -- remove ref from geometry_columns table - EXECUTE ''delete from geometry_columns where f_table_schema = '' || quote_literal(database_name) || - '' and f_table_name = '' || quote_literal(table_name) || - '' and f_geometry_column = '' || quote_literal(column_name ); - - -- update the given table/column so that it it all NULLS - - EXECUTE ''update "''||table_name||''" set "''||column_name||''"= NULL''; - - -- add = NULL constraint to given table/column - - EXECUTE ''ALTER TABLE "''||table_name||''" ADD CHECK ("''||column_name||''" IS NULL)''; - - RETURN table_name || ''.'' || column_name ||'' effectively removed.''; - -END; -' - LANGUAGE 'plpgsql' WITH (isstrict); - --- - - - - - - - - - - - - - - - - - - - - - - - - - - - --- ADDGEOMETRYCOLUMN( --- , ---
, --- , --- , --- , --- ) --- --- Type can be one of geometry, GEOMETRYCOLLECTION, POINT, MULTIPOINT, POLYGON, --- MULTIPOLYGON, LINESTRING, or MULTILINESTRING. --- --- Types (except geometry) are checked for consistency using a CHECK constraint --- uses SQL ALTER TABLE command to add the geometry column to the table --- added a row to geometry_columns WITH info (catalog = '', schema = ) --- addes a constraint on the table that all the geometries MUST have the same --- SRID checks the coord_dimension to make sure its between 0 and 3 --- should also check the precision grid (future expansion) --- also checks to see if the database_name is in the pg_database table. --- -CREATE FUNCTION AddGeometryColumn(varchar,varchar,varchar,integer,varchar,integer) - RETURNS text - AS -' -DECLARE - database_name alias for $1; - table_name alias for $2; - column_name alias for $3; - new_srid alias for $4; - new_type alias for $5; - new_dim alias for $6; - - real_db_name varchar; - db_query record; - db_name_ok boolean; - -BEGIN - - IF (not( (new_type =''GEOMETRY'') or (new_type =''GEOMETRYCOLLECTION'') or (new_type =''POINT'') - or (new_type =''MULTIPOINT'') or (new_type =''POLYGON'') or (new_type =''MULTIPOLYGON'') - or (new_type =''LINESTRING'') or (new_type =''MULTILINESTRING'')) ) THEN - RAISE EXCEPTION ''Invalid type name - valid ones are: GEOMETRY, GEOMETRYCOLLECTION,POINT,MULTIPOINT,POLYGON,MULTIPOLYGON,LINESTRING, or MULTILINESTRING ''; - return ''fail''; - END IF; - - IF ( (new_dim >3) or (new_dim <0) ) THEN - RAISE EXCEPTION ''invalid dimension''; - return ''fail''; - END IF; - - db_name_ok := ''f''; - - FOR db_query IN SELECT datname from pg_database where text(datname) = database_name LOOP - db_name_ok := ''t''; - END LOOP; - - IF (db_name_ok <> ''t'') THEN - RAISE EXCEPTION ''Invalid database name.''; - return ''fail''; - END IF; - - EXECUTE ''ALTER TABLE '' || quote_ident(table_name) || '' ADD COLUMN '' || quote_ident(column_name) || '' geometry ''; - EXECUTE ''INSERT INTO geometry_columns VALUES ('' || quote_literal('''') || '','' || - quote_literal(database_name) || '','' || quote_literal(table_name) || '','' || - quote_literal(column_name) || '','' || - new_dim ||'',''||new_srid||'',''||quote_literal(new_type)||'')''; - - EXECUTE ''update geometry_columns set attrelid = (select pg_class.oid AS attrelid from pg_class,pg_attribute where relname =geometry_columns.f_table_name::name and pg_attribute.attrelid = pg_class.oid and pg_attribute.attname = geometry_columns.f_geometry_column::name), varattnum = (select pg_attribute.attnum from pg_class,pg_attribute where relname =geometry_columns.f_table_name::name and pg_attribute.attrelid = pg_class.oid and pg_attribute.attname = geometry_columns.f_geometry_column::name)''; - - - EXECUTE ''ALTER TABLE '' || quote_ident(table_name) || - '' ADD CHECK (SRID('' || quote_ident(column_name) || - '') = '' || new_srid || '')'' ; - - IF (not(new_type = ''GEOMETRY'')) THEN - EXECUTE ''ALTER TABLE '' || quote_ident(table_name) || - '' ADD CHECK (geometrytype('' || - quote_ident(column_name) || '')='' || - quote_literal(new_type) || '' OR ('' || - quote_ident(column_name) || '') is null)''; - END IF; - - return ''Geometry column '' || column_name || '' added to table '' - || table_name || '' WITH a SRID of '' || new_srid || - '' and type '' || new_type; -END; -' - LANGUAGE 'plpgsql' WITH (isstrict); -- - - - - - - - - - - - - - - - - - - - - - - - - - - - -- FIND_EXTENT(
, )