AS 'SELECT 'POSTGIS_VERSION'::text AS version'
LANGUAGE 'sql';
--- - - - - - - - - - - - - - - - - - - - - - - - - - - -
+-----------------------------------------------------------------------
-- FIND_SRID( <schema>, <table>, <geom col> )
+-----------------------------------------------------------------------
CREATE FUNCTION find_srid(varchar,varchar,varchar) RETURNS int4 AS
'DECLARE
'
LANGUAGE 'plpgsql' ;
--- - - - - - - - - - - - - - - - - - - - - - - - - - - -
--- ADDGEOMETRYCOLUMN (
--- <catalog>, <schema>, <table name>, <column name>,
--- <srid>, <type>, <dim> )
---
--- 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 ( <schema>, <table>, <column>, <srid>, <type>, <dim> )
--- - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - -
-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( <schema name>, <table name>, <column name> )
---
--- 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) = <srid> 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);
-
#elif USE_VERSION == 72
-- - - - - - - - - - - - - - - - - - - - - - - - - - - -
'
LANGUAGE 'plpgsql' ;
--- - - - - - - - - - - - - - - - - - - - - - - - - - - -
--- ADDGEOMETRYCOLUMN (
--- <catalog>, <schema>, <table name>, <column name>,
--- <srid>, <type>, <dim> )
---
--- 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 ( <schema>, <table>, <column>, <srid>, <type>, <dim> )
--- - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - -
-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( <schema name>, <table name>, <column name> )
---
--- 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) = <srid> 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);
-
#elif USE_VERSION == 73
--
'
LANGUAGE 'plpgsql' ;
+
+#elif USE_VERSION == 74
+
-- - - - - - - - - - - - - - - - - - - - - - - - - - - -
--- ADDGEOMETRYCOLUMN (
--- <catalog>, <schema>, <table name>, <column name>,
--- <srid>, <type>, <dim> )
---
--- 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 ( <schema>, <table>, <column>, <srid>, <type>, <dim> )
--- - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - -
-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( <schema name>, <table name>, <column name> )
---
--- Removes geometry column reference from geometry_columns table,
--- and actually drops the column.
---
-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;
-
-
- -- 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);
-
- -- Remove table column
- EXECUTE ''ALTER TABLE '' || quote_ident(real_schema) || ''.'' ||
- quote_ident(table_name) || '' DROP COLUMN '' ||
- quote_ident(column_name);
-
-
- RETURN real_schema || ''.'' || table_name || ''.'' || column_name ||'' effectively removed.'';
-
-END;
-'
-LANGUAGE 'plpgsql' WITH (isstrict);
-
-#elif USE_VERSION == 74
-
--- - - - - - - - - - - - - - - - - - - - - - - - - - - -
--- WKB
-
--- this has been moved here at _end from _start
--- because we need the definition of function bytea
--- found in _common
-CREATE TYPE wkb (
- internallength = variable,
- input = wkb_in,
- output = wkb_out,
- storage = extended,
- send = bytea,
- receive = wkb_recv
-);
-
+-- WKB
+
+-- this has been moved here at _end from _start
+-- because we need the definition of function bytea
+-- found in _common
+CREATE TYPE wkb (
+ internallength = variable,
+ input = wkb_in,
+ output = wkb_out,
+ storage = extended,
+ send = bytea,
+ receive = wkb_recv
+);
+
--
-- 7.3 explicit casting definitions
--
'
LANGUAGE 'plpgsql' ;
--- - - - - - - - - - - - - - - - - - - - - - - - - - - -
--- ADDGEOMETRYCOLUMN (
--- <catalog>, <schema>, <table name>, <column name>,
--- <srid>, <type>, <dim> )
---
--- 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 ( <schema>, <table>, <column>, <srid>, <type>, <dim> )
--- - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - -
-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( <schema name>, <table name>, <column name> )
---
--- Removes geometry column reference from geometry_columns table,
--- and actually drops the column.
---
-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;
-
-
- -- 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);
-
- -- Remove table column
- EXECUTE ''ALTER TABLE '' || quote_ident(real_schema) || ''.'' ||
- quote_ident(table_name) || '' DROP COLUMN '' ||
- quote_ident(column_name);
-
-
- RETURN real_schema || ''.'' || table_name || ''.'' || column_name ||'' effectively removed.'';
-
-END;
-'
-LANGUAGE 'plpgsql' WITH (isstrict);
-
#elif USE_VERSION == 75
-- - - - - - - - - - - - - - - - - - - - - - - - - - - -
'
LANGUAGE 'plpgsql' ;
--- - - - - - - - - - - - - - - - - - - - - - - - - - - -
--- ADDGEOMETRYCOLUMN (
--- <catalog>, <schema>, <table name>, <column name>,
--- <srid>, <type>, <dim> )
+
+#endif // USE_VERSION == ...
+
+
+---------------------------------------------
+--
+-- THIS part has been compressed to easly
+-- see the differences between pgsql versions
+--
+---------------------------------------------
+
+-----------------------------------------------------------------------
+-- ADDGEOMETRYCOLUMN
+-- <catalogue>, <schema>, <table>, <column>, <srid>, <type>, <dim>
+-----------------------------------------------------------------------
--
-- Type can be one of geometry, GEOMETRYCOLLECTION, POINT, MULTIPOINT, POLYGON,
-- MULTIPOLYGON, LINESTRING, or MULTILINESTRING.
-- 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
new_srid alias for $5;
new_type alias for $6;
new_dim alias for $7;
-
+#if USE_VERSION >= 73
rec RECORD;
schema_ok bool;
real_schema name;
+#endif
+
BEGIN
IF ( not ( (new_type =''GEOMETRY'') or
GEOMETRY, GEOMETRYCOLLECTION, POINT,
MULTIPOINT, POLYGON, MULTIPOLYGON,
LINESTRING, or MULTILINESTRING '';
- RETURN ''fail'';
+ return ''fail'';
END IF;
IF ( (new_dim >3) or (new_dim <0) ) THEN
RAISE EXCEPTION ''invalid dimension'';
- RETURN ''fail'';
+ return ''fail'';
END IF;
+#if USE_VERSION >= 73
IF ( schema_name != '''' ) THEN
schema_ok = ''f'';
FOR rec IN SELECT nspname FROM pg_namespace WHERE text(nspname) = schema_name LOOP
ELSE
SELECT current_schema() into real_schema;
END IF;
+#endif
- 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 ''ALTER TABLE '' ||
+#if USE_VERSION >= 73
+ quote_ident(real_schema) || ''.'' || quote_ident(table_name)
+#else
+ quote_ident(table_name)
+#endif
+ || '' ADD COLUMN '' || quote_ident(column_name) ||
+ '' geometry '';
EXECUTE ''INSERT INTO geometry_columns VALUES ('' ||
quote_literal('''') || '','' ||
+#if USE_VERSION >= 73
quote_literal(real_schema) || '','' ||
+#else
+ quote_literal('''') || '','' ||
+#endif
quote_literal(table_name) || '','' ||
quote_literal(column_name) || '','' ||
new_dim || '','' || new_srid || '','' ||
quote_literal(new_type) || '')'';
+ EXECUTE ''ALTER TABLE '' ||
+#if USE_VERSION >= 73
+ quote_ident(real_schema) || ''.'' || quote_ident(table_name)
+#else
+ quote_ident(table_name)
+#endif
+ || '' ADD CHECK (SRID('' || quote_ident(column_name) ||
+ '') = '' || new_srid || '')'' ;
+
+ IF (not(new_type = ''GEOMETRY'')) THEN
+ EXECUTE ''ALTER TABLE '' ||
+#if USE_VERSION >= 73
+ quote_ident(real_schema) || ''.'' || quote_ident(table_name)
+#else
+ quote_ident(table_name)
+#endif
+ || '' ADD CHECK (geometrytype('' ||
+ quote_ident(column_name) || '')='' ||
+ quote_literal(new_type) || '' OR ('' ||
+ quote_ident(column_name) || '') is null)'';
+ END IF;
+
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 ||
+#if USE_VERSION >= 73
+ || real_schema || ''.'' || table_name
+#else
+ || table_name
+#endif
+ || '' WITH a SRID of '' || new_srid ||
'' and type '' || new_type;
END;
' LANGUAGE 'plpgsql' WITH (isstrict);
--- - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - -
+
+----------------------------------------------------------------------------
-- ADDGEOMETRYCOLUMN ( <schema>, <table>, <column>, <srid>, <type>, <dim> )
--- - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - -
+----------------------------------------------------------------------------
+--
+-- This is a wrapper to the real AddGeometryColumn, for use
+-- when catalogue is undefined
+--
+----------------------------------------------------------------------------
CREATE FUNCTION AddGeometryColumn(varchar,varchar,varchar,integer,varchar,integer) RETURNS text AS '
DECLARE
ret text;
END;
' LANGUAGE 'plpgsql' WITH (isstrict);
--- - - - - - - - - - - - - - - - - - - - - - - - - - - -
--- DROPGEOMETRYCOLUMN( <schema name>, <table name>, <column name> )
+----------------------------------------------------------------------------
+-- ADDGEOMETRYCOLUMN ( <table>, <column>, <srid>, <type>, <dim> )
+----------------------------------------------------------------------------
--
--- Removes geometry column reference from geometry_columns table,
--- and actually drops the column.
+-- This is a wrapper to the real AddGeometryColumn, for use
+-- when catalogue and schema are undefined
--
-CREATE FUNCTION DropGeometryColumn(varchar,varchar,varchar)
+----------------------------------------------------------------------------
+CREATE FUNCTION AddGeometryColumn(varchar,varchar,integer,varchar,integer) RETURNS text AS '
+DECLARE
+ ret text;
+BEGIN
+ SELECT AddGeometryColumn('''','''',$1,$2,$3,$4,$5) into ret;
+ RETURN ret;
+END;
+' LANGUAGE 'plpgsql' WITH (isstrict);
+
+-----------------------------------------------------------------------
+-- DROPGEOMETRYCOLUMN
+-- <catalogue>, <schema>, <table>, <column>
+-----------------------------------------------------------------------
+--
+-- Removes geometry column reference from geometry_columns table.
+-- Drops the column with pgsql >= 73.
+-- Make some silly enforcements on it for pgsql < 73
+--
+-----------------------------------------------------------------------
+CREATE FUNCTION DropGeometryColumn(varchar, varchar,varchar,varchar)
RETURNS text
AS
'
DECLARE
- schema_name alias for $1;
- table_name alias for $2;
- column_name alias for $3;
-
+ catalog_name alias for $1;
+ schema_name alias for $2;
+ table_name alias for $3;
+ column_name alias for $4;
myrec RECORD;
- real_schema name;
okay boolean;
- query text;
+ real_schema name;
BEGIN
+#if USE_VERSION >= 73
-- Find, check or fix schema_name
IF ( schema_name != '''' ) THEN
okay = ''f'';
ELSE
SELECT current_schema() into real_schema;
END IF;
+#else
+ real_schema = schema_name;
+#endif // USE_VERSION >= 73
- -- first we find out if the column is in the geometry_columns table
+ -- 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'';
RETURN ''f'';
END IF;
-
-- 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);
-
+
+#if USE_VERSION < 73
+ -- Remove not-null constraint to table column
+ 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);
+ -- 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)'';
+#else
-- Remove table column
EXECUTE ''ALTER TABLE '' || quote_ident(real_schema) || ''.'' ||
quote_ident(table_name) || '' DROP COLUMN '' ||
quote_ident(column_name);
+#endif
RETURN real_schema || ''.'' || table_name || ''.'' || column_name ||'' effectively removed.'';
'
LANGUAGE 'plpgsql' WITH (isstrict);
+-----------------------------------------------------------------------
+-- DROPGEOMETRYCOLUMN
+-- <schema>, <table>, <column>
+-----------------------------------------------------------------------
+--
+-- This is a wrapper to the real DropGeometryColumn, for use
+-- when catalogue is undefined
+--
+-----------------------------------------------------------------------
+CREATE FUNCTION DropGeometryColumn(varchar,varchar,varchar)
+ RETURNS text
+ AS
+'
+DECLARE
+ ret text;
+BEGIN
+ SELECT DropGeometryColumn('''',$1,$2,$3) into ret;
+ RETURN ret;
+END;
+' LANGUAGE 'plpgsql' WITH (isstrict);
+
+-----------------------------------------------------------------------
+-- DROPGEOMETRYCOLUMN
+-- <table>, <column>
+-----------------------------------------------------------------------
+--
+-- This is a wrapper to the real DropGeometryColumn, for use
+-- when catalogue and schema is undefined.
+--
+-----------------------------------------------------------------------
+CREATE FUNCTION DropGeometryColumn(varchar,varchar)
+ RETURNS text
+ AS
+'
+DECLARE
+ ret text;
+BEGIN
+ SELECT DropGeometryColumn('''','''',$1,$2) into ret;
+ RETURN ret;
+END;
+' LANGUAGE 'plpgsql' WITH (isstrict);
-#endif // USE_VERSION == ...
+-----------------------------------------------------------------------
END TRANSACTION;