-
Notifications
You must be signed in to change notification settings - Fork 3
/
Copy pathtopology.sql.in
2013 lines (1762 loc) · 55.9 KB
/
topology.sql.in
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
641
642
643
644
645
646
647
648
649
650
651
652
653
654
655
656
657
658
659
660
661
662
663
664
665
666
667
668
669
670
671
672
673
674
675
676
677
678
679
680
681
682
683
684
685
686
687
688
689
690
691
692
693
694
695
696
697
698
699
700
701
702
703
704
705
706
707
708
709
710
711
712
713
714
715
716
717
718
719
720
721
722
723
724
725
726
727
728
729
730
731
732
733
734
735
736
737
738
739
740
741
742
743
744
745
746
747
748
749
750
751
752
753
754
755
756
757
758
759
760
761
762
763
764
765
766
767
768
769
770
771
772
773
774
775
776
777
778
779
780
781
782
783
784
785
786
787
788
789
790
791
792
793
794
795
796
797
798
799
800
801
802
803
804
805
806
807
808
809
810
811
812
813
814
815
816
817
818
819
820
821
822
823
824
825
826
827
828
829
830
831
832
833
834
835
836
837
838
839
840
841
842
843
844
845
846
847
848
849
850
851
852
853
854
855
856
857
858
859
860
861
862
863
864
865
866
867
868
869
870
871
872
873
874
875
876
877
878
879
880
881
882
883
884
885
886
887
888
889
890
891
892
893
894
895
896
897
898
899
900
901
902
903
904
905
906
907
908
909
910
911
912
913
914
915
916
917
918
919
920
921
922
923
924
925
926
927
928
929
930
931
932
933
934
935
936
937
938
939
940
941
942
943
944
945
946
947
948
949
950
951
952
953
954
955
956
957
958
959
960
961
962
963
964
965
966
967
968
969
970
971
972
973
974
975
976
977
978
979
980
981
982
983
984
985
986
987
988
989
990
991
992
993
994
995
996
997
998
999
1000
-- - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - -
--
-- $Id$
--
-- PostGIS - Spatial Types for PostgreSQL
-- http://postgis.refractions.net
--
-- Copyright (C) 2010, 2011 Sandro Santilli <[email protected]>
-- Copyright (C) 2005 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.
--
-- Author: Sandro Santilli <[email protected]>
--
-- - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - -
--
-- STATUS:
--
-- All objects are created in the 'topology' schema.
--
-- We have PostGIS-specific objects and SQL/MM objects.
-- PostGIS-specific objects have no prefix, SQL/MM ones
-- have the ``ST_' prefix.
--
-- [PostGIS-specific]
--
-- TABLE topology
-- Table storing topology info (name, srid, precision)
--
-- TYPE TopoGeometry
-- Complex type storing topology_id, layer_id, geometry type
-- and topogeometry id.
--
-- DOMAIN TopoElement
-- An array of two elements: element_id and element_type.
-- In fact, an array of integers.
--
-- DOMAIN TopoElementArray
-- An array of element_id,element_type values.
-- In fact, a bidimensional array of integers:
-- '{{id,type}, {id,type}, ...}'
--
-- FUNCTION CreateTopology(name, [srid], [precision])
-- Initialize a new topology (creating schema with
-- edge,face,node,relation) and add a record into
-- the topology.topology table.
-- TODO: add triggers (or rules, or whatever) enforcing
-- precision to the edge and node tables.
--
-- FUNCTION DropTopology(name)
-- Delete a topology removing reference from the
-- topology.topology table
--
-- FUNCTION GetTopologyId(name)
-- FUNCTION GetTopologySRID(name)
-- FUNCTION GetTopologyName(id)
-- Return info about a Topology
--
-- FUNCTION AddTopoGeometryColumn(toponame, schema, table, column, geomtype)
-- Add a TopoGeometry column to a table, making it a topology layer.
-- Returns created layer id.
--
-- FUNCTION DropTopoGeometryColumn(schema, table, column)
-- Drop a TopoGeometry column, unregister the associated layer,
-- cleanup the relation table.
--
-- FUNCTION CreateTopoGeom(toponame, geomtype, layer_id, topo_objects)
-- Create a TopoGeometry object from existing Topology elements.
-- The "topo_objects" parameter is of TopoElementArray type.
--
-- FUNCTION GetTopoGeomElementArray(toponame, layer_id, topogeom_id)
-- FUNCTION GetTopoGeomElementArray(TopoGeometry)
-- Returns a TopoElementArray object containing the topological
-- elements of the given TopoGeometry.
--
-- FUNCTION GetTopoGeomElements(toponame, layer_id, topogeom_id)
-- FUNCTION GetTopoGeomElements(TopoGeometry)
-- Returns a set of TopoElement objects containing the
-- topological elements of the given TopoGeometry (primitive
-- elements)
--
-- FUNCTION ValidateTopology(toponame)
-- Run validity checks on the topology, returning, for each
-- detected error, a 3-columns row containing error string
-- and references to involved topo elements: error, id1, id2
--
-- - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - -
--
-- Overloaded functions for TopoGeometry inputs
--
-- FUNCTION intersects(TopoGeometry, TopoGeometry)
-- FUNCTION equals(TopoGeometry, TopoGeometry)
--
-- - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - -
--
-- FUNCTION TopoGeo_AddPoint(toponame, point)
-- Add a Point geometry to the topology
-- TODO: accept a topology/layer id
-- rework to use existing node if existent
--
-- FUNCTION TopoGeo_AddLinestring(toponame, line)
-- Add a LineString geometry to the topology
-- TODO: accept a topology/layer id
-- rework to use existing nodes/edges
-- splitting them if required
--
-- FUNCTION TopoGeo_AddPolygon(toponame, polygon)
-- Add a Polygon geometry to the topology
-- TODO: implement
--
-- TYPE GetFaceEdges_ReturnType
-- Complex type used to return tuples from ST_GetFaceEdges
--
-- - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - -
--
-- [SQL/MM]
--
-- ST_InitTopoGeo
-- Done, can be modified to include explicit sequences or
-- more constraints. Very noisy due to implicit index creations
-- for primary keys and sequences for serial fields...
--
-- ST_CreateTopoGeo
-- Complete
--
-- ST_AddIsoNode
-- Complete
--
-- ST_RemoveIsoNode
-- Complete
--
-- ST_MoveIsoNode
-- Complete
--
-- ST_AddIsoEdge
-- Complete
--
-- ST_RemoveIsoEdge
-- Complete, exceptions untested
--
-- ST_ChangeEdgeGeom
-- Complete
--
-- ST_NewEdgesSplit
-- Complete
-- Also updates the Relation table
--
-- ST_ModEdgeSplit
-- Complete
-- Also updates the Relation table
--
-- ST_AddEdgeNewFaces
-- Complete
-- Also updates the Relation table
--
-- ST_AddEdgeModFace
-- Complete
-- Also updates the Relation table
--
-- ST_GetFaceEdges
-- Complete
--
-- ST_ModEdgeHeal
-- Complete
-- Also updates the Relation table
--
-- ST_NewEdgeHeal
-- Complete
-- Also updates the Relation table
--
-- ST_GetFaceGeometry
-- Implemented using ST_BuildArea()
--
-- ST_RemEdgeNewFace
-- Complete
-- Also updates the Relation table
--
-- ST_RemEdgeModFace
-- Complete
-- Also updates the Relation table
--
-- ST_ValidateTopoGeo
-- Unimplemented (probably a wrapper around ValidateTopology)
--
--
-- Uninstalling previous installation isn't really a good habit ...
-- Let people decide about that
-- DROP SCHEMA topology CASCADE;
#include "../postgis/sqldefines.h"
CREATE SCHEMA topology;
-- Doing everything outside of a transaction helps
-- upgrading in the best case.
BEGIN;
--={ ----------------------------------------------------------------
-- POSTGIS-SPECIFIC block
--
-- This part contains function NOT in the SQL/MM specification
--
---------------------------------------------------------------------
--
-- Topology table.
-- Stores id,name,precision and SRID of topologies.
--
CREATE TABLE topology.topology (
id SERIAL NOT NULL PRIMARY KEY,
name VARCHAR NOT NULL UNIQUE,
SRID INTEGER NOT NULL,
precision FLOAT8 NOT NULL,
hasz BOOLEAN NOT NULL DEFAULT false
);
--{ LayerTrigger()
--
-- Layer integrity trigger
--
CREATE OR REPLACE FUNCTION topology.LayerTrigger()
RETURNS trigger
AS
$$
DECLARE
rec RECORD;
ok BOOL;
toponame varchar;
query TEXT;
BEGIN
--RAISE NOTICE 'LayerTrigger called % % at % level', TG_WHEN, TG_OP, TG_LEVEL;
IF TG_OP = 'INSERT' THEN
RAISE EXCEPTION 'LayerTrigger not meant to be called on INSERT';
ELSIF TG_OP = 'UPDATE' THEN
RAISE EXCEPTION 'The topology.layer table cannot be updated';
END IF;
-- Check for existance of any feature column referencing
-- this layer
FOR rec IN SELECT * FROM pg_namespace n, pg_class c, pg_attribute a
WHERE text(n.nspname) = OLD.schema_name
AND c.relnamespace = n.oid
AND text(c.relname) = OLD.table_name
AND a.attrelid = c.oid
AND text(a.attname) = OLD.feature_column
LOOP
query = 'SELECT * '
|| ' FROM ' || quote_ident(OLD.schema_name)
|| '.' || quote_ident(OLD.table_name)
|| ' WHERE layer_id('
|| quote_ident(OLD.feature_column)||') '
|| '=' || OLD.layer_id
|| ' LIMIT 1';
--RAISE NOTICE '%', query;
FOR rec IN EXECUTE query
LOOP
RAISE NOTICE 'A feature referencing layer % of topology % still exists in %.%.%', OLD.layer_id, OLD.topology_id, OLD.schema_name, OLD.table_name, OLD.feature_column;
RETURN NULL;
END LOOP;
END LOOP;
-- Get topology name
SELECT name FROM topology.topology INTO toponame
WHERE id = OLD.topology_id;
IF toponame IS NULL THEN
RAISE NOTICE 'Could not find name of topology with id %',
OLD.layer_id;
END IF;
-- Check if any record in the relation table references this layer
FOR rec IN SELECT * FROM pg_namespace
WHERE text(nspname) = toponame
LOOP
query = 'SELECT * '
|| ' FROM ' || quote_ident(toponame)
|| '.relation '
|| ' WHERE layer_id = '|| OLD.layer_id
|| ' LIMIT 1';
--RAISE NOTICE '%', query;
FOR rec IN EXECUTE query
LOOP
RAISE NOTICE 'A record in %.relation still references layer %', toponame, OLD.layer_id;
RETURN NULL;
END LOOP;
END LOOP;
RETURN OLD;
END;
$$
LANGUAGE 'plpgsql' VOLATILE STRICT;
--} LayerTrigger()
--{
-- Layer table.
-- Stores topology layer informations
--
CREATE TABLE topology.layer (
topology_id INTEGER NOT NULL
REFERENCES topology.topology(id),
layer_id integer NOT NULL,
schema_name VARCHAR NOT NULL,
table_name VARCHAR NOT NULL,
feature_column VARCHAR NOT NULL,
feature_type integer NOT NULL,
level INTEGER NOT NULL DEFAULT 0,
child_id INTEGER DEFAULT NULL,
UNIQUE(schema_name, table_name, feature_column),
PRIMARY KEY(topology_id, layer_id)
);
CREATE TRIGGER layer_integrity_checks BEFORE UPDATE OR DELETE
ON topology.layer FOR EACH ROW EXECUTE PROCEDURE topology.LayerTrigger();
--} Layer table.
--
-- Type returned by ValidateTopology
--
CREATE TYPE topology.ValidateTopology_ReturnType AS (
error varchar,
id1 integer,
id2 integer
);
--
-- TopoGeometry type
--
CREATE TYPE topology.TopoGeometry AS (
topology_id integer,
layer_id integer,
id integer,
type integer -- 1: [multi]point, 2: [multi]line,
-- 3: [multi]polygon, 4: collection
);
--
-- TopoElement domain
--
-- This is an array of two elements: element_id and element_type.
--
-- When used to define _simple_ TopoGeometries,
-- element_type can be:
-- 0: a node
-- 1: an edge
-- 2: a face
-- and element_id will be the node, edge or face identifier
--
-- When used to define _hierarchical_ TopoGeometries,
-- element_type will be the child layer identifier and
-- element_id will be composing TopoGoemetry identifier
--
CREATE DOMAIN topology.TopoElement AS integer[]
CONSTRAINT DIMENSIONS CHECK (
array_upper(VALUE, 2) IS NULL
AND array_upper(VALUE, 1) = 2
);
ALTER DOMAIN topology.TopoElement ADD
CONSTRAINT lower_dimension CHECK (
array_lower(VALUE, 1) = 1
);
ALTER DOMAIN topology.TopoElement DROP CONSTRAINT
#if POSTGIS_PGSQL_VERSION >= 92
IF EXISTS
#endif
type_range;
ALTER DOMAIN topology.TopoElement ADD
CONSTRAINT type_range CHECK (
VALUE[2] > 0
);
--
-- TopoElementArray domain
--
CREATE DOMAIN topology.TopoElementArray AS integer[][]
CONSTRAINT DIMENSIONS CHECK (
array_upper(VALUE, 2) IS NOT NULL
AND array_upper(VALUE, 2) = 2
AND array_upper(VALUE, 3) IS NULL
);
--{ RelationTrigger()
--
-- Relation integrity trigger
--
CREATE OR REPLACE FUNCTION topology.RelationTrigger()
RETURNS trigger
AS
$$
DECLARE
toponame varchar;
topoid integer;
plyr RECORD; -- parent layer
rec RECORD;
ok BOOL;
BEGIN
IF TG_NARGS != 2 THEN
RAISE EXCEPTION 'RelationTrigger called with wrong number of arguments';
END IF;
topoid = TG_ARGV[0];
toponame = TG_ARGV[1];
--RAISE NOTICE 'RelationTrigger called % % on %.relation for a %', TG_WHEN, TG_OP, toponame, TG_LEVEL;
IF TG_OP = 'DELETE' THEN
RAISE EXCEPTION 'RelationTrigger not meant to be called on DELETE';
END IF;
-- Get layer info (and verify it exists)
ok = false;
FOR plyr IN EXECUTE 'SELECT * FROM topology.layer '
|| 'WHERE '
|| ' topology_id = ' || topoid
|| ' AND'
|| ' layer_id = ' || NEW.layer_id
LOOP
ok = true;
EXIT;
END LOOP;
IF NOT ok THEN
RAISE EXCEPTION 'Layer % does not exist in topology %',
NEW.layer_id, topoid;
RETURN NULL;
END IF;
IF plyr.level > 0 THEN -- this is hierarchical layer
-- ElementType must be the layer child id
IF NEW.element_type != plyr.child_id THEN
RAISE EXCEPTION 'Type of elements in layer % must be set to its child layer id %', plyr.layer_id, plyr.child_id;
RETURN NULL;
END IF;
-- ElementId must be an existent TopoGeometry in child layer
ok = false;
FOR rec IN EXECUTE 'SELECT topogeo_id FROM '
|| quote_ident(toponame) || '.relation '
|| ' WHERE layer_id = ' || plyr.child_id
|| ' AND topogeo_id = ' || NEW.element_id
LOOP
ok = true;
EXIT;
END LOOP;
IF NOT ok THEN
RAISE EXCEPTION 'TopoGeometry % does not exist in the child layer %', NEW.element_id, plyr.child_id;
RETURN NULL;
END IF;
ELSE -- this is a basic layer
-- ElementType must be compatible with layer type
IF plyr.feature_type != 4
AND plyr.feature_type != NEW.element_type
THEN
RAISE EXCEPTION 'Element of type % is not compatible with layer of type %', NEW.element_type, plyr.feature_type;
RETURN NULL;
END IF;
--
-- Now lets see if the element is consistent, which
-- is it exists in the topology tables.
--
--
-- Element is a Node
--
IF NEW.element_type = 1
THEN
ok = false;
FOR rec IN EXECUTE 'SELECT node_id FROM '
|| quote_ident(toponame) || '.node '
|| ' WHERE node_id = ' || NEW.element_id
LOOP
ok = true;
EXIT;
END LOOP;
IF NOT ok THEN
RAISE EXCEPTION 'Node % does not exist in topology %', NEW.element_id, toponame;
RETURN NULL;
END IF;
--
-- Element is an Edge
--
ELSIF NEW.element_type = 2
THEN
ok = false;
FOR rec IN EXECUTE 'SELECT edge_id FROM '
|| quote_ident(toponame) || '.edge_data '
|| ' WHERE edge_id = ' || abs(NEW.element_id)
LOOP
ok = true;
EXIT;
END LOOP;
IF NOT ok THEN
RAISE EXCEPTION 'Edge % does not exist in topology %', NEW.element_id, toponame;
RETURN NULL;
END IF;
--
-- Element is a Face
--
ELSIF NEW.element_type = 3
THEN
IF NEW.element_id = 0 THEN
RAISE EXCEPTION 'Face % cannot be associated with any feature', NEW.element_id;
RETURN NULL;
END IF;
ok = false;
FOR rec IN EXECUTE 'SELECT face_id FROM '
|| quote_ident(toponame) || '.face '
|| ' WHERE face_id = ' || NEW.element_id
LOOP
ok = true;
EXIT;
END LOOP;
IF NOT ok THEN
RAISE EXCEPTION 'Face % does not exist in topology %', NEW.element_id, toponame;
RETURN NULL;
END IF;
END IF;
END IF;
RETURN NEW;
END;
$$
LANGUAGE 'plpgsql' VOLATILE STRICT;
--} RelationTrigger()
--{
-- AddTopoGeometryColumn(toponame, schema, table, colum, type, [child])
--
-- Add a TopoGeometry column to a table, making it a topology layer.
-- Returns created layer id.
--
--
CREATE OR REPLACE FUNCTION topology.AddTopoGeometryColumn(toponame varchar, schema varchar, tbl varchar, col varchar, ltype varchar, child integer)
RETURNS integer
AS
$$
DECLARE
intltype integer;
newlevel integer;
topoid integer;
rec RECORD;
newlayer_id integer;
query text;
BEGIN
-- Get topology id
SELECT id FROM topology.topology into topoid
WHERE name = toponame;
IF topoid IS NULL THEN
RAISE EXCEPTION 'Topology % does not exist', toponame;
END IF;
IF ltype ILIKE '%POINT%' OR ltype ILIKE 'PUNTAL' THEN
intltype = 1;
ELSIF ltype ILIKE '%LINE%' OR ltype ILIKE 'LINEAL' THEN
intltype = 2;
ELSIF ltype ILIKE '%POLYGON%' OR ltype ILIKE 'AREAL' THEN
intltype = 3;
ELSIF ltype ILIKE '%COLLECTION%' OR ltype ILIKE 'GEOMETRY' THEN
intltype = 4;
ELSE
RAISE EXCEPTION 'Layer type must be one of POINT,LINE,POLYGON,COLLECTION';
END IF;
--
-- Add new TopoGeometry column in schema.table
--
EXECUTE 'ALTER TABLE ' || quote_ident(schema)
|| '.' || quote_ident(tbl)
|| ' ADD COLUMN ' || quote_ident(col)
|| ' topology.TopoGeometry;';
--
-- See if child id exists and extract its level
--
IF child IS NOT NULL THEN
SELECT level + 1 FROM topology.layer
WHERE layer_id = child
INTO newlevel;
IF newlevel IS NULL THEN
RAISE EXCEPTION 'Child layer % does not exist in topology "%"', child, toponame;
END IF;
END IF;
--
-- Get new layer id from sequence
--
EXECUTE 'SELECT nextval(' ||
quote_literal(
quote_ident(toponame) || '.layer_id_seq'
) || ')' INTO STRICT newlayer_id;
EXECUTE 'INSERT INTO '
|| 'topology.layer(topology_id, '
|| 'layer_id, level, child_id, schema_name, '
|| 'table_name, feature_column, feature_type) '
|| 'VALUES ('
|| topoid || ','
|| newlayer_id || ',' || COALESCE(newlevel, 0) || ','
|| COALESCE(child::text, 'NULL') || ','
|| quote_literal(schema) || ','
|| quote_literal(tbl) || ','
|| quote_literal(col) || ','
|| intltype || ');';
--
-- Create a sequence for TopoGeometries in this new layer
--
EXECUTE 'CREATE SEQUENCE ' || quote_ident(toponame)
|| '.topogeo_s_' || newlayer_id;
--
-- Add constraints on TopoGeom column
--
EXECUTE 'ALTER TABLE ' || quote_ident(schema)
|| '.' || quote_ident(tbl)
|| ' ADD CONSTRAINT "check_topogeom_' || col || '" CHECK ('
|| 'topology_id(' || quote_ident(col) || ') = ' || topoid
|| ' AND '
|| 'layer_id(' || quote_ident(col) || ') = ' || newlayer_id
|| ' AND '
|| 'type(' || quote_ident(col) || ') = ' || intltype
|| ');';
--
-- Add dependency of the feature column on the topology schema
--
query = 'INSERT INTO pg_catalog.pg_depend SELECT '
|| 'fcat.oid, fobj.oid, fsub.attnum, tcat.oid, '
|| 'tobj.oid, 0, ''n'' '
|| 'FROM pg_class fcat, pg_namespace fnsp, '
|| ' pg_class fobj, pg_attribute fsub, '
|| ' pg_class tcat, pg_namespace tobj '
|| ' WHERE fcat.relname = ''pg_class'' '
|| ' AND fnsp.nspname = ' || quote_literal(schema)
|| ' AND fobj.relnamespace = fnsp.oid '
|| ' AND fobj.relname = ' || quote_literal(tbl)
|| ' AND fsub.attrelid = fobj.oid '
|| ' AND fsub.attname = ' || quote_literal(col)
|| ' AND tcat.relname = ''pg_namespace'' '
|| ' AND tobj.nspname = ' || quote_literal(toponame);
--
-- The only reason to add this dependency is to avoid
-- simple drop of a feature column. Still, drop cascade
-- will remove both the feature column and the sequence
-- corrupting the topology anyway ...
--
#if 0
--
-- Add dependency of the topogeom sequence on the feature column
-- This is a dirty hack ...
--
query = 'INSERT INTO pg_catalog.pg_depend SELECT '
|| 'scat.oid, sobj.oid, 0, fcat.oid, '
|| 'fobj.oid, fsub.attnum, ''n'' '
|| 'FROM pg_class fcat, pg_namespace fnsp, '
|| ' pg_class fobj, pg_attribute fsub, '
|| ' pg_class scat, pg_class sobj, '
|| ' pg_namespace snsp '
|| ' WHERE fcat.relname = ''pg_class'' '
|| ' AND fnsp.nspname = ' || quote_literal(schema)
|| ' AND fobj.relnamespace = fnsp.oid '
|| ' AND fobj.relname = ' || quote_literal(tbl)
|| ' AND fsub.attrelid = fobj.oid '
|| ' AND fsub.attname = ' || quote_literal(col)
|| ' AND scat.relname = ''pg_class'' '
|| ' AND snsp.nspname = ' || quote_literal(toponame)
|| ' AND sobj.relnamespace = snsp.oid '
|| ' AND sobj.relname = '
|| ' ''topogeo_s_' || newlayer_id || ''' ';
RAISE NOTICE '%', query;
EXECUTE query;
#endif
RETURN newlayer_id;
END;
$$
LANGUAGE 'plpgsql' VOLATILE;
--}{ AddTopoGeometryColumn
CREATE OR REPLACE FUNCTION topology.AddTopoGeometryColumn(varchar, varchar, varchar, varchar, varchar)
RETURNS integer
AS
$$
SELECT topology.AddTopoGeometryColumn($1, $2, $3, $4, $5, NULL);
$$
LANGUAGE 'sql' VOLATILE;
--
--} AddTopoGeometryColumn
--{
-- DropTopoGeometryColumn(schema, table, colum)
--
-- Drop a TopoGeometry column, unregister the associated layer,
-- cleanup the relation table.
--
--
CREATE OR REPLACE FUNCTION topology.DropTopoGeometryColumn(schema varchar, tbl varchar, col varchar)
RETURNS text
AS
$$
DECLARE
rec RECORD;
lyrinfo RECORD;
ok BOOL;
result text;
BEGIN
-- Get layer and topology info
ok = false;
FOR rec IN EXECUTE 'SELECT t.name as toponame, l.* FROM '
|| 'topology.topology t, topology.layer l '
|| ' WHERE l.topology_id = t.id'
|| ' AND l.schema_name = ' || quote_literal(schema)
|| ' AND l.table_name = ' || quote_literal(tbl)
|| ' AND l.feature_column = ' || quote_literal(col)
LOOP
ok = true;
lyrinfo = rec;
END LOOP;
-- Layer not found
IF NOT ok THEN
RAISE EXCEPTION 'No layer registered on %.%.%',
schema,tbl,col;
END IF;
-- Clean up the topology schema
FOR rec IN SELECT * FROM pg_namespace
WHERE text(nspname) = lyrinfo.toponame
LOOP
-- Cleanup the relation table
EXECUTE 'DELETE FROM ' || quote_ident(lyrinfo.toponame)
|| '.relation '
|| ' WHERE '
|| 'layer_id = ' || lyrinfo.layer_id;
-- Drop the sequence for topogeoms in this layer
EXECUTE 'DROP SEQUENCE ' || quote_ident(lyrinfo.toponame)
|| '.topogeo_s_' || lyrinfo.layer_id;
END LOOP;
ok = false;
FOR rec IN SELECT * FROM pg_namespace n, pg_class c, pg_attribute a
WHERE text(n.nspname) = schema
AND c.relnamespace = n.oid
AND text(c.relname) = tbl
AND a.attrelid = c.oid
AND text(a.attname) = col
LOOP
ok = true;
EXIT;
END LOOP;
IF ok THEN
-- Set feature column to NULL to bypass referential integrity
-- checks
EXECUTE 'UPDATE ' || quote_ident(schema) || '.'
|| quote_ident(tbl)
|| ' SET ' || quote_ident(col)
|| ' = NULL';
END IF;
-- Delete the layer record
EXECUTE 'DELETE FROM topology.layer '
|| ' WHERE topology_id = ' || lyrinfo.topology_id
|| ' AND layer_id = ' || lyrinfo.layer_id;
IF ok THEN
-- Drop the layer column
EXECUTE 'ALTER TABLE ' || quote_ident(schema) || '.'
|| quote_ident(tbl)
|| ' DROP ' || quote_ident(col)
|| ' cascade';
END IF;
result = 'Layer ' || lyrinfo.layer_id || ' ('
|| schema || '.' || tbl || '.' || col
|| ') dropped';
RETURN result;
END;
$$
LANGUAGE 'plpgsql' VOLATILE;
--
--} DropTopoGeometryColumn
--{
-- CreateTopoGeom(topology_name, topogeom_type, layer_id, elements)
--
-- Create a TopoGeometry object from Topology elements.
-- The elements parameter is a two-dimensional array.
-- Every element of the array is either a Topology element represented by
-- (id, type) or a TopoGeometry element represented by (id, layer).
-- The actual semantic depends on the TopoGeometry layer, either at
-- level 0 (elements are topological primitives) or higer (elements
-- are TopoGeoms from child layer).
--
-- @param toponame Topology name
--
-- @param tg_type Spatial type of geometry
-- 1:[multi]point (puntal)
-- 2:[multi]line (lineal)
-- 3:[multi]poly (areal)
-- 4:collection (mixed)
--
-- @param layer_id Layer identifier
--
-- @param tg_objs Array of components
--
-- Return a topology.TopoGeometry object.
--
CREATE OR REPLACE FUNCTION topology.CreateTopoGeom(toponame varchar, tg_type integer, layer_id integer, tg_objs topology.TopoElementArray)
RETURNS topology.TopoGeometry
AS
$$
DECLARE
i integer;
dims varchar;
outerdims varchar;
innerdims varchar;
obj_type integer;
obj_id integer;
ret topology.TopoGeometry;
rec RECORD;
layertype integer;
layerlevel integer;
layerchild integer;
BEGIN
IF tg_type < 1 OR tg_type > 4 THEN
RAISE EXCEPTION 'Invalid TopoGeometry type % (must be in the range 1..4)', tg_type;
END IF;
-- Get topology id into return TopoGeometry
SELECT id FROM topology.topology into ret.topology_id
WHERE name = toponame;
--
-- Get layer info
--
layertype := NULL;
FOR rec IN EXECUTE 'SELECT * FROM topology.layer'
|| ' WHERE topology_id = ' || ret.topology_id
|| ' AND layer_id = ' || layer_id
LOOP
layertype = rec.feature_type;
layerlevel = rec.level;
layerchild = rec.child_id;
END LOOP;
-- Check for existence of given layer id
IF layertype IS NULL THEN
RAISE EXCEPTION 'No layer with id % is registered with topology %', layer_id, toponame;
END IF;
-- Verify compatibility between layer geometry type and
-- TopoGeom requested geometry type
IF layertype != 4 and layertype != tg_type THEN
RAISE EXCEPTION 'A Layer of type % cannot contain a TopoGeometry of type %', layertype, tg_type;
END IF;
-- Set layer id and type in return object
ret.layer_id = layer_id;
ret.type = tg_type;
--
-- Get new TopoGeo id from sequence
--
FOR rec IN EXECUTE 'SELECT nextval(' ||
quote_literal(
quote_ident(toponame) || '.topogeo_s_' || layer_id
) || ')'
LOOP
ret.id = rec.nextval;
END LOOP;
-- Loop over outer dimension
i = array_lower(tg_objs, 1);
LOOP
obj_id = tg_objs[i][1];
obj_type = tg_objs[i][2];
-- Elements of type 0 represent emptiness, just skip them
IF obj_type = 0 THEN
IF obj_id != 0 THEN
RAISE EXCEPTION 'Malformed empty topo element {0,%} -- id must be 0 as well', obj_id;
END IF;
ELSE
IF layerlevel = 0 THEN -- array specifies lower-level objects
IF tg_type != 4 and tg_type != obj_type THEN
RAISE EXCEPTION 'A TopoGeometry of type % cannot contain topology elements of type %', tg_type, obj_type;
END IF;
ELSE -- array specifies lower-level topogeometries
IF obj_type != layerchild THEN
RAISE EXCEPTION 'TopoGeom element layer do not match TopoGeom child layer';
END IF;
-- TODO: verify that the referred TopoGeometry really
-- exists in the relation table ?
END IF;
--RAISE NOTICE 'obj:% type:% id:%', i, obj_type, obj_id;
--
-- Insert record into the Relation table
--
EXECUTE 'INSERT INTO '||quote_ident(toponame)
|| '.relation(topogeo_id, layer_id, '
|| 'element_id,element_type) '
|| ' VALUES ('||ret.id
||','||ret.layer_id
|| ',' || obj_id || ',' || obj_type || ');';
END IF;
i = i+1;
IF i > array_upper(tg_objs, 1) THEN
EXIT;
END IF;
END LOOP;
RETURN ret;
END
$$
LANGUAGE 'plpgsql' VOLATILE STRICT;
--} CreateTopoGeom(toponame,topogeom_type, layer_id, TopoElementArray)
--{
-- CreateTopoGeom(topology_name, topogeom_type, layer_id) - creates the empty topogeom
CREATE OR REPLACE FUNCTION topology.CreateTopoGeom(toponame varchar, tg_type integer, layer_id integer)
RETURNS topology.TopoGeometry
AS
$$
SELECT topology.CreateTopoGeom($1,$2,$3,'{{0,0}}');
$$ LANGUAGE 'sql' VOLATILE STRICT;
--} CreateTopoGeom(toponame, topogeom_type, layer_id)
--{
-- GetTopologyName(topology_id)
--
-- TODO: rewrite in SQL ?
--
CREATE OR REPLACE FUNCTION topology.GetTopologyName(topoid integer)
RETURNS varchar
AS
$$
DECLARE
ret varchar;
BEGIN
SELECT name FROM topology.topology into ret
WHERE id = topoid;
RETURN ret;
END
$$
LANGUAGE 'plpgsql' STABLE STRICT;
--} GetTopologyName(topoid)
--{
-- GetTopologyId(toponame)
--
-- TODO: rewrite in SQL ?
--
CREATE OR REPLACE FUNCTION topology.GetTopologyId(toponame varchar)
RETURNS integer
AS
$$
DECLARE
ret integer;
BEGIN
SELECT id FROM topology.topology into ret
WHERE name = toponame;
RETURN ret;
END
$$