-- - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - -- -- $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 the GNU General Public Licence. See the COPYING file. -- -- - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - -- $Log$ -- Revision 1.3 2004/08/20 14:08:41 strk -- Added Geom{etry,}FromWkb(,[]) funx. -- Added LWGEOM typedef and SERIALIZED_FORM(LWGEOM) macro. -- Made lwgeom_setSRID an API function. -- Added LWGEOM_setAllocator(). -- -- Revision 1.2 2004/08/19 13:54:15 strk -- cpp checks updated to use 80 instead of 75 for USE_VERSION -- -- - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - #if USE_VERSION > 71 #define CREATEFUNCTION CREATE OR REPLACE FUNCTION #else #define CREATEFUNCTION CREATE FUNCTION #endif BEGIN; ------------------------------------------------------------------- -- HISTOGRAM2D TYPE (lwhistogram2d) ------------------------------------------------------------------- #if USE_VERSION < 73 # define HISTOGRAM_IN_REP opaque # define HISTOGRAM_OUT_REP opaque #else # define HISTOGRAM_IN_REP histogram2d # define HISTOGRAM_OUT_REP cstring #endif CREATEFUNCTION histogram2d_in(HISTOGRAM_OUT_REP) RETURNS HISTOGRAM_IN_REP AS '@MODULE_FILENAME@', 'lwhistogram2d_in' LANGUAGE 'C' WITH (isstrict); CREATEFUNCTION histogram2d_out(HISTOGRAM_IN_REP) RETURNS HISTOGRAM_OUT_REP AS '@MODULE_FILENAME@', 'lwhistogram2d_out' LANGUAGE 'C' WITH (isstrict); CREATE TYPE histogram2d ( alignment = double, internallength = variable, input = histogram2d_in, output = histogram2d_out, storage = main ); ------------------------------------------------------------------- -- GEOMETRY TYPE (lwgeom) ------------------------------------------------------------------- CREATEFUNCTION geometry_in(cstring) RETURNS geometry AS '@MODULE_FILENAME@','LWGEOM_in' LANGUAGE 'C' WITH (isstrict,iscachable); CREATEFUNCTION geometry_out(geometry) RETURNS cstring AS '@MODULE_FILENAME@','LWGEOM_out' LANGUAGE 'C' WITH (isstrict,iscachable); #if USE_VERSION >= 80 CREATEFUNCTION geometry_analyze(internal) RETURNS bool AS '@MODULE_FILENAME@', 'lwgeom_analyze' LANGUAGE 'C' WITH (isstrict); #endif CREATE TYPE geometry ( internallength = variable, input = geometry_in, output = geometry_out, storage = main ); CREATEFUNCTION geometryfromtext(geometry) RETURNS geometry AS '@MODULE_FILENAME@','LWGEOM_from_text' LANGUAGE 'C' WITH (isstrict,iscachable); CREATEFUNCTION geometryfromtext(geometry, int4) RETURNS geometry AS '@MODULE_FILENAME@','LWGEOM_from_text' LANGUAGE 'C' WITH (isstrict,iscachable); CREATEFUNCTION geomfromtext(geometry) RETURNS geometry AS ' SELECT geometryfromtext($1) ' LANGUAGE 'SQL' WITH (isstrict,iscachable); CREATEFUNCTION geomfromtext(geometry, int4) RETURNS geometry AS ' SELECT geometryfromtext($1, $2) ' LANGUAGE 'SQL' WITH (isstrict,iscachable); ----------------------------------------------------------------------- -- -- BOX2D -- ----------------------------------------------------------------------- CREATEFUNCTION box2d_in(cstring) RETURNS box2d AS '@MODULE_FILENAME@','BOX2DFLOAT4_in' LANGUAGE 'C' WITH (isstrict,iscachable); CREATEFUNCTION box2d_out(box2d) RETURNS cstring AS '@MODULE_FILENAME@','BOX2DFLOAT4_out' LANGUAGE 'C' WITH (isstrict,iscachable); CREATE TYPE box2d ( internallength = 16, input = box2d_in, output = box2d_out, storage = plain ); CREATEFUNCTION box2d(geometry) RETURNS box2d AS '@MODULE_FILENAME@','LWGEOM_to_BOX2DFLOAT4' LANGUAGE 'C' WITH (isstrict,iscachable); CREATEFUNCTION geometry(text) RETURNS geometry AS '@MODULE_FILENAME@','parse_WKT_lwgeom' LANGUAGE 'C' WITH (isstrict,iscachable); ---- BOX2D support functions CREATEFUNCTION box2d_overleft(box2d, box2d) RETURNS bool AS '@MODULE_FILENAME@' LANGUAGE 'C' WITH (isstrict,iscachable); CREATEFUNCTION box2d_overright(box2d, box2d) RETURNS bool AS '@MODULE_FILENAME@' LANGUAGE 'C' WITH (isstrict,iscachable); CREATEFUNCTION box2d_left(box2d, box2d) RETURNS bool AS '@MODULE_FILENAME@' LANGUAGE 'C' WITH (isstrict,iscachable); CREATEFUNCTION box2d_right(box2d, box2d) RETURNS bool AS '@MODULE_FILENAME@' LANGUAGE 'C' WITH (isstrict,iscachable); CREATEFUNCTION box2d_contain(box2d, box2d) RETURNS bool AS '@MODULE_FILENAME@' LANGUAGE 'C' WITH (isstrict,iscachable); CREATEFUNCTION box2d_contained(box2d, box2d) RETURNS bool AS '@MODULE_FILENAME@' LANGUAGE 'C' WITH (isstrict,iscachable); CREATEFUNCTION box2d_overlap(box2d, box2d) RETURNS bool AS '@MODULE_FILENAME@' LANGUAGE 'C' WITH (isstrict,iscachable); CREATEFUNCTION box2d_same(box2d, box2d) RETURNS bool AS '@MODULE_FILENAME@' LANGUAGE 'C' WITH (isstrict,iscachable); CREATE OPERATOR << ( LEFTARG = box2d, RIGHTARG = box2d, PROCEDURE = box2d_left, COMMUTATOR = '>>', RESTRICT = positionsel, JOIN = positionjoinsel ); CREATE OPERATOR &< ( LEFTARG = box2d, RIGHTARG = box2d, PROCEDURE = box2d_overleft, COMMUTATOR = '&>', RESTRICT = positionsel, JOIN = positionjoinsel ); CREATE OPERATOR && ( LEFTARG = box2d, RIGHTARG = box2d, PROCEDURE = box2d_overlap, COMMUTATOR = '&&', RESTRICT = areasel, JOIN = positionjoinsel ); CREATE OPERATOR &> ( LEFTARG = box2d, RIGHTARG = box2d, PROCEDURE = box2d_overright, COMMUTATOR = '&<', RESTRICT = positionsel, JOIN = positionjoinsel ); CREATE OPERATOR >> ( LEFTARG = box2d, RIGHTARG = box2d, PROCEDURE = box2d_right, COMMUTATOR = '<<', RESTRICT = positionsel, JOIN = positionjoinsel ); CREATE OPERATOR ~= ( LEFTARG = box2d, RIGHTARG = box2d, PROCEDURE = box2d_same, COMMUTATOR = '~=', RESTRICT = eqsel, JOIN = eqjoinsel ); CREATE OPERATOR @ ( LEFTARG = box2d, RIGHTARG = box2d, PROCEDURE = box2d_contained, COMMUTATOR = '~', RESTRICT = contsel, JOIN = contjoinsel ); CREATE OPERATOR ~ ( LEFTARG = box2d, RIGHTARG = box2d, PROCEDURE = box2d_contain, COMMUTATOR = '@', RESTRICT = contsel, JOIN = contjoinsel ); -- lwgeom operator support functions ------------------------------------------------------------------- -- BTREE indexes ------------------------------------------------------------------- CREATEFUNCTION geometry_lt(geometry, geometry) RETURNS bool AS '@MODULE_FILENAME@', 'lwgeom_lt' LANGUAGE 'C' WITH (isstrict); CREATEFUNCTION geometry_le(geometry, geometry) RETURNS bool AS '@MODULE_FILENAME@', 'lwgeom_le' LANGUAGE 'C' WITH (isstrict); CREATEFUNCTION geometry_gt(geometry, geometry) RETURNS bool AS '@MODULE_FILENAME@', 'lwgeom_gt' LANGUAGE 'C' WITH (isstrict); CREATEFUNCTION geometry_ge(geometry, geometry) RETURNS bool AS '@MODULE_FILENAME@', 'lwgeom_ge' LANGUAGE 'C' WITH (isstrict); CREATEFUNCTION geometry_eq(geometry, geometry) RETURNS bool AS '@MODULE_FILENAME@', 'lwgeom_eq' LANGUAGE 'C' WITH (isstrict); CREATEFUNCTION geometry_cmp(geometry, geometry) RETURNS integer AS '@MODULE_FILENAME@', 'lwgeom_cmp' LANGUAGE 'C' WITH (isstrict); -- -- Sorting operators for Btree -- CREATE OPERATOR < ( LEFTARG = geometry, RIGHTARG = geometry, PROCEDURE = geometry_lt, COMMUTATOR = '>', NEGATOR = '>=', RESTRICT = contsel, JOIN = contjoinsel ); CREATE OPERATOR <= ( LEFTARG = geometry, RIGHTARG = geometry, PROCEDURE = geometry_le, COMMUTATOR = '>=', NEGATOR = '>', RESTRICT = contsel, JOIN = contjoinsel ); CREATE OPERATOR = ( LEFTARG = geometry, RIGHTARG = geometry, PROCEDURE = geometry_eq, COMMUTATOR = '=', -- we might implement a faster negator here RESTRICT = contsel, JOIN = contjoinsel ); CREATE OPERATOR >= ( LEFTARG = geometry, RIGHTARG = geometry, PROCEDURE = geometry_ge, COMMUTATOR = '<=', NEGATOR = '<', RESTRICT = contsel, JOIN = contjoinsel ); CREATE OPERATOR > ( LEFTARG = geometry, RIGHTARG = geometry, PROCEDURE = geometry_gt, COMMUTATOR = '<', NEGATOR = '<=', RESTRICT = contsel, JOIN = contjoinsel ); #if USE_VERSION >= 74 CREATE OPERATOR CLASS btree_geometry_ops DEFAULT FOR TYPE geometry USING btree AS OPERATOR 1 < , OPERATOR 2 <= , OPERATOR 3 = , OPERATOR 4 >= , OPERATOR 5 > , FUNCTION 1 geometry_cmp (geometry, geometry); #endif // USE_VERSION >= 74 ------------------------------------------------------------------- -- GiST indexes ------------------------------------------------------------------- #if USE_VERSION == 71 CREATEFUNCTION postgis_gist_sel(oid, oid, int2, opaque, int4) #elif USE_VERSION == 72 CREATEFUNCTION postgis_gist_sel(opaque, oid, opaque, int4) #else CREATEFUNCTION postgis_gist_sel (internal, oid, internal, int4) #endif RETURNS float8 AS '@MODULE_FILENAME@', 'lwgeom_gist_sel' LANGUAGE 'C'; CREATEFUNCTION lwgeom_overleft(geometry, geometry) RETURNS bool AS '@MODULE_FILENAME@' LANGUAGE 'C' WITH (isstrict,iscachable); CREATEFUNCTION lwgeom_overright(geometry, geometry) RETURNS bool AS '@MODULE_FILENAME@' LANGUAGE 'C' WITH (isstrict,iscachable); CREATEFUNCTION lwgeom_left(geometry, geometry) RETURNS bool AS '@MODULE_FILENAME@' LANGUAGE 'C' WITH (isstrict,iscachable); CREATEFUNCTION lwgeom_right(geometry, geometry) RETURNS bool AS '@MODULE_FILENAME@' LANGUAGE 'C' WITH (isstrict,iscachable); CREATEFUNCTION lwgeom_contain(geometry, geometry) RETURNS bool AS '@MODULE_FILENAME@' LANGUAGE 'C' WITH (isstrict,iscachable); CREATEFUNCTION lwgeom_contained(geometry, geometry) RETURNS bool AS '@MODULE_FILENAME@' LANGUAGE 'C' WITH (isstrict,iscachable); CREATEFUNCTION lwgeom_overlap(geometry, geometry) RETURNS bool AS '@MODULE_FILENAME@' LANGUAGE 'C' WITH (isstrict,iscachable); CREATEFUNCTION lwgeom_same(geometry, geometry) RETURNS bool AS '@MODULE_FILENAME@' LANGUAGE 'C' WITH (isstrict,iscachable); CREATE OPERATOR << ( LEFTARG = geometry, RIGHTARG = geometry, PROCEDURE = lwgeom_left, COMMUTATOR = '>>', RESTRICT = positionsel, JOIN = positionjoinsel ); CREATE OPERATOR &< ( LEFTARG = geometry, RIGHTARG = geometry, PROCEDURE = lwgeom_overleft, COMMUTATOR = '&>', RESTRICT = positionsel, JOIN = positionjoinsel ); CREATE OPERATOR && ( LEFTARG = geometry, RIGHTARG = geometry, PROCEDURE = lwgeom_overlap, COMMUTATOR = '&&', RESTRICT = postgis_gist_sel, JOIN = positionjoinsel ); CREATE OPERATOR &> ( LEFTARG = geometry, RIGHTARG = geometry, PROCEDURE = lwgeom_overright, COMMUTATOR = '&<', RESTRICT = positionsel, JOIN = positionjoinsel ); CREATE OPERATOR >> ( LEFTARG = geometry, RIGHTARG = geometry, PROCEDURE = lwgeom_right, COMMUTATOR = '<<', RESTRICT = positionsel, JOIN = positionjoinsel ); CREATE OPERATOR ~= ( LEFTARG = geometry, RIGHTARG = geometry, PROCEDURE = lwgeom_same, COMMUTATOR = '~=', RESTRICT = eqsel, JOIN = eqjoinsel ); CREATE OPERATOR @ ( LEFTARG = geometry, RIGHTARG = geometry, PROCEDURE = lwgeom_contained, COMMUTATOR = '~', RESTRICT = contsel, JOIN = contjoinsel ); CREATE OPERATOR ~ ( LEFTARG = geometry, RIGHTARG = geometry, PROCEDURE = lwgeom_contain, COMMUTATOR = '@', RESTRICT = contsel, JOIN = contjoinsel ); -- gist support functions CREATEFUNCTION gist_lwgeom_consistent(internal,geometry,int4) RETURNS bool AS '@MODULE_FILENAME@' ,'gist_lwgeom_consistent' LANGUAGE 'C'; CREATEFUNCTION gist_lwgeom_compress(internal) RETURNS internal AS '@MODULE_FILENAME@','gist_lwgeom_compress' LANGUAGE 'C'; CREATEFUNCTION gist_lwgeom_penalty(internal,internal,internal) RETURNS internal AS '@MODULE_FILENAME@' ,'lwgeom_box_penalty' LANGUAGE 'C'; CREATEFUNCTION gist_lwgeom_picksplit(internal, internal) RETURNS internal AS '@MODULE_FILENAME@' ,'lwgeom_gbox_picksplit' LANGUAGE 'C'; CREATEFUNCTION gist_lwgeom_union(bytea, internal) RETURNS internal AS '@MODULE_FILENAME@' ,'lwgeom_box_union' LANGUAGE 'C'; CREATEFUNCTION gist_lwgeom_same(box2d, box2d, internal) RETURNS internal AS '@MODULE_FILENAME@' ,'lwgeom_gbox_same' LANGUAGE 'C'; CREATEFUNCTION gist_lwgeom_decompress(internal) RETURNS internal AS '@MODULE_FILENAME@' ,'gist_rtree_decompress' LANGUAGE 'C'; ------------------------------------------- -- GIST opclass index binding entries. ------------------------------------------- #if USE_VERSION == 71 INSERT INTO pg_opclass (opcname, opcdeftype) SELECT 'gist_geometry_ops', oid FROM pg_type WHERE typname = 'geometry'; 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'; -- box_left INSERT INTO pg_amop (amopid, amopclaid, amopopr, amopstrategy) SELECT am.oid, opcl.oid, c.opoid, 1 FROM pg_am am, pg_opclass opcl, rt_ops_tmp c WHERE amname = 'gist' AND opcname = 'gist_geometry_ops' AND c.oprname = '<<'; -- box_overleft INSERT INTO pg_amop (amopid, amopclaid, amopopr, amopstrategy) SELECT am.oid, opcl.oid, c.opoid, 2 FROM pg_am am, pg_opclass opcl, rt_ops_tmp c WHERE amname = 'gist' AND opcname = 'gist_geometry_ops' AND c.oprname = '&<'; -- box_overlap INSERT INTO pg_amop (amopid, amopclaid, amopopr, amopstrategy) SELECT am.oid, opcl.oid, c.opoid, 3 FROM pg_am am, pg_opclass opcl, rt_ops_tmp c WHERE amname = 'gist' AND opcname = 'gist_geometry_ops' AND c.oprname = '&&'; -- box_overright INSERT INTO pg_amop (amopid, amopclaid, amopopr, amopstrategy) SELECT am.oid, opcl.oid, c.opoid, 4 FROM pg_am am, pg_opclass opcl, rt_ops_tmp c WHERE amname = 'gist' AND opcname = 'gist_geometry_ops' AND c.oprname = '&>'; -- box_right INSERT INTO pg_amop (amopid, amopclaid, amopopr, amopstrategy) SELECT am.oid, opcl.oid, c.opoid, 5 FROM pg_am am, pg_opclass opcl, rt_ops_tmp c WHERE amname = 'gist' AND opcname = 'gist_geometry_ops' AND c.oprname = '>>'; -- box_same INSERT INTO pg_amop (amopid, amopclaid, amopopr, amopstrategy) SELECT am.oid, opcl.oid, c.opoid, 6 FROM pg_am am, pg_opclass opcl, rt_ops_tmp c WHERE amname = 'gist' AND opcname = 'gist_geometry_ops' AND c.oprname = '~='; -- box_contains INSERT INTO pg_amop (amopid, amopclaid, amopopr, amopstrategy) SELECT am.oid, opcl.oid, c.opoid, 7 FROM pg_am am, pg_opclass opcl, rt_ops_tmp c WHERE amname = 'gist' AND opcname = 'gist_geometry_ops' AND c.oprname = '~'; -- box_contained INSERT INTO pg_amop (amopid, amopclaid, amopopr, amopstrategy) SELECT am.oid, opcl.oid, c.opoid, 8 FROM pg_am am, pg_opclass opcl, rt_ops_tmp c 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 (amid, amopclaid, amproc, amprocnum) SELECT am.oid, opcl.oid, pro.oid, 1 FROM pg_am am, pg_opclass opcl, pg_proc pro WHERE amname = 'gist' AND opcname = 'gist_geometry_ops' AND proname = 'gist_lwgeom_consistent'; INSERT INTO pg_amproc (amid, amopclaid, amproc, amprocnum) SELECT am.oid, opcl.oid, pro.oid, 2 FROM pg_am am, pg_opclass opcl, pg_proc pro WHERE amname = 'gist' AND opcname = 'gist_geometry_ops' AND proname = 'gist_lwgeom_union'; INSERT INTO pg_amproc (amid, amopclaid, amproc, amprocnum) SELECT am.oid, opcl.oid, pro.oid, 3 FROM pg_am am, pg_opclass opcl, pg_proc pro WHERE amname = 'gist' AND opcname = 'gist_geometry_ops' AND proname = 'gist_lwgeom_compress'; INSERT INTO pg_amproc (amid, amopclaid, amproc, amprocnum) SELECT am.oid, opcl.oid, pro.oid, 4 FROM pg_am am, pg_opclass opcl, pg_proc pro WHERE amname = 'gist' AND opcname = 'gist_geometry_ops' AND proname = 'gist_lwgeom_decompress'; INSERT INTO pg_amproc (amid, amopclaid, amproc, amprocnum) SELECT am.oid, opcl.oid, pro.oid, 5 FROM pg_am am, pg_opclass opcl, pg_proc pro WHERE amname = 'gist' AND opcname = 'gist_geometry_ops' AND proname = 'gist_lwgeom_penalty'; INSERT INTO pg_amproc (amid, amopclaid, amproc, amprocnum) SELECT am.oid, opcl.oid, pro.oid, 6 FROM pg_am am, pg_opclass opcl, pg_proc pro WHERE amname = 'gist' AND opcname = 'gist_geometry_ops' AND proname = 'gist_lwgeom_picksplit'; INSERT INTO pg_amproc (amid, amopclaid, amproc, amprocnum) SELECT am.oid, opcl.oid, pro.oid, 7 FROM pg_am am, pg_opclass opcl, pg_proc pro WHERE amname = 'gist' AND opcname = 'gist_geometry_ops' AND proname = 'gist_lwgeom_same'; #elsif USE_VERSION == 72 -- -- Create opclass index binding entries for PG72 -- 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 = 'box2d')); -- 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 = 'gist_lwgeom_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 = 'gist_lwgeom_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 = 'gist_lwgeom_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 = 'gist_lwgeom_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 = 'gist_lwgeom_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 = 'gist_lwgeom_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 = 'gist_lwgeom_same'; #else // USE_VERSION >= 73 -- -- Create opclass index bindings for PG>=73 -- CREATE OPERATOR CLASS gist_geometry_ops DEFAULT FOR TYPE geometry USING gist AS OPERATOR 1 << RECHECK, OPERATOR 2 &< RECHECK, OPERATOR 3 && RECHECK, OPERATOR 4 &> RECHECK, OPERATOR 5 >> RECHECK, OPERATOR 6 ~= RECHECK, OPERATOR 7 ~ RECHECK, OPERATOR 8 @ RECHECK, FUNCTION 1 gist_lwgeom_consistent (internal, geometry, int4), FUNCTION 2 gist_lwgeom_union (bytea, internal), FUNCTION 3 gist_lwgeom_compress (internal), FUNCTION 4 gist_lwgeom_decompress (internal), FUNCTION 5 gist_lwgeom_penalty (internal, internal, internal), FUNCTION 6 gist_lwgeom_picksplit (internal, internal), FUNCTION 7 gist_lwgeom_same (box2d, box2d, internal); UPDATE pg_opclass SET opckeytype = (select oid from pg_type where typname = 'box2d') WHERE opcname = 'gist_geometry_ops'; -- TODO: add btree binding... #endif // USE_VERSION >= 73 -- other lwgeom functions CREATEFUNCTION addBBOX(geometry) RETURNS geometry AS '@MODULE_FILENAME@','LWGEOM_addBBOX' LANGUAGE 'C' WITH (isstrict,iscachable); CREATEFUNCTION getSRID(geometry) RETURNS int4 AS '@MODULE_FILENAME@','LWGEOM_getSRID' LANGUAGE 'C' WITH (isstrict,iscachable); -- defined for backward compatibility CREATEFUNCTION SRID(geometry) RETURNS int4 AS '@MODULE_FILENAME@','LWGEOM_getSRID' LANGUAGE 'C' WITH (isstrict,iscachable); CREATEFUNCTION setSRID(geometry,int4) RETURNS geometry AS '@MODULE_FILENAME@','LWGEOM_setSRID' LANGUAGE 'C' WITH (isstrict,iscachable); CREATEFUNCTION asText(geometry) RETURNS TEXT AS '@MODULE_FILENAME@','LWGEOM_asText' LANGUAGE 'C' WITH (isstrict,iscachable); CREATEFUNCTION getbbox(geometry) RETURNS box2d AS '@MODULE_FILENAME@','LWGEOM_to_BOX2DFLOAT4' LANGUAGE 'C' WITH (isstrict,iscachable); CREATEFUNCTION mem_size(geometry) RETURNS int4 AS '@MODULE_FILENAME@', 'lwgeom_mem_size' LANGUAGE 'C' WITH (isstrict); CREATEFUNCTION geometrytype(geometry) RETURNS text AS '@MODULE_FILENAME@', 'LWGEOM_getTYPE' LANGUAGE 'C' WITH (isstrict); -- -- Aggregate functions -- CREATEFUNCTION combine_bbox(box2d,geometry) RETURNS box2d AS '@MODULE_FILENAME@', 'combine_box2d' LANGUAGE 'C'; CREATE AGGREGATE extent( sfunc = combine_bbox, basetype = geometry, stype = box2d ); ----------------------------------------------------------------------- -- CREATE_HISTOGRAM2D( , ) ----------------------------------------------------------------------- -- -- Returns a histgram with 0s in all the boxes. -- ----------------------------------------------------------------------- CREATEFUNCTION create_histogram2d(box2d,int) RETURNS histogram2d AS '@MODULE_FILENAME@','create_lwhistogram2d' LANGUAGE 'C' with (isstrict); ----------------------------------------------------------------------- -- BUILD_HISTOGRAM2D( , , ) ----------------------------------------------------------------------- CREATEFUNCTION build_histogram2d (histogram2d,text,text) RETURNS histogram2d AS '@MODULE_FILENAME@','build_lwhistogram2d' LANGUAGE 'C' with (isstrict); #if USE_VERSION >= 73 ----------------------------------------------------------------------- -- BUILD_HISTOGRAM2D(,,,) ----------------------------------------------------------------------- -- This is a wrapper to the omonimous schema unaware function, -- thanks to Carl Anderson for the idea. ----------------------------------------------------------------------- CREATEFUNCTION build_histogram2d (histogram2d,text,text,text) RETURNS histogram2d AS ' BEGIN EXECUTE ''SET local search_path = ''||$2||'',public''; RETURN public.build_histogram2d($1,$3,$4); END ' LANGUAGE 'plpgsql' with (isstrict); #endif // USE_VERSION >= 73 ----------------------------------------------------------------------- -- EXPLODE_HISTOGRAM2D( , ) ----------------------------------------------------------------------- CREATEFUNCTION explode_histogram2d (histogram2d,text) RETURNS histogram2d AS '@MODULE_FILENAME@','explode_lwhistogram2d' LANGUAGE 'C' with (isstrict); ----------------------------------------------------------------------- -- ESTIMATE_HISTOGRAM2D( , ) ----------------------------------------------------------------------- CREATEFUNCTION estimate_histogram2d(histogram2d,box2d) RETURNS float8 AS '@MODULE_FILENAME@','estimate_lwhistogram2d' LANGUAGE 'C' with (isstrict); ----------------------------------------------------------------------- -- FIND_EXTENT( , , ) ----------------------------------------------------------------------- CREATEFUNCTION find_extent(text,text,text) RETURNS box2d AS ' DECLARE schemaname alias for $1; tablename alias for $2; columnname alias for $3; myrec RECORD; BEGIN FOR myrec IN EXECUTE ''SELECT extent("''||columnname||''") FROM "''||schemaname||''"."''||tablename||''"'' LOOP return myrec.extent; END LOOP; END; ' LANGUAGE 'plpgsql' WITH (isstrict); ----------------------------------------------------------------------- -- FIND_EXTENT(
, ) ----------------------------------------------------------------------- CREATEFUNCTION find_extent(text,text) RETURNS box2d AS ' DECLARE tablename alias for $1; columnname alias for $2; myrec RECORD; BEGIN FOR myrec IN EXECUTE ''SELECT extent("''||columnname||''") FROM "''||tablename||''"'' LOOP return myrec.extent; END LOOP; END; ' LANGUAGE 'plpgsql' WITH (isstrict); ------------------------------------------------------------------- -- SPATIAL_REF_SYS ------------------------------------------------------------------- CREATE TABLE spatial_ref_sys ( srid integer not null primary key, auth_name varchar(256), auth_srid integer, srtext varchar(2048), proj4text varchar(2048) ); ------------------------------------------------------------------- -- GEOMETRY_COLUMNS ------------------------------------------------------------------- CREATE TABLE geometry_columns ( f_table_catalog varchar(256) not null, f_table_schema varchar(256) not null, f_table_name varchar(256) not null, f_geometry_column varchar(256) not null, coord_dimension integer not null, srid integer not null, type varchar(30) not null, #if USE_VERSION < 80 attrelid oid, varattnum int, stats histogram2d, #endif CONSTRAINT geometry_columns_pk primary key ( f_table_catalog, f_table_schema, f_table_name, f_geometry_column ) ); ----------------------------------------------------------------------- -- GET_PROJ4_FROM_SRID( ) ----------------------------------------------------------------------- CREATEFUNCTION get_proj4_from_srid(integer) RETURNS text AS 'SELECT proj4text::text FROM spatial_ref_sys WHERE srid= $1' LANGUAGE 'sql' WITH (iscachable,isstrict); ----------------------------------------------------------------------- -- RENAME_GEOMETRY_TABLE_CONSTRAINTS() ----------------------------------------------------------------------- -- This function has been obsoleted for the difficulty in -- finding attribute on which the constraint is applied. -- AddGeometryColumn will name the constraints in a meaningful -- way, but nobody can rely on it since old postgis versions did -- not do that. ----------------------------------------------------------------------- CREATEFUNCTION rename_geometry_table_constraints() RETURNS text AS ' SELECT ''rename_geometry_table_constraint() is obsoleted''::text ' LANGUAGE 'SQL'; ----------------------------------------------------------------------- -- FIX_GEOMETRY_COLUMNS() ----------------------------------------------------------------------- -- This function will: -- -- o try to fix the schema of records with an invalid one -- (for PG>=73) -- -- o link records to system tables through attrelid and varattnum -- (for PG<75) -- -- o delete all records for which no linking was possible -- (for PG<75) -- -- ----------------------------------------------------------------------- CREATEFUNCTION fix_geometry_columns() RETURNS text AS ' DECLARE result text; linked integer; deleted integer; #if USE_VERSION >= 73 foundschema integer; #endif BEGIN #if USE_VERSION >= 73 -- Since 7.3 schema support has been added. -- Previous postgis versions used to put the database name in -- the schema column. This needs to be fixed, so we try to -- set the correct schema for each geometry_colums record -- looking at table, column, type and srid. UPDATE geometry_columns SET f_table_schema = n.nspname FROM pg_namespace n, pg_class c, pg_attribute a, pg_constraint sridcheck, pg_constraint typecheck WHERE ( f_table_schema is NULL OR f_table_schema = '''' OR f_table_schema NOT IN ( SELECT nspname::varchar FROM pg_namespace nn, pg_class cc, pg_attribute aa WHERE cc.relnamespace = nn.oid AND cc.relname = f_table_name::name AND aa.attrelid = cc.oid AND aa.attname = f_geometry_column::name)) AND f_table_name::name = c.relname AND c.oid = a.attrelid AND c.relnamespace = n.oid AND f_geometry_column::name = a.attname AND sridcheck.conrelid = c.oid --AND sridcheck.conname = ''$1'' AND sridcheck.consrc LIKE ''(srid(% = %)'' AND typecheck.conrelid = c.oid --AND typecheck.conname = ''$2'' AND typecheck.consrc LIKE ''((geometrytype(%) = ''''%''''::text) OR (% IS NULL))'' AND sridcheck.consrc ~ textcat('' = '', srid::text) AND typecheck.consrc ~ textcat('' = '''''', type::text) AND NOT EXISTS ( SELECT oid FROM geometry_columns gc WHERE c.relname::varchar = gc.f_table_name #if USE_VERSION >= 73 AND n.nspname::varchar = gc.f_table_schema #endif AND a.attname::varchar = gc.f_geometry_column ); GET DIAGNOSTICS foundschema = ROW_COUNT; #endif #if USE_VERSION >= 80 -- no linkage to system table needed return ''fixed:''||foundschema::text; #endif -- fix linking to system tables UPDATE geometry_columns SET attrelid = NULL, varattnum = NULL, stats = NULL; UPDATE geometry_columns SET attrelid = c.oid, varattnum = a.attnum #if USE_VERSION >= 73 FROM pg_class c, pg_attribute a, pg_namespace n WHERE n.nspname = f_table_schema::name AND c.relname = f_table_name::name AND c.relnamespace = n.oid #else // USE_VERSION < 73 FROM pg_class c, pg_attribute a WHERE c.relname = f_table_name::name #endif AND a.attname = f_geometry_column::name AND a.attrelid = c.oid; GET DIAGNOSTICS linked = ROW_COUNT; -- remove stale records DELETE FROM geometry_columns WHERE attrelid IS NULL; GET DIAGNOSTICS deleted = ROW_COUNT; result = #if USE_VERSION >= 73 ''fixed:'' || foundschema::text || #endif '' linked:'' || linked::text || '' deleted:'' || deleted::text; return result; END; ' LANGUAGE 'plpgsql' ; ----------------------------------------------------------------------- -- PROBE_GEOMETRY_COLUMNS() ----------------------------------------------------------------------- -- Fill the geometry_columns table with values probed from the system -- catalogues. 3d flag can not be probed, it defaults to 2 -- -- Note that bogus records already in geometry_columns are not -- overridden (a check for schema.table.column is performed), so -- to have a fresh probe backup your geometry_column, delete from -- it and probe. ----------------------------------------------------------------------- CREATEFUNCTION probe_geometry_columns() RETURNS text AS ' DECLARE inserted integer; oldcount integer; probed integer; stale integer; BEGIN SELECT count(*) INTO oldcount FROM geometry_columns; SELECT count(*) INTO probed FROM pg_class c, pg_attribute a, pg_type t, #if USE_VERSION >= 73 pg_namespace n, #endif pg_constraint sridcheck, pg_constraint typecheck WHERE t.typname = ''geometry'' AND a.atttypid = t.oid AND a.attrelid = c.oid #if USE_VERSION >= 73 AND c.relnamespace = n.oid AND sridcheck.connamespace = n.oid AND typecheck.connamespace = n.oid #endif AND sridcheck.conrelid = c.oid --AND sridcheck.conname = ''$1'' AND sridcheck.consrc LIKE ''(srid(% = %)'' AND typecheck.conrelid = c.oid --AND typecheck.conname = ''$2''; AND typecheck.consrc LIKE ''((geometrytype(%) = ''''%''''::text) OR (% IS NULL))'' ; INSERT INTO geometry_columns SELECT ''''::varchar as f_table_catalogue, #if USE_VERSION >= 73 n.nspname::varchar as f_table_schema, #else ''''::varchar as f_table_schema, #endif c.relname::varchar as f_table_name, a.attname::varchar as f_geometry_column, 2 as coord_dimension, trim(both '' =)'' from substr(sridcheck.consrc, strpos(sridcheck.consrc, ''='')))::integer as srid, trim(both '' =)'''''' from substr(typecheck.consrc, strpos(typecheck.consrc, ''=''), strpos(typecheck.consrc, ''::'')- strpos(typecheck.consrc, ''='') ))::varchar as type, #if USE_VERSION < 80 a.attrelid, a.attnum as varattnum, null::histogram2d as stats #endif FROM pg_class c, pg_attribute a, pg_type t, #if USE_VERSION >= 73 pg_namespace n, #endif pg_constraint sridcheck, pg_constraint typecheck WHERE t.typname = ''geometry'' AND a.atttypid = t.oid AND a.attrelid = c.oid #if USE_VERSION >= 73 AND c.relnamespace = n.oid AND sridcheck.connamespace = n.oid AND typecheck.connamespace = n.oid #endif AND sridcheck.conrelid = c.oid --AND sridcheck.conname = ''$1'' AND sridcheck.consrc LIKE ''(srid(% = %)'' AND typecheck.conrelid = c.oid --AND typecheck.conname = ''$2'' AND typecheck.consrc LIKE ''((geometrytype(%) = ''''%''''::text) OR (% IS NULL))'' AND NOT EXISTS ( SELECT oid FROM geometry_columns gc WHERE c.relname::varchar = gc.f_table_name #if USE_VERSION >= 73 AND n.nspname::varchar = gc.f_table_schema #endif AND a.attname::varchar = gc.f_geometry_column ); GET DIAGNOSTICS inserted = ROW_COUNT; IF oldcount > probed THEN stale = oldcount-probed; ELSE stale = 0; END IF; RETURN ''probed:''||probed|| '' inserted:''||inserted|| '' conflicts:''||probed-inserted|| '' stale:''||stale; 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. -- ----------------------------------------------------------------------- CREATEFUNCTION 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; #if USE_VERSION >= 73 rec RECORD; schema_ok bool; real_schema name; #endif fixgeomres text; 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 USE_VERSION >= 73 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; #endif -- Add geometry column 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 ''; -- Delete stale record in geometry_column (if any) EXECUTE ''DELETE FROM geometry_columns WHERE f_table_catalog = '' || quote_literal('''') || '' AND f_table_schema = '' || #if USE_VERSION >= 73 quote_literal(real_schema) || #else quote_literal('''') || #endif '' AND f_table_name = '' || quote_literal(table_name) || '' AND f_geometry_column = '' || quote_literal(column_name); -- Add record in geometry_column 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) || '')''; -- Add table checks EXECUTE ''ALTER TABLE '' || #if USE_VERSION >= 73 quote_ident(real_schema) || ''.'' || quote_ident(table_name) #else quote_ident(table_name) #endif || '' ADD CONSTRAINT "enforce_srid_'' || column_name || ''" 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 CONSTRAINT "enforce_geotype_'' || column_name || ''" CHECK (geometrytype('' || quote_ident(column_name) || '')='' || quote_literal(new_type) || '' OR ('' || quote_ident(column_name) || '') is null)''; END IF; SELECT fix_geometry_columns() INTO fixgeomres; return #if USE_VERSION >= 73 real_schema || ''.'' || #endif table_name || ''.'' || column_name || '' SRID:'' || new_srid || '' TYPE:'' || new_type || ''\n '' || ''geometry_column '' || fixgeomres; END; ' LANGUAGE 'plpgsql' WITH (isstrict); ---------------------------------------------------------------------------- -- ADDGEOMETRYCOLUMN ( ,
, , , , ) ---------------------------------------------------------------------------- -- -- This is a wrapper to the real AddGeometryColumn, for use -- when catalogue is undefined -- ---------------------------------------------------------------------------- CREATEFUNCTION 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); ---------------------------------------------------------------------------- -- ADDGEOMETRYCOLUMN (
, , , , ) ---------------------------------------------------------------------------- -- -- This is a wrapper to the real AddGeometryColumn, for use -- when catalogue and schema are undefined -- ---------------------------------------------------------------------------- CREATEFUNCTION 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 -- , ,
, ----------------------------------------------------------------------- -- -- Removes geometry column reference from geometry_columns table. -- Drops the column with pgsql >= 73. -- Make some silly enforcements on it for pgsql < 73 -- ----------------------------------------------------------------------- CREATEFUNCTION DropGeometryColumn(varchar, varchar,varchar,varchar) RETURNS text AS ' DECLARE catalog_name alias for $1; schema_name alias for $2; table_name alias for $3; column_name alias for $4; myrec RECORD; okay boolean; real_schema name; BEGIN #if USE_VERSION >= 73 -- 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; #else real_schema = schema_name; #endif // USE_VERSION >= 73 -- 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); #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.''; END; ' LANGUAGE 'plpgsql' WITH (isstrict); ----------------------------------------------------------------------- -- DROPGEOMETRYCOLUMN -- ,
, ----------------------------------------------------------------------- -- -- This is a wrapper to the real DropGeometryColumn, for use -- when catalogue is undefined -- ----------------------------------------------------------------------- CREATEFUNCTION 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 --
, ----------------------------------------------------------------------- -- -- This is a wrapper to the real DropGeometryColumn, for use -- when catalogue and schema is undefined. -- ----------------------------------------------------------------------- CREATEFUNCTION DropGeometryColumn(varchar,varchar) RETURNS text AS ' DECLARE ret text; BEGIN SELECT DropGeometryColumn('''','''',$1,$2) into ret; RETURN ret; END; ' LANGUAGE 'plpgsql' WITH (isstrict); ----------------------------------------------------------------------- -- DROPGEOMETRYTABLE -- , ,
----------------------------------------------------------------------- -- -- Drop a table and all its references in geometry_columns -- ----------------------------------------------------------------------- CREATEFUNCTION DropGeometryTable(varchar, varchar,varchar) RETURNS text AS ' DECLARE catalog_name alias for $1; schema_name alias for $2; table_name alias for $3; real_schema name; BEGIN #if USE_VERSION >= 73 IF ( schema_name = '''' ) THEN SELECT current_schema() into real_schema; ELSE real_schema = schema_name; END IF; #endif // USE_VERSION >= 73 -- Remove refs from geometry_columns table EXECUTE ''DELETE FROM geometry_columns WHERE '' || #if USE_VERSION >= 73 ''f_table_schema = '' || quote_literal(real_schema) || '' AND '' || #endif '' f_table_name = '' || quote_literal(table_name); -- Remove table EXECUTE ''DROP TABLE '' #if USE_VERSION >= 73 || quote_ident(real_schema) || ''.'' || #endif quote_ident(table_name); RETURN #if USE_VERSION >= 73 real_schema || ''.'' || #endif table_name ||'' dropped.''; END; ' LANGUAGE 'plpgsql' WITH (isstrict); ----------------------------------------------------------------------- -- DROPGEOMETRYTABLE -- ,
----------------------------------------------------------------------- -- -- Drop a table and all its references in geometry_columns -- ----------------------------------------------------------------------- CREATEFUNCTION DropGeometryTable(varchar,varchar) RETURNS text AS 'SELECT DropGeometryTable('''',$1,$2)' LANGUAGE 'sql' WITH (isstrict); ----------------------------------------------------------------------- -- DROPGEOMETRYTABLE --
----------------------------------------------------------------------- -- -- Drop a table and all its references in geometry_columns -- For PG>=73 use current_schema() -- ----------------------------------------------------------------------- CREATEFUNCTION DropGeometryTable(varchar) RETURNS text AS 'SELECT DropGeometryTable('''','''',$1)' LANGUAGE 'sql' WITH (isstrict); ----------------------------------------------------------------------- -- UPDATE_GEOMETRY_STATS() ----------------------------------------------------------------------- -- -- Only meaningful for PG<75. -- Gather statisticts about geometry columns for use -- with cost estimator. -- -- It is defined also for PG>=75 for back-compatibility -- ----------------------------------------------------------------------- #if USE_VERSION >= 80 CREATEFUNCTION update_geometry_stats() RETURNS text AS ' SELECT ''update_geometry_stats() has been obsoleted. Statistics are automatically built running the ANALYZE command''::text' LANGUAGE 'sql'; #else // USE_VERSION < 80 CREATEFUNCTION update_geometry_stats() RETURNS text AS ' DECLARE result text; stated integer; fixres text; BEGIN SELECT fix_geometry_columns() INTO fixres; UPDATE geometry_columns SET #if USE_VERSION >= 73 stats = (build_histogram2d(create_histogram2d( find_extent(f_table_schema, f_table_name, f_geometry_column), 40), f_table_schema, f_table_name, f_geometry_column)) FROM pg_class c, pg_attribute a, pg_namespace n WHERE n.nspname = f_table_schema::name AND c.relname = f_table_name::name AND c.relnamespace = n.oid #else // USE_VERSION < 73 stats = (build_histogram2d(create_histogram2d( find_extent(f_table_name, f_geometry_column), 40), f_table_name, f_geometry_column)) FROM pg_class c, pg_attribute a WHERE c.relname = f_table_name::name #endif AND a.attname = f_geometry_column::name AND a.attrelid = c.oid AND geometry_columns.attrelid is not null; GET DIAGNOSTICS stated = ROW_COUNT; result = fixres || '' stats:'' || stated::text; return result; END; ' LANGUAGE 'plpgsql' ; #endif // USE_VERSION < 80 ----------------------------------------------------------------------- -- UPDATE_GEOMETRY_STATS(
, ) ----------------------------------------------------------------------- -- -- Only meaningful for PG<75. -- Gather statisticts about a geometry column for use -- with cost estimator. -- -- It is defined also for PG>=75 for back-compatibility -- ----------------------------------------------------------------------- #if USE_VERSION >= 80 CREATEFUNCTION update_geometry_stats(varchar,varchar) RETURNS text AS 'SELECT update_geometry_stats();' LANGUAGE 'sql' ; #else CREATEFUNCTION update_geometry_stats(varchar,varchar) RETURNS text AS ' DECLARE tablename aliAS for $1; columnname aliAS for $2; stated integer; result text; fixres text; BEGIN SELECT fix_geometry_columns() INTO fixres; EXECUTE ''UPDATE geometry_columns SET #if USE_VERSION >= 73 stats = (build_histogram2d(create_histogram2d( find_extent(f_table_schema, f_table_name, f_geometry_column), 40), f_table_schema, f_table_name, f_geometry_column)) FROM pg_class c, pg_attribute a, pg_namespace n WHERE n.nspname = f_table_schema::name AND c.relname = f_table_name::name AND a.attname = f_geometry_column::name AND c.relnamespace = n.oid AND a.attrelid = c.oid #else // USE_VERSION < 73 stats = (build_histogram2d(create_histogram2d( find_extent(f_table_name, f_geometry_column), 40), f_table_name, f_geometry_column)) FROM pg_class c, pg_attribute a WHERE c.relname = f_table_name::name AND a.attname = f_geometry_column::name AND a.attrelid = c.oid #endif AND f_table_name = '' || quote_literal(tablename) || '' AND f_geometry_column = '' || quote_literal(columnname) || '' AND geometry_columns.attrelid is not null''; GET DIAGNOSTICS stated = ROW_COUNT; result = fixres || '' stats:'' || stated::text; return result; END; ' LANGUAGE 'plpgsql' ; #endif // USE_VERSION < 80 ----------------------------------------------------------------------- -- FIND_SRID( ,
, ) ----------------------------------------------------------------------- CREATEFUNCTION find_srid(varchar,varchar,varchar) RETURNS int4 AS 'DECLARE schem text; tabl text; sr int4; BEGIN IF $1 IS NULL THEN RAISE EXCEPTION ''find_srid() - schema is NULL!''; END IF; IF $2 IS NULL THEN RAISE EXCEPTION ''find_srid() - table name is NULL!''; END IF; IF $3 IS NULL THEN RAISE EXCEPTION ''find_srid() - column name is NULL!''; END IF; schem = $1; tabl = $2; -- if the table contains a . and the schema is empty -- split the table into a schema and a table -- otherwise drop through to default behavior IF ( schem = '''' and tabl LIKE ''%.%'' ) THEN schem = substr(tabl,1,strpos(tabl,''.'')-1); tabl = substr(tabl,length(schem)+2); ELSE schem = schem || ''%''; END IF; select SRID into sr from geometry_columns where f_table_schema like schem and f_table_name = tabl and f_geometry_column = $3; IF NOT FOUND THEN RAISE EXCEPTION ''find_srid() - couldnt find the corresponding SRID - is the geometry registered in the GEOMETRY_COLUMNS table? Is there an uppercase/lowercase missmatch?''; END IF; return sr; END; ' LANGUAGE 'plpgsql' WITH (iscachable); COMMIT; #if 0 ----------------------------------------------- -- CONVERSION FUNCTION TO/FROM OLDGEOMETRY ----------------------------------------------- BEGIN; CREATEFUNCTION geometry(wkb,int4) RETURNS geometry AS '@MODULE_FILENAME@','LWGEOMFromWKB' LANGUAGE 'C' WITH (isstrict,iscachable); CREATEFUNCTION wkb(geometry) RETURNS wkb AS '@MODULE_FILENAME@','WKBFromLWGEOM' LANGUAGE 'C' WITH (isstrict,iscachable); CREATEFUNCTION asbinary(geometry) RETURNS wkb AS '@MODULE_FILENAME@','WKBFromLWGEOM' LANGUAGE 'C' WITH (isstrict,iscachable); CREATEFUNCTION geometry(wkb) RETURNS geometry AS '@MODULE_FILENAME@','LWGEOMFromWKB' LANGUAGE 'C' WITH (isstrict,iscachable); CREATEFUNCTION oldgeometry(geometry) RETURNS oldgeometry AS 'BEGIN RAISE NOTICE ''lwgeom => geometry CONVERSION''; RETURN GeomFromWKB(asBinary($1),getSRID($1) ); END;' LANGUAGE 'plpgsql' WITH (iscachable,isstrict); CREATEFUNCTION geometry(oldgeometry) RETURNS geometry AS 'BEGIN RAISE NOTICE ''geometry => lwgeom CONVERSION''; RETURN setSRID(geometry(asBinary($1)),SRID($1) ); END;' LANGUAGE 'plpgsql' WITH (iscachable,isstrict); CREATE CAST (geometry as oldgeometry) WITH FUNCTION oldgeometry(geometry) AS IMPLICIT ; CREATE CAST (oldgeometry as geometry) WITH FUNCTION geometry(oldgeometry) AS IMPLICIT ; CREATE CAST (geometry as box2d) WITH FUNCTION box2d(geometry) AS IMPLICIT ; CREATE CAST (geometry as wkb) WITH FUNCTION wkb(geometry) AS IMPLICIT ; CREATE CAST (wkb as geometry) WITH FUNCTION geometry(wkb) AS IMPLICIT ; CREATEFUNCTION box2d(box3d) RETURNS box2d AS '@MODULE_FILENAME@','BOX3D_to_BOX2DFLOAT4' LANGUAGE 'C' WITH (isstrict,iscachable); CREATEFUNCTION box3d(box2d) RETURNS box3d AS '@MODULE_FILENAME@','BOX2DFLOAT4_to_BOX3D' LANGUAGE 'C' WITH (isstrict,iscachable); CREATE CAST (box3d as box2d) WITH FUNCTION box2d(box3d) AS IMPLICIT ; CREATE CAST (box2d as box3d) WITH FUNCTION box3d(box2d) AS IMPLICIT ; COMMIT; #endif