postgis/Attic/postgis_sql_72_end.sql.in
Sandro Santilli 2da2b51bca For all versions:
Updated fix_geometry_columns to use a more readable format in queries.

For PG >= 73:
Updated fix_geometry_columns() to consider schema when fixing attrelid and
varattnum, also changed empty value to 'public' string for records with
an invalid schema specification.
Updated DropGeometryColumn to actually issue the
ALTER TABLE DROP COLUMN query.


git-svn-id: http://svn.osgeo.org/postgis/trunk@416 b70326c6-7e19-0410-871a-916f4a2858ee
2003-12-30 10:40:21 +00:00

511 lines
18 KiB
MySQL

-- - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - -
--
-- $Id$
--
-- PostGIS - Spatial Types for PostgreSQL
-- http://postgis.refractions.net
-- Copyright 2001-2003 Refractions Research Inc.
--
-- This is free software; you can redistribute and/or modify it under
-- the terms of hte GNU General Public Licence. See the COPYING file.
--
-- - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - -
-- $Log$
-- Revision 1.6 2003/12/30 10:40:21 strk
-- For all versions:
-- Updated fix_geometry_columns to use a more readable format in queries.
--
-- For PG >= 73:
-- Updated fix_geometry_columns() to consider schema when fixing attrelid and
-- varattnum, also changed empty value to 'public' string for records with
-- an invalid schema specification.
-- Updated DropGeometryColumn to actually issue the
-- ALTER TABLE DROP COLUMN query.
--
-- 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.
--
-- Revision 1.3 2003/07/01 18:30:55 pramsey
-- Added CVS revision headers.
--
--
-- - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - -
-- - - - - - - - - - - - - - - - - - - - - - - - - - - -
-- UPDATE_GEOMETRY_STATS()
CREATE FUNCTION update_geometry_stats() RETURNS text
AS
'
BEGIN
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 ''update geometry_columns set stats = (build_histogram2d( create_histogram2d(find_extent(f_table_name,f_GEOMETRY_column),40 ),f_table_name::text, f_GEOMETRY_column::text)) '';
return ''done'';
END;
'
LANGUAGE 'plpgsql' ;
-- - - - - - - - - - - - - - - - - - - - - - - - - - - -
-- UPDATE_GEOMETRY_STATS( <table>, <column> )
CREATE FUNCTION update_geometry_stats(varchar,varchar) RETURNS text
AS
'
DECLARE
tablename aliAS for $1;
columnname aliAS for $2;
BEGIN
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 ''update geometry_columns set stats = (build_histogram2d( create_histogram2d(find_extent(''|| quote_literal(tablename) || '',''||quote_literal(columnname) ||''),40 ),''|| quote_literal(tablename) || ''::text,''||quote_literal(columnname) ||''::text )) WHERE f_table_name=''|| quote_literal(tablename) || ''and f_GEOMETRY_column=''||quote_literal(columnname) ;
return ''done'';
END;
'
LANGUAGE 'plpgsql' ;
-- - - - - - - - - - - - - - - - - - - - - - - - - - - -
-- CREATE_HISTOGRAM2D( <box>, <size> )
--
-- Returns a histgram with 0s in all the boxes.
CREATE FUNCTION create_histogram2d(box3d,int)
RETURNS histogram2d
AS '@MODULE_FILENAME@','create_histogram2d'
LANGUAGE 'C' with (isstrict);
-- - - - - - - - - - - - - - - - - - - - - - - - - - - -
-- BUILD_HISTOGRAM2D( <histogram2d>, <tablename>, <columnname> )
--
CREATE FUNCTION build_histogram2d (HISTOGRAM2D,text,text)
RETURNS histogram2d
AS '@MODULE_FILENAME@','build_histogram2d'
LANGUAGE 'C' with (isstrict);
-- - - - - - - - - - - - - - - - - - - - - - - - - - - -
-- EXPLODE_HISTOGRAM2D( <histogram2d>, <tablename> )
--
CREATE FUNCTION explode_histogram2d (HISTOGRAM2D,text)
RETURNS histogram2d
AS '@MODULE_FILENAME@','explode_histogram2d'
LANGUAGE 'C' with (isstrict);
-- - - - - - - - - - - - - - - - - - - - - - - - - - - -
-- ESTIMATE_HISTOGRAM2D( <histogram2d>, <box> )
--
CREATE FUNCTION estimate_histogram2d(HISTOGRAM2D,box)
RETURNS float8
AS '@MODULE_FILENAME@','estimate_histogram2d'
LANGUAGE 'C' with (isstrict);
-- - - - - - - - - - - - - - - - - - - - - - - - - - - -
-- POSTGISCOSTESTIMATE()
--
CREATE FUNCTION postgisgistcostestimate(opaque,opaque,opaque,opaque,opaque,opaque,opaque,opaque)
RETURNS opaque
AS '@MODULE_FILENAME@','postgisgistcostestimate'
LANGUAGE 'C' with (isstrict);
--
-- 7.2 GiST support functions
--
CREATE FUNCTION ggeometry_consistent(opaque,geometry,int4)
RETURNS bool
AS '@MODULE_FILENAME@'
LANGUAGE'C';
CREATE FUNCTION ggeometry_compress(opaque)
RETURNS opaque
AS '@MODULE_FILENAME@'
LANGUAGE'C';
CREATE FUNCTION gbox_penalty(opaque,opaque,opaque)
RETURNS opaque
AS '@MODULE_FILENAME@'
LANGUAGE'C';
CREATE FUNCTION gbox_picksplit(opaque, opaque)
RETURNS opaque
AS '@MODULE_FILENAME@'
LANGUAGE'C';
CREATE FUNCTION gbox_union(bytea, opaque)
RETURNS opaque
AS '@MODULE_FILENAME@'
LANGUAGE'C';
CREATE FUNCTION gbox_same(box, box, opaque)
RETURNS opaque
AS '@MODULE_FILENAME@'
LANGUAGE'C';
CREATE FUNCTION rtree_decompress(opaque)
RETURNS opaque
AS '@MODULE_FILENAME@'
LANGUAGE'C';
--
-- 7.2 RTREE support functions
--
CREATE FUNCTION geometry_union(geometry,geometry)
RETURNS geometry
AS '@MODULE_FILENAME@'
LANGUAGE'C';
CREATE FUNCTION geometry_inter(geometry,geometry)
RETURNS geometry
AS '@MODULE_FILENAME@'
LANGUAGE'C';
CREATE FUNCTION geometry_size(geometry,opaque)
RETURNS float4
AS '@MODULE_FILENAME@'
LANGUAGE'C';
--
-- Create opclass index binding entries.
--
INSERT INTO pg_opclass (opcamid, opcname, opcintype, opcdefault, opckeytype)
VALUES (
(SELECT oid FROM pg_am WHERE amname = 'gist'),
'gist_geometry_ops',
(SELECT oid FROM pg_type WHERE typname = 'geometry'),
true,
(SELECT oid FROM pg_type WHERE typname = 'box'));
-- drop table rt_ops_tmp;
SELECT o.oid AS opoid, o.oprname
INTO TABLE rt_ops_tmp
FROM pg_operator o, pg_type t
WHERE o.oprleft = t.oid
AND t.typname = 'geometry';
-- poly_left
INSERT INTO pg_amop (amopclaid, amopstrategy, amopreqcheck, amopopr)
SELECT opcl.oid, 1, true, c.opoid
FROM pg_opclass opcl, rt_ops_tmp c
WHERE
opcamid = (SELECT oid FROM pg_am WHERE amname = 'gist')
and opcname = 'gist_geometry_ops'
and c.oprname = '<<';
-- poly_overleft
INSERT INTO pg_amop (amopclaid, amopstrategy, amopreqcheck, amopopr)
SELECT opcl.oid, 2, true, c.opoid
FROM pg_opclass opcl, rt_ops_tmp c
WHERE
opcamid = (SELECT oid FROM pg_am WHERE amname = 'gist')
and opcname = 'gist_geometry_ops'
and c.oprname = '&<';
-- poly_overlap
INSERT INTO pg_amop (amopclaid, amopstrategy, amopreqcheck, amopopr)
SELECT opcl.oid, 3, true, c.opoid
FROM pg_opclass opcl, rt_ops_tmp c
WHERE
opcamid = (SELECT oid FROM pg_am WHERE amname = 'gist')
and opcname = 'gist_geometry_ops'
and c.oprname = '&&';
-- poly_overright
INSERT INTO pg_amop (amopclaid, amopstrategy, amopreqcheck, amopopr)
SELECT opcl.oid, 4, true, c.opoid
FROM pg_opclass opcl, rt_ops_tmp c
WHERE
opcamid = (SELECT oid FROM pg_am WHERE amname = 'gist')
and opcname = 'gist_geometry_ops'
and c.oprname = '&>';
-- poly_right
INSERT INTO pg_amop (amopclaid, amopstrategy, amopreqcheck, amopopr)
SELECT opcl.oid, 5, true, c.opoid
FROM pg_opclass opcl, rt_ops_tmp c
WHERE
opcamid = (SELECT oid FROM pg_am WHERE amname = 'gist')
and opcname = 'gist_geometry_ops'
and c.oprname = '>>';
-- poly_same
INSERT INTO pg_amop (amopclaid, amopstrategy, amopreqcheck, amopopr)
SELECT opcl.oid, 6, true, c.opoid
FROM pg_opclass opcl, rt_ops_tmp c
WHERE
opcamid = (SELECT oid FROM pg_am WHERE amname = 'gist')
and opcname = 'gist_geometry_ops'
and c.oprname = '~=';
-- poly_contains
INSERT INTO pg_amop (amopclaid, amopstrategy, amopreqcheck, amopopr)
SELECT opcl.oid, 7, true, c.opoid
FROM pg_opclass opcl, rt_ops_tmp c
WHERE
opcamid = (SELECT oid FROM pg_am WHERE amname = 'gist')
and opcname = 'gist_geometry_ops'
and c.oprname = '~';
-- poly_contained
INSERT INTO pg_amop (amopclaid, amopstrategy, amopreqcheck, amopopr)
SELECT opcl.oid, 8, true, c.opoid
FROM pg_opclass opcl, rt_ops_tmp c
WHERE
opcamid = (SELECT oid FROM pg_am WHERE amname = 'gist')
and opcname = 'gist_geometry_ops'
and c.oprname = '@';
DROP TABLE rt_ops_tmp;
-- add the entries to amproc for the support methods
-- note the amprocnum numbers associated with each are specific!
INSERT INTO pg_amproc (amopclaid, amprocnum, amproc)
SELECT opcl.oid, 1, pro.oid
FROM pg_opclass opcl, pg_proc pro
WHERE
opcamid = (SELECT oid FROM pg_am WHERE amname = 'gist')
and opcname = 'gist_geometry_ops'
and proname = 'ggeometry_consistent';
INSERT INTO pg_amproc (amopclaid, amprocnum, amproc)
SELECT opcl.oid, 2, pro.oid
FROM pg_opclass opcl, pg_proc pro
WHERE
opcamid = (SELECT oid FROM pg_am WHERE amname = 'gist')
and opcname = 'gist_geometry_ops'
and proname = 'gbox_union';
INSERT INTO pg_amproc (amopclaid, amprocnum, amproc)
SELECT opcl.oid, 3, pro.oid
FROM pg_opclass opcl, pg_proc pro
WHERE
opcamid = (SELECT oid FROM pg_am WHERE amname = 'gist')
and opcname = 'gist_geometry_ops'
and proname = 'ggeometry_compress';
INSERT INTO pg_amproc (amopclaid, amprocnum, amproc)
SELECT opcl.oid, 4, pro.oid
FROM pg_opclass opcl, pg_proc pro
WHERE
opcamid = (SELECT oid FROM pg_am WHERE amname = 'gist')
and opcname = 'gist_geometry_ops'
and proname = 'rtree_decompress';
INSERT INTO pg_amproc (amopclaid, amprocnum, amproc)
SELECT opcl.oid, 5, pro.oid
FROM pg_opclass opcl, pg_proc pro
WHERE
opcamid = (SELECT oid FROM pg_am WHERE amname = 'gist')
and opcname = 'gist_geometry_ops'
and proname = 'gbox_penalty';
INSERT INTO pg_amproc (amopclaid, amprocnum, amproc)
SELECT opcl.oid, 6, pro.oid
FROM pg_opclass opcl, pg_proc pro
WHERE
opcamid = (SELECT oid FROM pg_am WHERE amname = 'gist')
and opcname = 'gist_geometry_ops'
and proname = 'gbox_picksplit';
INSERT INTO pg_amproc (amopclaid, amprocnum, amproc)
SELECT opcl.oid, 7, pro.oid
FROM pg_opclass opcl, pg_proc pro
WHERE
opcamid = (SELECT oid FROM pg_am WHERE amname = 'gist')
and opcname = 'gist_geometry_ops'
and proname = 'gbox_same';
-- - - - - - - - - - - - - - - - - - - - - - - - - - - -
-- FIX_GEOMETRY_COLUMNS()
CREATE FUNCTION fix_geometry_columns() RETURNS text
AS
'
BEGIN
UPDATE geometry_columns SET attrelid = ( SELECT c.oid AS attrelid FROM pg_class c, pg_attribute a WHERE c.relname = geometry_columns.f_table_name::name AND a.attrelid = c.oid AND a.attname = geometry_columns.f_geometry_column::name
);
UPDATE geometry_columns SET varattnum = ( SELECT a.attnum FROM pg_class c, pg_attribute a WHERE c.relname = geometry_columns.f_table_name::name AND a.attrelid = c.oid AND a.attname = geometry_columns.f_geometry_column::name
);
RETURN ''geometry_columns table is now linked to the system tables'';
END;
'
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);
END TRANSACTION;