├── .gitignore
├── 01-ast_postgis.sql
├── CHANGELOG.md
├── Dockerfile
├── META.json
├── Makefile
├── README.md
├── ast_postgis.control
├── doc
├── INSTALL
└── LICENSE
├── examples
├── transportation_system
│ ├── ddl.sql
│ ├── schema.png
│ └── transportation_system.xml
└── urban_system
│ ├── ddl.sql
│ ├── schema.png
│ └── urban_system.xml
├── install-ast_postgis-15.bat
├── install-ast_postgis-16.bat
├── install-ast_postgis-17.bat
├── sql
├── consistency_functions.sql
├── domain_functions.sql
├── domains.sql
├── event_triggers.sql
├── postgis.sql
├── relationship_triggers.sql
├── tables.sql
├── type_functions.sql
├── types.sql
└── utils.sql
└── tests
├── aggregationTest.sql
├── arcarcTest.sql
├── arcnodeTest.sql
├── containsTest.sql
├── crossesTest.sql
├── disjointTest.sql
├── distantTest.sql
├── intersectsTest.sql
├── isolinesTest.sql
├── lineTest.sql
├── nearTest.sql
├── planarsubdivisionTest.sql
├── polygonTest.sql
├── touchesTest.sql
└── withinTest.sql
/.gitignore:
--------------------------------------------------------------------------------
1 | *.DS_Store
2 | .AppleDouble
3 | .LSOverride
4 |
5 | # Icon must end with two \r
6 | Icon
7 |
8 |
9 | # Thumbnails
10 | ._*
11 |
12 | # Files that might appear in the root of a volume
13 | .DocumentRevisions-V100
14 | .fseventsd
15 | .Spotlight-V100
16 | .TemporaryItems
17 | .Trashes
18 | .VolumeIcon.icns
19 | .com.apple.timemachine.donotpresent
20 |
21 | # Directories potentially created on remote AFP share
22 | .AppleDB
23 | .AppleDesktop
24 | Network Trash Folder
25 | Temporary Items
26 | .apdisk
27 |
28 | *~
29 |
30 | # temporary files which can be created if a process still has a handle open of a deleted file
31 | .fuse_hidden*
32 |
33 | # KDE directory preferences
34 | .directory
35 |
36 | # Linux trash folder which might appear on any partition or disk
37 | .Trash-*
38 |
39 | # Postgres extension result file
40 | ast_postgis--*.sql
41 |
--------------------------------------------------------------------------------
/01-ast_postgis.sql:
--------------------------------------------------------------------------------
1 | CREATE EXTENSION IF NOT EXISTS ast_postgis;
2 |
--------------------------------------------------------------------------------
/CHANGELOG.md:
--------------------------------------------------------------------------------
1 | # Changelog
2 |
3 | All notable changes to this project is documented in this file.
4 |
5 | ## September 05, 2024
6 | ### New functionalities
7 |
8 | - Postgres 16 is now supported.
9 |
10 | ## March 27, 2024
11 | ### New functionalities
12 |
13 | - `AST_LINE` is now mapped to a `multilinestring` geometry type in PostGIS.
14 | - `AST_POLYGON` and `AST_PLANARSUBDIVISION` are now mapped to a `multipolygon` geometry type in PostGIS.
15 |
16 | ## June 26, 2023
17 | ### New functionalities
18 |
19 | - Postgres 15 is now supported.
20 | - `ast_topologicalrelationship` procedure is now named `ast_spatialrelationship`
21 |
--------------------------------------------------------------------------------
/Dockerfile:
--------------------------------------------------------------------------------
1 | FROM camptocamp/postgis:9.5
2 |
3 |
4 | WORKDIR /postgis_omtg
5 | COPY . /postgis_omtg/
6 | COPY 01-ast_postgis.sql /docker-entrypoint-initdb.d/
7 |
8 | RUN printf "deb http://archive.debian.org/debian/ jessie main\ndeb-src http://archive.debian.org/debian/ jessie main\ndeb http://security.debian.org jessie/updates main\ndeb-src http://security.debian.org jessie/updates main" > /etc/apt/sources.list \
9 | && apt-get update \
10 | && apt-get install --no-install-recommends -y make postgresql-server-dev-9.5 \
11 | && make \
12 | && make install \
13 | && apt-get remove -y --purge make postgresql-server-dev-9.5 \
14 | && apt-get autoremove -y \
15 | && apt-get clean -y
16 |
17 | EXPOSE 5432
18 |
--------------------------------------------------------------------------------
/META.json:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/lizardoluis/ast_postgis/a7b71d3b350cd7c12dfb574ea886bd14c870ce6c/META.json
--------------------------------------------------------------------------------
/Makefile:
--------------------------------------------------------------------------------
1 | EXTENSION = ast_postgis
2 | EXTVERSION = $(shell grep default_version $(EXTENSION).control | \
3 | sed -e "s/default_version[[:space:]]*=[[:space:]]*'\([^']*\)'/\1/")
4 | DOCS = $(wildcard doc/*)
5 | # TESTS = $(wildcard test/sql/*.sql)
6 | # MODULES = $(patsubst %.c,%,$(wildcard src/*.c))
7 | REGRESS = $(patsubst test/sql/%.sql,%,$(TESTS))
8 | REGRESS_OPTS = --inputdir=test
9 | PG_CONFIG = pg_config
10 |
11 | all: sql/$(EXTENSION)--$(EXTVERSION).sql
12 |
13 | sql/$(EXTENSION)--$(EXTVERSION).sql: $(strip sql/tables.sql \
14 | sql/types.sql \
15 | sql/type_functions.sql \
16 | sql/utils.sql \
17 | sql/domain_functions.sql \
18 | sql/domains.sql \
19 | sql/relationship_triggers.sql \
20 | sql/event_triggers.sql \
21 | sql/consistency_functions.sql \
22 | )
23 | cat $^ > $@
24 |
25 | DATA = sql/$(EXTENSION)--$(EXTVERSION).sql
26 | EXTRA_CLEAN = sql/$(EXTENSION)--$(EXTVERSION).sql
27 | PGXS := $(shell $(PG_CONFIG) --pgxs)
28 | include $(PGXS)
29 |
--------------------------------------------------------------------------------
/README.md:
--------------------------------------------------------------------------------
1 | AST-PostGIS
2 | ===========
3 |
4 | The AST-PostGIS is an extension for PostgreSQL/PostGIS that incorporates advanced spatial data types and implements spatial integrity constraints. The extension reduces the distance between the conceptual and the physical designs of spatial databases, by providing richer representations for geo-object and geo-field geometries. It also offers procedures to assert the consistency of spatial relationships during data updates. Such procedures can also be used before enforcing spatial integrity constraints for the first time.
5 |
6 | Motivation
7 | ----------
8 |
9 | Geometric primitives defined by OGC and ISO standards, implemented in most modern spatially-enabled database management systems (DBMS), are unable to capture the semantics of richer representation types, as found in current geographic data models. Moreover, relational DBMSs do not extend referential integrity mechanisms to cover spatial relationships and to support spatial integrity constraints. Rather, they usually assume that all spatial integrity checking will be carried out by the application, during the data entry process. This is not practical if the DBMS supports many applications, and can lead to redundant work.
10 |
11 |
12 | Compatibility
13 | =============
14 |
15 | This module has been tested on:
16 |
17 | * **Postgres 15**
18 | * **PostGIS 2.2**
19 |
20 | And requires the extensions:
21 |
22 | * **postgis**
23 |
24 |
25 | Build and Install
26 | =================
27 |
28 | ## From source ##
29 |
30 | If you aren't using the `pg_config` on your path (or don't have it on your path), specify the correct one to build against:
31 |
32 | PG_CONFIG=/Library/PostgreSQL/9.5/bin/pg_config make
33 |
34 | Or to build with what's on your path, just:
35 |
36 | make
37 |
38 | Then install:
39 |
40 | sudo make install
41 |
42 | After you've built and installed the artifacts, fire up `psql`:
43 |
44 | postgres=# CREATE EXTENSION ast_postgis;
45 |
46 | ## Docker ##
47 |
48 | Use the pre-builded docker with:
49 |
50 | ```
51 | docker run -v ${HOME}/pgdata:/var/lib/postgresql/data --net=host gabrielmcf/ast_postgis:9.5-2.2-1.0
52 | ```
53 |
54 | Build the docker using:
55 |
56 | ```
57 | docker build --rm -f Dockerfile -t ast_postgis:9.5-2.2-1.0 .
58 | ```
59 |
60 | Run the server using:
61 |
62 | ```
63 | docker run -v ${HOME}/pgdata:/var/lib/postgresql/data --net=host ast_postgis:9.5-2.2-1.0
64 | ```
65 |
66 | ## On Windows ##
67 |
68 | Execute `install-ast_postgis.bat` as administrator.
69 | You'll be prompted for your username, password and database name.
70 |
71 | Usage
72 | =====
73 |
74 | Here is explained how the extension works.
75 |
76 |
77 | Advanced Spatial Data Types
78 | ---------------------------
79 |
80 | Advanced Spatial Types are essentially the primitive geometric types of PostGIS together with a set of spatial integrity constraints to control their behavior. These new spatial data types can be handled in the same way the primitive types are, as they can be employed as column definition of tables, as variables in PL/pgSQL scripts or as arguments of functions or stored procedures. They can also be stored, retrieved and updated with the geometry processing functions of PostGIS.
81 |
82 | The following table shows the eleven advanced spatial data types implemented by the extension and how they are mapped to the PostGIS types. These types are derived from the concepts of geo-objects and geo-fields classes of the [OMT-G data model](http://link.springer.com/article/10.1023/A:1011482030093).
83 |
84 |
85 |
86 | Spatial Class |
87 | Advanced spatial datatypes |
88 | PostGIS Type |
89 |
90 |
91 | Polygon |
92 | ast_polygon |
93 | geometry(multipolygon) |
94 |
95 |
96 | Line |
97 | ast_line |
98 | geometry(multilinestring) |
99 |
100 |
101 | Point |
102 | ast_point |
103 | geometry(point) |
104 |
105 |
106 | Node |
107 | ast_node |
108 | geometry(point) |
109 |
110 |
111 | Isoline |
112 | ast_isoline |
113 | geometry(linestring) |
114 |
115 |
116 | Planar subdivision |
117 | ast_planarsubdivision |
118 | geometry(multipolygon) |
119 |
120 |
121 | Triangular Irregular Network (TIN) |
122 | ast_tin |
123 | geometry(polygon) |
124 |
125 |
126 | Tesselation |
127 | ast_tesselation |
128 | raster |
129 |
130 |
131 | Sample |
132 | ast_sample |
133 | geometry(point) |
134 |
135 |
136 | Unidirectional line |
137 | ast_uniline |
138 | geometry(linestring) |
139 |
140 |
141 | Bidirectional line |
142 | ast_biline |
143 | geometry(linestring) |
144 |
145 |
146 |
147 |
148 | Trigger procedures for relationship integrity constraints
149 | ---------------------------------------------------------
150 |
151 | The following procedures can be called by triggers to assert the consistency of spatial relationships, like topological relationship, arc-node and arc-arc networks or spatial aggregation.
152 |
153 |
154 |
155 | Spatial Relationship |
156 | Trigger Procedure |
157 |
158 |
159 | Topological Relationship |
160 | ast_spatialrelationship(a_tbl, a_geom, b_tbl, b_geom, spatial_relation) |
161 |
162 |
163 | Topological Relationship (distant, near) |
164 | ast_spatialrelationship(a_tbl, a_geom, b_tbl, b_geom, spatial_relation, distance) |
165 |
166 |
167 | Arc-Node Network |
168 | ast_arcnodenetwork(arc_tbl, arc_geom, node_tbl, node_geom) |
169 |
170 |
171 | Arc-Arc Network |
172 | ast_arcnodenetwork(arc_tbl, arc_geom) |
173 |
174 |
175 | Spatial Aggregation |
176 | ast_aggregation(part_tbl, part_geom, whole_tbl, whole_geom) |
177 |
178 |
179 |
180 | The `spatial_relation` argument, which are passed as an argument to the topological relationship procedure, can be one of the following:
181 |
182 | * contains
183 | * containsproperly
184 | * covers
185 | * coveredby
186 | * crosses
187 | * disjoint
188 | * distant
189 | * intersects
190 | * near
191 | * overlaps
192 | * touches
193 | * within
194 |
195 |
196 | Consistency check functions
197 | ---------------------------
198 |
199 | The SQL functions listed in this section can be called to analyze the consistency of the spatial database before the initial enforcement of constraints. These functions return the state of the database (`true` = valid, `false` = invalid) and register, in the `ast_validation_log` table, the details of each inconsistency encountered.
200 |
201 |
202 |
203 | Spatial Relationship |
204 | Check functions |
205 |
206 |
207 | Topological Relationship |
208 | ast_isTopologicalRelationshipValid(a_tbl text, a_geom text, b_tbl text, b_geom text, relation text) |
209 |
210 |
211 | Topological Relationship (near) |
212 | ast_isTopologicalRelationshipValid(a_tbl text, a_geom text, b_tbl text, b_geom text, dist real) |
213 |
214 |
215 | Arc-Node Network |
216 | ast_isNetworkValid(arc_tbl text, arc_geom text, node_tbl text, node_geom text) |
217 |
218 |
219 | Arc-Arc Network |
220 | ast_isNetworkValid(arc_tbl text, arc_geom text) |
221 |
222 |
223 | Spatial Aggregation |
224 | ast_isSpatialAggregationValid(part_tbl text, part_geom text, whole_tbl text, whole_geom text) |
225 |
226 |
227 |
228 |
229 | Use Case
230 | ========
231 |
232 | This section shows an use case example (also available in the `examples` folder) intended to clarify the use of this extension.
233 |
234 | Transportation system
235 | ---------------------
236 |
237 | The following figure shows a schema fragment for a bus transportation network (nodes at bus stops and unidirectional arcs corresponding to route segments) that serves a set of school districts. A conventional class holds the attributes for the bus line. The schema embeds spatial integrity constraints for (1) the network relationship (each route segment must be related to two bus stops), (2) a “contains” relationship (school district cannot exists without a bus stop), and (3) the geometry of route segments and school districts (lines and polygons must be simple, i.e., with no self-intersections).
238 |
239 |
240 |
241 | The implementation of this schema that uses the `ast_postgis` extension and considers all the spatial constraints is as follows:
242 |
243 | create table bus_line (
244 | line_number integer primary key,
245 | description varchar(50),
246 | operator varchar(50)
247 | );
248 |
249 | create table school_district (
250 | district_name varchar(50) primary key,
251 | school_capacity integer,
252 | geom ast_polygon
253 | );
254 |
255 | create table bus_stop (
256 | stop_id integer primary key,
257 | shelter_type varchar(50),
258 | geom ast_point
259 | );
260 |
261 | create table bus_route_segment (
262 | traverse_time real,
263 | segment_number integer,
264 | busline integer references bus_line (line_number),
265 | geom ast_uniline
266 | );
267 |
268 | -- school_district and bus_stop topological relationship constraints:
269 | create trigger school_district_contains_trigger
270 | after insert or update on school_district
271 | for each statement
272 | execute procedure ast_spatialrelationship('school_district', 'geom', 'bus_stop', 'geom', 'contains');
273 |
274 | -- bus_route_segment and bus_stop arc-node network constraints:
275 | create trigger busroute_insert_update_trigger
276 | after insert or update on bus_route_segment
277 | for each statement
278 | execute procedure ast_arcnodenetwork('bus_route_segment', 'geom', 'bus_stop', 'geom');
279 |
280 |
281 | License and Copyright
282 | =====================
283 |
284 | AST-PostGIS is released under a [MIT license](doc/LICENSE).
285 |
286 | Copyright (c) 2016 Luís Eduardo Oliveira Lizardo.
287 |
288 |
289 | References
290 | ----------
291 |
292 | [1] K. A. V. Borges, C. A. Davis Jr., and A. H. F. Laender. OMT-G: an object-oriented data model for geographic applications. GeoInformatica, 5(3):221–260, 2001.
293 |
294 | [2] L. E. O. Lizardo and C. A. Davis Jr. OMT-G Designer: a web tool for modeling geographic databases in OMT-G. In Advances in Conceptual Modeling: 33rd International Conference on Conceptual Modeling, ER 2014, volume 8823 of Lecture Notes in Computer Science, pages 228–233. Springer International Publishing, 2014.
295 |
296 | [3] Lizardo, L. E. O., & Davis Jr, C. A. (2017, November). A PostGIS extension to support advanced spatial data types and integrity constraints. In Proceedings of the 25th ACM SIGSPATIAL International Conference on Advances in Geographic Information Systems (pp. 1-10).
297 |
--------------------------------------------------------------------------------
/ast_postgis.control:
--------------------------------------------------------------------------------
1 | # Advanced spatial data types and spatial integrity constraints for PostGIS.
2 | comment = 'Advanced spatial data types and spatial integrity constraints for PostGIS.'
3 | default_version = '1.1.1'
4 | module_pathname = '$libdir/ast_postgis'
5 | relocatable = true
6 | requires = 'postgis'
7 |
--------------------------------------------------------------------------------
/doc/INSTALL:
--------------------------------------------------------------------------------
1 | ## From source ##
2 |
3 | If you aren't using the `pg_config` on your path (or don't have it on your path), specify the correct one to build against:
4 |
5 | PG_CONFIG=/Library/PostgreSQL/9.5/bin/pg_config make
6 |
7 | Or to build with what's on your path, just:
8 |
9 | make
10 |
11 | Then install:
12 |
13 | sudo make install
14 |
15 | After you've built and installed the artifacts, fire up `psql`:
16 |
17 | postgres=# CREATE EXTENSION ast_postgis;
18 | CREATE EXTENSION
19 |
--------------------------------------------------------------------------------
/doc/LICENSE:
--------------------------------------------------------------------------------
1 | The MIT License (MIT)
2 |
3 | Copyright (c) 2016 Luis Eduardo Oliveira Lizardo
4 |
5 | Permission is hereby granted, free of charge, to any person obtaining a copy
6 | of this software and associated documentation files (the "Software"), to deal
7 | in the Software without restriction, including without limitation the rights
8 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell
9 | copies of the Software, and to permit persons to whom the Software is
10 | furnished to do so, subject to the following conditions:
11 |
12 | The above copyright notice and this permission notice shall be included in all
13 | copies or substantial portions of the Software.
14 |
15 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR
16 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY,
17 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE
18 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER
19 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM,
20 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE
21 | SOFTWARE.
22 |
--------------------------------------------------------------------------------
/examples/transportation_system/ddl.sql:
--------------------------------------------------------------------------------
1 | --
2 | -- TRANSPORTATION SYSTEM
3 | --
4 |
5 | -- Tables creation
6 | create table bus_line (
7 | line_number integer primary key,
8 | description varchar(50),
9 | operator varchar(20)
10 | );
11 |
12 | create table school_district (
13 | district_name varchar(50) primary key,
14 | school_capacity integer,
15 | geom ast_polygon
16 | );
17 |
18 | create table bus_stop (
19 | stop_id integer primary key,
20 | shelter_type varchar(50),
21 | geom ast_node
22 | );
23 |
24 | create table bus_route_segment (
25 | traverse_time time,
26 | segment_number integer,
27 | busline integer references bus_line (line_number),
28 | geom ast_uniline
29 | );
30 |
31 | --
32 | -- School_district and bus_stop topological relationship constraints.
33 | --
34 | CREATE TRIGGER school_district_contains_trigger
35 | AFTER INSERT OR UPDATE ON school_district
36 | FOR EACH STATEMENT
37 | EXECUTE PROCEDURE ast_spatialrelationship('school_district', 'geom', 'bus_stop', 'geom', 'contains');
38 |
39 | --
40 | -- Bus_route_segment and Bus_stop arc-node network constraints
41 | --
42 | CREATE TRIGGER busroute_insert_update_trigger
43 | AFTER INSERT OR UPDATE ON bus_route_segment
44 | FOR EACH STATEMENT
45 | EXECUTE PROCEDURE ast_arcnodenetwork('bus_route_segment', 'geom', 'bus_stop', 'geom');
46 |
--------------------------------------------------------------------------------
/examples/transportation_system/schema.png:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/lizardoluis/ast_postgis/a7b71d3b350cd7c12dfb574ea886bd14c870ce6c/examples/transportation_system/schema.png
--------------------------------------------------------------------------------
/examples/transportation_system/transportation_system.xml:
--------------------------------------------------------------------------------
1 | Bus_Line115141conventionalLine_numberINTEGERtrueDescriptionVARCHAR50OperatorVARCHAR20Bus_Route_Segment383143un-lineTraverse_timeTIMESegment_NumberINTEGERBus_Stop384500nodeStop_IDINTEGERtrueShelter_typeVARCHAR50School_District119497polygonDistrict_nameVARCHARtrue50School_CapacityINTEGERIncludesBus_Line11Bus_Route_Segment1*ContainsSchool_District11Bus_Stop1*networkBus_Route_SegmentBus_Stop
--------------------------------------------------------------------------------
/examples/urban_system/ddl.sql:
--------------------------------------------------------------------------------
1 | --
2 | -- URBAN SYSTEM
3 | --
4 |
5 |
6 | -- Tables creation
7 | CREATE TABLE City (
8 | id integer PRIMARY KEY,
9 | name varchar(50),
10 | geom_point ast_point,
11 | geom_boundary ast_polygon
12 | );
13 |
14 | CREATE TABLE Relief (
15 | altitude integer,
16 | geom ast_isoline
17 | );
18 |
19 | CREATE TABLE Block (
20 | zoning_type varchar(50),
21 | geom ast_polygon
22 | );
23 |
24 | CREATE TABLE Parcel (
25 | id integer PRIMARY KEY,
26 | size integer,
27 | geom ast_polygon
28 | );
29 |
30 | CREATE TABLE Industry (
31 | name varchar(50) PRIMARY KEY,
32 | production_type varchar(50),
33 | geom ast_point
34 | );
35 |
36 | CREATE TABLE Nature_Reserve (
37 | name varchar(50) PRIMARY KEY,
38 | geom ast_polygon
39 | );
40 |
41 | CREATE TABLE Neighborhood (
42 | id integer PRIMARY KEY,
43 | name varchar(50),
44 | geom ast_planarsubdivision
45 | );
46 |
47 | CREATE TABLE Thoroughfare (
48 | name varchar(50) PRIMARY KEY,
49 | speed_limit integer
50 | );
51 |
52 | CREATE TABLE Address (
53 | number integer,
54 | thoroughfare varchar(50)
55 | REFERENCES Thoroughfare(name),
56 | geom ast_point
57 | );
58 |
59 | CREATE TABLE Street_Segment (
60 | paviment varchar(50),
61 | thoroughfare varchar(50)
62 | REFERENCES Thoroughfare(name),
63 | geom ast_biline
64 | );
65 |
66 | CREATE TABLE Crossing (
67 | geom ast_node
68 | );
69 |
70 | --
71 | -- Spatial aggregation between Block and Parcel
72 | --
73 | CREATE TRIGGER Aggr_Block_Parcel
74 | AFTER INSERT OR UPDATE OR DELETE ON Parcel
75 | FOR EACH STATEMENT EXECUTE PROCEDURE
76 | ast_aggregation('Parcel', 'geom', 'Block', 'geom');
77 |
78 | --
79 | -- Spatial aggregation between City and Neighborhood
80 | --
81 | CREATE TRIGGER Aggr_Boundary_Neighborhood
82 | AFTER INSERT OR UPDATE OR DELETE ON Neighborhood
83 | FOR EACH STATEMENT EXECUTE PROCEDURE
84 | ast_aggregation('Neighborhood', 'geom', 'City', 'geom_boundary');
85 |
86 | --
87 | -- Topological relationship between Industry and Parcel
88 | --
89 | CREATE TRIGGER Industry_Parcel_Within
90 | AFTER INSERT OR UPDATE ON Industry
91 | FOR EACH STATEMENT EXECUTE PROCEDURE
92 | ast_spatialrelationship('Industry', 'geom', 'Parcel', 'geom', 'within');
93 |
94 | --
95 | -- Topological relationship between Block and City
96 | --
97 | CREATE TRIGGER Block_City_Boundary_Within
98 | AFTER INSERT OR UPDATE ON Block
99 | FOR EACH STATEMENT EXECUTE PROCEDURE
100 | ast_spatialrelationship('Block', 'geom', 'City', 'geom_boundary', 'within');
101 |
102 | --
103 | -- Topological relationship between Parcel and Address
104 | --
105 | CREATE TRIGGER Parcel_Address_Contains
106 | AFTER INSERT OR UPDATE ON Parcel
107 | FOR EACH STATEMENT EXECUTE PROCEDURE
108 | ast_spatialrelationship('Parcel', 'geom', 'Address', 'geom', 'contains');
109 |
110 | --
111 | -- Topological relationship between Nature_Reserve and Industry
112 | --
113 | CREATE TRIGGER Nature_Reserve_Industry_Distant
114 | AFTER INSERT OR UPDATE ON Nature_Reserve
115 | FOR EACH STATEMENT EXECUTE PROCEDURE
116 | ast_spatialrelationship('Nature_Reserve', 'geom', 'Industry', 'geom', 'distant', '800');
117 |
118 | --
119 | -- Arc-Node network between Street_Segment and Crossing
120 | --
121 | CREATE TRIGGER Street_Segment_Crossing_network
122 | AFTER INSERT OR UPDATE ON Street_Segment
123 | FOR EACH STATEMENT EXECUTE PROCEDURE
124 | ast_arcnodenetwork('Street_Segment', 'geom', 'Crossing', 'geom');
125 |
--------------------------------------------------------------------------------
/examples/urban_system/schema.png:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/lizardoluis/ast_postgis/a7b71d3b350cd7c12dfb574ea886bd14c870ce6c/examples/urban_system/schema.png
--------------------------------------------------------------------------------
/examples/urban_system/urban_system.xml:
--------------------------------------------------------------------------------
1 | City24348conventionalidINTEGERtruetruenameVARCHARtrueCity_Point241194pointCity_Boundary244470polygonNeighbourhood370191planar-subdivisionidINTEGERtruenameVARCHARBlock243899polygonzoning_typeVARCHARParcel5231005polygonidINTEGERtruesizeINTEGERCrossing536192nodeStreet_Segment535457bi-linepavimentVARCHARThoroughfare350451conventionalnameVARCHARtruespeed_limitINTEGERAddress536654pointnumberINTEGERNature_Reserve1181202polygonnameVARCHARtrueIndustry4701290pointnameVARCHARtrueproduction_typeVARCHARRelief83753isolinesaltitudeINTEGERCityscaleoverlappingCity_PointCity_BoundaryCity_BoundaryNeighbourhoodBlockParcelStreet NetworkCrossingStreet_SegmentThoroughfareStreet_SegmentWithinBlock0*City_Boundary11ContainsParcel11Address1*Distant800Nature_Reserve0*Industry0*belongs toAddress0*Thoroughfare11WithinIndustry0*Parcel11
--------------------------------------------------------------------------------
/install-ast_postgis-15.bat:
--------------------------------------------------------------------------------
1 | @echo off
2 | set /p PGUSER="Insert the username for PostgreSQL: "
3 | set /p PGPASSWORD="Insert the password for PostgreSQL: "
4 | set /p PGDATABASE="Insert the schema name to each ast_postgis should be installed: "
5 |
6 |
7 | echo "Enabling the extension PostGIS"
8 |
9 | "C:/Program Files/PostgreSQL/15/bin/psql.exe" -h localhost < "%~dp0\sql\postgis.sql"
10 |
11 | echo "Installing the ast_postgis."
12 |
13 | "C:/Program Files/PostgreSQL/15/bin/psql.exe" -h localhost < "%~dp0\sql\tables.sql"
14 | "C:/Program Files/PostgreSQL/15/bin/psql.exe" -h localhost < "%~dp0\sql\types.sql"
15 | "C:/Program Files/PostgreSQL/15/bin/psql.exe" -h localhost < "%~dp0\sql\type_functions.sql"
16 | "C:/Program Files/PostgreSQL/15/bin/psql.exe" -h localhost < "%~dp0\sql\utils.sql"
17 | "C:/Program Files/PostgreSQL/15/bin/psql.exe" -h localhost < "%~dp0\sql\domain_functions.sql"
18 | "C:/Program Files/PostgreSQL/15/bin/psql.exe" -h localhost < "%~dp0\sql\domains.sql"
19 | "C:/Program Files/PostgreSQL/15/bin/psql.exe" -h localhost < "%~dp0\sql\relationship_triggers.sql"
20 | "C:/Program Files/PostgreSQL/15/bin/psql.exe" -h localhost < "%~dp0\sql\event_triggers.sql"
21 | "C:/Program Files/PostgreSQL/15/bin/psql.exe" -h localhost < "%~dp0\sql\consistency_functions.sql"
22 |
23 | pause
--------------------------------------------------------------------------------
/install-ast_postgis-16.bat:
--------------------------------------------------------------------------------
1 | @echo off
2 | set /p PGUSER="Insert the username for PostgreSQL: "
3 | set /p PGPASSWORD="Insert the password for PostgreSQL: "
4 | set /p PGDATABASE="Insert the schema name to each ast_postgis should be installed: "
5 |
6 |
7 | echo "Enabling the extension PostGIS"
8 |
9 | "C:/Program Files/PostgreSQL/16/bin/psql.exe" -h localhost < "%~dp0\sql\postgis.sql"
10 |
11 | echo "Installing the ast_postgis."
12 |
13 | "C:/Program Files/PostgreSQL/16/bin/psql.exe" -h localhost < "%~dp0\sql\tables.sql"
14 | "C:/Program Files/PostgreSQL/16/bin/psql.exe" -h localhost < "%~dp0\sql\types.sql"
15 | "C:/Program Files/PostgreSQL/16/bin/psql.exe" -h localhost < "%~dp0\sql\type_functions.sql"
16 | "C:/Program Files/PostgreSQL/16/bin/psql.exe" -h localhost < "%~dp0\sql\utils.sql"
17 | "C:/Program Files/PostgreSQL/16/bin/psql.exe" -h localhost < "%~dp0\sql\domain_functions.sql"
18 | "C:/Program Files/PostgreSQL/16/bin/psql.exe" -h localhost < "%~dp0\sql\domains.sql"
19 | "C:/Program Files/PostgreSQL/16/bin/psql.exe" -h localhost < "%~dp0\sql\relationship_triggers.sql"
20 | "C:/Program Files/PostgreSQL/16/bin/psql.exe" -h localhost < "%~dp0\sql\event_triggers.sql"
21 | "C:/Program Files/PostgreSQL/16/bin/psql.exe" -h localhost < "%~dp0\sql\consistency_functions.sql"
22 |
23 | pause
--------------------------------------------------------------------------------
/install-ast_postgis-17.bat:
--------------------------------------------------------------------------------
1 | @echo off
2 | set /p PGUSER="Insert the username for PostgreSQL: "
3 | set /p PGPASSWORD="Insert the password for PostgreSQL: "
4 | set /p PGDATABASE="Insert the schema name to each ast_postgis should be installed: "
5 |
6 |
7 | echo "Enabling the extension PostGIS"
8 |
9 | "C:/Program Files/PostgreSQL/17/bin/psql.exe" -h localhost < "%~dp0\sql\postgis.sql"
10 |
11 | echo "Installing the ast_postgis."
12 |
13 | "C:/Program Files/PostgreSQL/17/bin/psql.exe" -h localhost < "%~dp0\sql\tables.sql"
14 | "C:/Program Files/PostgreSQL/17/bin/psql.exe" -h localhost < "%~dp0\sql\types.sql"
15 | "C:/Program Files/PostgreSQL/17/bin/psql.exe" -h localhost < "%~dp0\sql\type_functions.sql"
16 | "C:/Program Files/PostgreSQL/17/bin/psql.exe" -h localhost < "%~dp0\sql\utils.sql"
17 | "C:/Program Files/PostgreSQL/17/bin/psql.exe" -h localhost < "%~dp0\sql\domain_functions.sql"
18 | "C:/Program Files/PostgreSQL/17/bin/psql.exe" -h localhost < "%~dp0\sql\domains.sql"
19 | "C:/Program Files/PostgreSQL/17/bin/psql.exe" -h localhost < "%~dp0\sql\relationship_triggers.sql"
20 | "C:/Program Files/PostgreSQL/17/bin/psql.exe" -h localhost < "%~dp0\sql\event_triggers.sql"
21 | "C:/Program Files/PostgreSQL/17/bin/psql.exe" -h localhost < "%~dp0\sql\consistency_functions.sql"
22 |
23 | pause
--------------------------------------------------------------------------------
/sql/consistency_functions.sql:
--------------------------------------------------------------------------------
1 | --
2 | -- This function checks if all the elements of b_tbl is within the buffer
3 | -- distance from the elements of a_tbl.
4 | --
5 | create function ast_isSpatialRelationshipValid(a_tbl text, a_geom text, b_tbl text, b_geom text, dist real)
6 | returns boolean as $$
7 | declare
8 | pkColumn text := _ast_getPrimaryKeyColumn(b_tbl);
9 | res boolean;
10 | begin
11 |
12 | if pkColumn = '' then
13 | raise exception 'AST_isSpatialRelationshipValid function error.'
14 | using detail = 'Table passed as first parameter does not have primary key and without it is not possible to validate the topological relationship.';
15 | return false;
16 | end if;
17 |
18 | if not _ast_isOMTGDomain(a_tbl, a_geom) or not _ast_isOMTGDomain(b_tbl, b_geom) then
19 | raise exception 'AST_isSpatialRelationshipValid error! Invalid parameters.'
20 | using detail = 'Usage: SELECT ast_isSpatialRelationshipValid(a_tbl text, a_geom text, b_tbl text, b_geom text, dist real);';
21 | end if;
22 |
23 | execute 'insert into ast_violation_log (time, type, description) (
24 | select now(),
25 | ''Near buffer violation'',
26 | ''Table ´'|| b_tbl ||'´ tuple with primary key ´''|| b.'|| pkColumn ||' ||''´ is outside the buffer distance of ´'|| dist ||'´ from table ´'|| a_tbl ||'´.''
27 | from '|| b_tbl ||' b
28 | where b.'|| pkColumn ||' not in
29 | (
30 | select distinct b.'|| pkColumn ||'
31 | from '|| a_tbl ||' a, '|| b_tbl ||' b
32 | where st_dwithin(a.'|| a_geom ||', b.'|| b_geom ||', '|| dist ||')
33 | )
34 | ) returning true;' into res;
35 |
36 | if res then return false;
37 | else return true;
38 | end if;
39 | end;
40 | $$ language plpgsql;
41 |
42 |
43 |
44 | --
45 | -- This function checks if the topolotical relationship is valid.
46 | --
47 | create function ast_isSpatialRelationshipValid(a_tbl text, a_geom text, b_tbl text, b_geom text, relation text)
48 | returns boolean as $$
49 | declare
50 | pkColumn text := _ast_getPrimaryKeyColumn(a_tbl);
51 | res boolean;
52 | begin
53 |
54 | if pkColumn = '' then
55 | raise exception 'AST_isSpatialRelationshipValid function error.'
56 | using detail = 'Table passed as first parameter does not have primary key and without it is not possible to validate the topological relationship.';
57 | end if;
58 |
59 | if not _ast_isOMTGDomain(a_tbl, a_geom) or not _ast_isOMTGDomain(b_tbl, b_geom) or not _ast_isSpatialRelationship(relation) then
60 | raise exception 'AST_isSpatialRelationshipValid error! Invalid parameters.'
61 | using detail = 'Usage: SELECT ast_isSpatialRelationshipValid(a_tbl text, a_geom text, b_tbl text, b_geom text, relation text);';
62 | end if;
63 |
64 | execute 'insert into ast_violation_log (time, type, description) (
65 | select now(),
66 | ''Topological relationship violation'',
67 | ''Topological relationship ('|| relation ||') between ´'|| a_tbl ||'´ and ´'|| b_tbl ||'´ is violated by the tuple of ´'|| a_tbl ||'´ with primary key ´''|| a.'|| pkColumn ||' ||''´.''
68 | from '|| a_tbl ||' a
69 | where a.'|| pkColumn ||' not in
70 | (
71 | select distinct a.'|| pkColumn ||'
72 | from '|| a_tbl ||' a, '|| b_tbl ||' b
73 | where st_'|| relation ||'(a.'|| a_geom ||', b.'|| b_geom ||')
74 | )
75 | ) returning true;' into res;
76 |
77 | if res then return false;
78 | else return true;
79 | end if;
80 | end;
81 | $$ language plpgsql;
82 |
83 |
84 |
85 | --
86 | -- This function checks if the arc-node network is valid.
87 | --
88 | create function ast_isNetworkValid(arc_tbl text, arc_geom text, node_tbl text, node_geom text)
89 | returns boolean as $$
90 | declare
91 | pkColumn text := _ast_getPrimaryKeyColumn(arc_tbl);
92 | res1 boolean;
93 | res2 boolean;
94 | begin
95 |
96 | if pkColumn = '' then
97 | raise exception 'AST_isNetworkValid function error.'
98 | using detail = 'ARC table does not have primary key and without it is not possible to validate the network.';
99 | end if;
100 |
101 | if not _ast_isOMTGDomain(arc_tbl, arc_geom) then
102 | raise exception 'AST_isNetworkValid error! Invalid parameters.'
103 | using detail = 'Usage: SELECT ast_isNetworkValid(arc_tbl text, arc_geom text, node_tbl text, node_geom text);';
104 | end if;
105 |
106 | execute 'insert into ast_violation_log (time, type, description) (
107 | select now(),
108 | ''Arc-Node Network violation'',
109 | ''Start point of arc with primary key ´''|| '|| pkColumn ||' ||''´ does not intersect any node.''
110 | from '|| arc_tbl ||'
111 | where '|| pkColumn ||' not in (
112 | select distinct a.'|| pkColumn ||'
113 | from '|| arc_tbl ||' a, '|| node_tbl ||' n
114 | where st_intersects(st_startpoint(a.'|| arc_geom ||'), n.'|| node_geom ||')
115 | )
116 | ) returning true;' into res1;
117 |
118 | execute 'insert into ast_violation_log (time, type, description) (
119 | select now(),
120 | ''Arc-Node Network violation'',
121 | ''End point of arc with primary key ´''|| '|| pkColumn ||' ||''´ does not intersect any node.''
122 | from '|| arc_tbl ||'
123 | where '|| pkColumn ||' not in (
124 | select distinct a.'|| pkColumn ||'
125 | from '|| arc_tbl ||' a, '|| node_tbl ||' n
126 | where st_intersects(st_endpoint(a.'|| arc_geom ||'), n.'|| node_geom ||')
127 | )
128 | ) returning true;' into res2;
129 |
130 | if res1 or res2 then return false;
131 | else return true;
132 | end if;
133 | end;
134 | $$ language plpgsql;
135 |
136 |
137 |
138 | --
139 | -- This function checks if the arc-arc network is valid.
140 | --
141 | create function ast_isNetworkValid(arc_tbl text, arc_geom text)
142 | returns boolean as $$
143 | declare
144 | pkColumn text := _ast_getPrimaryKeyColumn(arc_tbl);
145 | res boolean;
146 | begin
147 |
148 | if pkColumn = '' then
149 | raise exception 'AST_isNetworkValid function error.'
150 | using detail = 'ARC table does not have primary key and without it is not possible to validate the network.';
151 | end if;
152 |
153 | if not _ast_isOMTGDomain(arc_tbl, arc_geom) then
154 | raise exception 'AST_isNetworkValid error! Invalid parameters.'
155 | using detail = 'Usage: SELECT ast_isNetworkValid(arc_tbl text, arc_geom text);';
156 | end if;
157 |
158 | execute 'insert into ast_violation_log (time, type, description) (
159 | select now(),
160 | ''Arc-Arc Network violation'',
161 | ''Arcs ´''|| a.'|| pkColumn ||' ||''´ and ´''|| b.'|| pkColumn ||' ||''´ intersect each other on middle points.''
162 | from '|| arc_tbl ||' as a, '|| arc_tbl ||' as b
163 | where a.ctid < b.ctid
164 | and st_intersects(a.'|| arc_geom ||', b.'|| arc_geom ||')
165 | and not st_intersects(st_startpoint(a.'|| arc_geom ||'), st_startpoint(b.'|| arc_geom ||'))
166 | and not st_intersects(st_startpoint(a.'|| arc_geom ||'), st_endpoint(b.'|| arc_geom ||'))
167 | and not st_intersects(st_endpoint(a.'|| arc_geom ||'), st_startpoint(b.'|| arc_geom ||'))
168 | and not st_intersects(st_endpoint(a.'|| arc_geom ||'), st_endpoint(b.'|| arc_geom ||'))
169 | ) returning true;' into res;
170 |
171 | if res then return false;
172 | else return true;
173 | end if;
174 | end;
175 | $$ language plpgsql;
176 |
177 |
178 |
179 | --
180 | -- This function checks if the spatial aggregation is valid.
181 | --
182 | create function ast_isSpatialAggregationValid(part_tbl text, part_geom text, whole_tbl text, whole_geom text)
183 | returns boolean as $$
184 | declare
185 | pkColumn text := _ast_getPrimaryKeyColumn(part_tbl);
186 | res1 boolean;
187 | res2 boolean;
188 | res3 boolean;
189 | begin
190 |
191 | if pkColumn = '' then
192 | raise exception 'AST_isSpatialAggregationValid function error.'
193 | using detail = 'PART table does not have primary key and without it is not possible to validate the spatial aggregation.';
194 | end if;
195 |
196 | if not _ast_isOMTGDomain(part_tbl, part_geom) or not _ast_isomtgdomain(whole_tbl, whole_geom) then
197 | raise exception 'AST_isSpatialAggregationValid error! Invalid parameters.'
198 | using detail = 'Usage: SELECT ast_isSpatialAggregationValid(part_tbl text, part_geom text, whole_tbl text, whole_geom text);';
199 | end if;
200 |
201 | -- 1. Pi intersection W = Pi, for all i such as 0 <= i <= n
202 | execute 'insert into ast_violation_log (time, type, description) (
203 | select now(),
204 | ''Spatial Aggregation violation'',
205 | ''The geometry of the PART with primary key ´''|| c.'|| pkColumn ||' ||''´ is not entirely contained within the geometry of the WHOLE.''
206 | from '|| part_tbl ||' c
207 | where c.ctid not in
208 | (
209 | select b.ctid
210 | from '|| whole_tbl ||' a, '|| part_tbl ||' b
211 | where ST_Equals(ST_Intersection(a.'|| whole_geom ||', b.'|| part_geom ||'), b.'|| part_geom ||')
212 | )
213 | ) returning true;' into res1;
214 |
215 |
216 | -- 3. ((Pi touch Pj) or (Pi disjoint Pj)) = T for all i, j such as i != j
217 | execute 'insert into ast_violation_log (time, type, description) (
218 | select now(),
219 | ''Spatial Aggregation violation'',
220 | ''The geometries of the parts ´''|| b1.'|| pkColumn ||' ||''´ and ´''|| b2.'|| pkColumn ||' ||''´ are overlapping.''
221 | from '|| part_tbl ||' b1, '|| part_tbl ||' b2
222 | where b1.ctid < b2.ctid and
223 | (not st_touches(b1.'|| part_geom ||', b2.'|| part_geom ||') and not st_disjoint(b1.'|| part_geom ||', b2.'|| part_geom ||'))
224 | ) returning true;' into res2;
225 |
226 |
227 | -- 2. (W intersection all P) = W
228 | execute 'select not st_equals(st_union(a.geom), st_union(b.geom))
229 | from tablea a, tableb b;' into res3;
230 |
231 | if res3 then
232 | execute 'insert into ast_violation_log (time, type, description) (
233 | select now(),
234 | ''Spatial Aggregation violation'',
235 | ''The geometry of the WHOLE is not fully covered by the geometry of the PARTS.''
236 | )';
237 | return false;
238 | end if;
239 |
240 | if res1 or res2 then return false;
241 | else return true;
242 | end if;
243 | end;
244 | $$ language plpgsql;
245 |
--------------------------------------------------------------------------------
/sql/domain_functions.sql:
--------------------------------------------------------------------------------
1 | --
2 | -- This function returns the name of the column given its type.
3 | --
4 | CREATE FUNCTION _ast_getGeomColumnDomain(tbl regclass, cname text) RETURNS TEXT AS $$
5 | DECLARE
6 | dname text;
7 | BEGIN
8 |
9 | SELECT domain_name::text INTO dname
10 | FROM information_schema.columns
11 | WHERE table_name = tbl::text AND column_name = cname
12 | LIMIT 1;
13 |
14 | RETURN dname;
15 | END;
16 | $$ LANGUAGE plpgsql;
17 |
18 |
19 |
20 | --
21 | -- This function checks if the column is a OMTG geometry domain
22 | --
23 | CREATE FUNCTION _ast_isOMTGDomain(tname regclass, cname text) RETURNS BOOLEAN AS $$
24 | DECLARE
25 | cDomain TEXT := _ast_getGeomColumnDomain(tname, cname);
26 | res boolean;
27 | BEGIN
28 |
29 | SELECT cDomain = ANY ('{ast_polygon, ast_line, ast_point, ast_node,
30 | ast_isoline, ast_planarsubdivision, ast_tin, ast_tesselation,
31 | ast_sambple, ast_uniline, ast_biline}'::text[]) into res;
32 |
33 | IF res THEN
34 | return 'TRUE';
35 | ELSE
36 | return 'FALSE';
37 | END IF;
38 |
39 | END;
40 | $$ LANGUAGE plpgsql;
41 |
42 |
43 |
44 | --
45 | -- Isoline
46 | --
47 | CREATE FUNCTION _ast_check_isoline() RETURNS TRIGGER AS $$
48 | DECLARE
49 | res BOOLEAN;
50 | tbl CONSTANT TEXT := quote_ident(TG_TABLE_NAME);
51 | cgeom CONSTANT TEXT := _ast_getGeomColumnName(tbl, 'ast_isoline');
52 | BEGIN
53 |
54 | -- Checks if isolines are disjoint
55 | EXECUTE 'SELECT EXISTS (
56 | SELECT 1
57 | FROM '|| tbl ||' AS t1, '|| tbl ||' AS t2
58 | WHERE t1.CTID < t2.CTID AND NOT
59 | ST_Disjoint(t1.'|| cgeom ||', t2.'|| cgeom ||')
60 | )' into res;
61 |
62 | IF res THEN
63 | RAISE EXCEPTION 'OMT-G Isolines integrity constraint violation.'
64 | USING DETAIL = 'Isolines must be disjoint from each other.';
65 | END IF;
66 |
67 | RETURN NULL; -- result is ignored since this is an AFTER trigger
68 | END;
69 | $$ LANGUAGE plpgsql;
70 |
71 |
72 |
73 | --
74 | -- Planar Subdivision
75 | --
76 | CREATE FUNCTION _ast_check_planarsubdivision() RETURNS TRIGGER AS $$
77 | DECLARE
78 | res BOOLEAN;
79 | tbl CONSTANT TEXT := quote_ident(TG_TABLE_NAME);
80 | cgeom CONSTANT TEXT := _ast_getGeomColumnName(tbl, 'ast_planarsubdivision');
81 | BEGIN
82 | -- Checks for overlaps
83 | EXECUTE 'SELECT EXISTS (
84 | SELECT 1
85 | FROM '|| tbl ||' as t1, '|| tbl ||' as t2
86 | WHERE t1.CTID < t2.CTID AND
87 | NOT ST_Touches(t1.'|| cgeom ||', t2.'|| cgeom ||') AND
88 | NOT ST_Disjoint(t1.'|| cgeom ||', t2.'|| cgeom ||')
89 | )' into res;
90 |
91 | IF res THEN
92 | RAISE EXCEPTION 'OMT-G Planar Subdivision integrity constraint violation.'
93 | USING DETAIL = 'Planar Subdivision polygons cannot have overlaps.';
94 | END IF;
95 |
96 | RETURN NULL; -- result is ignored since this is an AFTER trigger
97 |
98 | END;
99 | $$ LANGUAGE plpgsql;
100 |
101 |
102 |
103 | --
104 | -- Sample
105 | --
106 | CREATE FUNCTION _ast_check_sample() RETURNS TRIGGER AS $$
107 | DECLARE
108 | res BOOLEAN;
109 | tbl CONSTANT TEXT := quote_ident(TG_TABLE_NAME);
110 | cgeom CONSTANT TEXT := _ast_getGeomColumnName(tbl, 'ast_sample');
111 | BEGIN
112 |
113 | -- Checks for overlaps
114 | EXECUTE 'SELECT EXISTS (
115 | SELECT 1
116 | FROM '|| tbl ||' as t1, '|| tbl ||' as t2
117 | WHERE t1.CTID < t2.CTID AND
118 | ST_Intersects(t1.'|| cgeom ||', t2.'|| cgeom ||')
119 | )' into res;
120 |
121 | IF res THEN
122 | RAISE EXCEPTION 'OMT-G Sample integrity constraint violation.'
123 | USING DETAIL = 'Sample points cannot have overlaps.';
124 | END IF;
125 |
126 | RETURN NULL; -- result is ignored since this is an AFTER trigger
127 |
128 | END;
129 | $$ LANGUAGE plpgsql;
130 |
131 |
132 |
133 | --
134 | -- TIN
135 | --
136 | CREATE FUNCTION _ast_check_tin() RETURNS TRIGGER AS $$
137 | DECLARE
138 | res BOOLEAN;
139 | tbl CONSTANT TEXT := quote_ident(TG_TABLE_NAME);
140 | cgeom CONSTANT TEXT := _ast_getGeomColumnName(tbl, 'ast_tin');
141 | BEGIN
142 |
143 | -- Checks for overlaps
144 | EXECUTE 'SELECT EXISTS (
145 | SELECT 1
146 | FROM '|| tbl ||' as t1, '|| tbl ||' as t2
147 | WHERE t1.CTID < t2.CTID AND
148 | NOT ST_Touches(t1.'|| cgeom ||', t2.'|| cgeom ||') AND
149 | NOT ST_Disjoint(t1.'|| cgeom ||', t2.'|| cgeom ||')
150 | )' into res;
151 |
152 | IF res THEN
153 | RAISE EXCEPTION 'OMT-G TIN integrity constraint violation.'
154 | USING DETAIL = 'TIN polygons must be triangles and cannot contain overlaps.';
155 | END IF;
156 |
157 | RETURN NULL; -- result is ignored since this is an AFTER trigger
158 | END;
159 | $$ LANGUAGE plpgsql;
160 |
161 |
162 |
163 | --
164 | -- This function creates a domain trigger on a table
165 | --
166 | CREATE FUNCTION _ast_createTriggerOnTable(tname text, omtgClass text, geomName text) RETURNS void AS $$
167 | DECLARE
168 | tgrname text := tname ||'_'|| omtgClass ||'_'|| geomName ||'_trigger';
169 | BEGIN
170 |
171 | -- Check if trigger already exists
172 | IF NOT _ast_isTriggerEnable(tgrname) THEN
173 |
174 | EXECUTE 'CREATE TRIGGER '|| tgrname ||' AFTER INSERT OR UPDATE OR DELETE ON '|| tname ||'
175 | FOR EACH STATEMENT EXECUTE PROCEDURE _ast_check_'|| omtgClass ||'();';
176 |
177 | END IF;
178 |
179 | END;
180 | $$ LANGUAGE plpgsql;
181 |
182 |
183 |
184 | --
185 | -- This function adds the right trigger to a table with a geometry omtg column.
186 | --
187 | CREATE FUNCTION _ast_addClassConstraint() RETURNS event_trigger AS $$
188 | DECLARE
189 | r record;
190 | tname text;
191 | ast_column record;
192 | cname text;
193 | ctype text;
194 | BEGIN
195 | FOR r IN SELECT * FROM pg_event_trigger_ddl_commands()
196 | LOOP
197 | SELECT r.object_identity::regclass INTO tname;
198 |
199 | -- verify that tags match
200 | IF r.command_tag = 'CREATE TABLE' OR r.command_tag = 'ALTER TABLE' THEN
201 |
202 | FOR ast_column IN SELECT attname AS cname, format_type(atttypid, atttypmod) AS ctype
203 | FROM pg_attribute
204 | WHERE attrelid = r.objid AND attnum > 0 AND NOT attisdropped and format_type(atttypid, atttypmod) like 'ast_%'
205 | LOOP
206 |
207 | CASE ast_column.ctype
208 | WHEN 'ast_isoline' THEN
209 | PERFORM _ast_createTriggerOnTable(tname, 'isoline', ast_column.cname);
210 |
211 | WHEN 'ast_planarsubdivision' THEN
212 | PERFORM _ast_createTriggerOnTable(tname, 'planarsubdivision', ast_column.cname);
213 |
214 | WHEN 'ast_sample' THEN
215 | PERFORM _ast_createTriggerOnTable(tname, 'sample', ast_column.cname);
216 |
217 | WHEN 'ast_tin' THEN
218 | PERFORM _ast_createTriggerOnTable(tname, 'tin', ast_column.cname);
219 |
220 | ELSE RETURN;
221 |
222 | END CASE;
223 | END LOOP;
224 | END IF;
225 | END LOOP;
226 | END;
227 | $$ LANGUAGE plpgsql;
228 |
--------------------------------------------------------------------------------
/sql/domains.sql:
--------------------------------------------------------------------------------
1 | --
2 | -- Polygon
3 | --
4 | create domain AST_POLYGON as GEOMETRY(MULTIPOLYGON)
5 | constraint simple_polygon_constraint check (_ast_isSimpleGeometry(VALUE));
6 |
7 | --
8 | -- Line
9 | --
10 | create domain AST_LINE as GEOMETRY(MULTILINESTRING)
11 | constraint simple_line_constraint check (_ast_isSimpleGeometry(VALUE));
12 |
13 | --
14 | -- Point
15 | --
16 | create domain AST_POINT as GEOMETRY(POINT);
17 |
18 | --
19 | -- Node
20 | --
21 | create domain AST_NODE as GEOMETRY(POINT);
22 |
23 | --
24 | -- Isoline
25 | --
26 | create domain AST_ISOLINE as GEOMETRY(LINESTRING)
27 | constraint simple_isoline_constraint check (_ast_isSimpleGeometry(VALUE));
28 |
29 | --
30 | -- Planar subdivision
31 | --
32 | create domain AST_PLANARSUBDIVISION as GEOMETRY(MULTIPOLYGON)
33 | constraint simple_planarsubdivision_constraint check (_ast_isSimpleGeometry(VALUE));
34 | --
35 | -- TIN
36 | --
37 | create domain AST_TIN as GEOMETRY(POLYGON)
38 | constraint simple_tin_constraint check (_ast_isSimpleGeometry(VALUE))
39 | constraint triangle_tin_constraint check (_ast_isTriangle(VALUE));
40 |
41 | --
42 | -- Tesselation
43 | --
44 | create domain AST_TESSELATION as RASTER;
45 |
46 | --
47 | -- Sample
48 | --
49 | create domain AST_SAMPLE as GEOMETRY(POINT);
50 |
51 | --
52 | -- Unidirectional Line
53 | --
54 | create domain AST_UNILINE as GEOMETRY(LINESTRING)
55 | constraint simple_uniline_constraint check (_ast_isSimpleGeometry(VALUE));
56 |
57 | --
58 | -- Bidirectional Line
59 | --
60 | create domain AST_BILINE as GEOMETRY(LINESTRING)
61 | constraint simple_biline_constraint check (_ast_isSimpleGeometry(VALUE));
62 |
--------------------------------------------------------------------------------
/sql/event_triggers.sql:
--------------------------------------------------------------------------------
1 | --
2 | -- Event trigger to add constraints automatic to tables with OMT-G types
3 | --
4 | CREATE EVENT TRIGGER ast_add_class_constraint_trigger
5 | ON ddl_command_end
6 | WHEN tag IN ('create table', 'alter table')
7 | EXECUTE PROCEDURE _ast_addClassConstraint();
8 |
9 |
10 |
11 | --
12 | -- Event trigger to validate user triggers
13 | --
14 | CREATE EVENT TRIGGER ast_validate_triggers
15 | ON ddl_command_end
16 | WHEN tag IN ('create trigger')
17 | EXECUTE PROCEDURE _ast_validateTrigger();
18 |
--------------------------------------------------------------------------------
/sql/postgis.sql:
--------------------------------------------------------------------------------
1 | CREATE EXTENSION postgis;
2 | CREATE EXTENSION postgis_topology;
3 | CREATE EXTENSION postgis_raster;
--------------------------------------------------------------------------------
/sql/relationship_triggers.sql:
--------------------------------------------------------------------------------
1 | --
2 | -- Arc-Node relationship. Check if arcs are valid
3 | --
4 | CREATE FUNCTION _ast_arcnodenetwork_onarc(arc regclass, node regclass, ageom text, ngeom text)
5 | RETURNS BOOLEAN AS $$
6 | DECLARE
7 | res BOOLEAN;
8 | a_geom CONSTANT TEXT := quote_ident(ageom);
9 | n_geom CONSTANT TEXT := quote_ident(ngeom);
10 | BEGIN
11 |
12 | -- Checks if for each arc there are at least 2 nodes.
13 | EXECUTE 'WITH Points AS (
14 | SELECT ST_StartPoint('|| a_geom ||') AS point FROM '|| arc ||'
15 | UNION
16 | SELECT ST_EndPoint('|| a_geom ||') AS point FROM '|| arc ||'
17 | )
18 | SELECT NOT EXISTS(
19 | SELECT 1 FROM Points AS P
20 | LEFT JOIN '|| node ||' AS N ON ST_INTERSECTS(P.point, N.'|| n_geom ||') WHERE N.'|| n_geom ||' IS NULL
21 | )' INTO res;
22 |
23 | RETURN res;
24 | END;
25 | $$ LANGUAGE plpgsql;
26 |
27 |
28 |
29 | --
30 | -- Arc-Node relationship. Check if nodes are valid
31 | --
32 | CREATE FUNCTION _ast_arcnodenetwork_onnode(arc regclass, node regclass, ageom text, ngeom text)
33 | RETURNS BOOLEAN AS $$
34 | DECLARE
35 | res BOOLEAN;
36 | a_geom CONSTANT TEXT := quote_ident(ageom);
37 | n_geom CONSTANT TEXT := quote_ident(ngeom);
38 | BEGIN
39 |
40 | -- Checks if for each node, there is at least one arc.
41 | EXECUTE 'WITH Points AS (
42 | SELECT ST_StartPoint('|| a_geom ||') AS point FROM '|| arc ||'
43 | UNION
44 | SELECT ST_EndPoint('|| a_geom ||') AS point FROM '|| arc ||'
45 | )
46 | SELECT NOT EXISTS(
47 | SELECT 1 FROM '|| node ||' AS N
48 | LEFT JOIN Points AS P ON ST_INTERSECTS(N.'|| n_geom ||', P.point) = TRUE WHERE P.point IS NULL
49 | )' INTO res;
50 |
51 | RETURN res;
52 | END;
53 | $$ LANGUAGE plpgsql;
54 |
55 |
56 |
57 | --
58 | -- Arc-Node network.
59 | --
60 | CREATE FUNCTION ast_arcnodenetwork() RETURNS TRIGGER AS $$
61 | DECLARE
62 | arc_tbl CONSTANT REGCLASS := TG_ARGV[0];
63 | arc_geom CONSTANT TEXT := quote_ident(TG_ARGV[1]);
64 |
65 | node_tbl CONSTANT REGCLASS := TG_ARGV[2];
66 | node_geom CONSTANT TEXT := quote_ident(TG_ARGV[3]);
67 |
68 | arc_domain CONSTANT TEXT := _ast_getGeomColumnDomain(arc_tbl, arc_geom);
69 | node_domain CONSTANT TEXT := _ast_getGeomColumnDomain(node_tbl, node_geom);
70 |
71 | BEGIN
72 |
73 | -- Validate trigger settings
74 | IF TG_WHEN != 'AFTER' THEN
75 | RAISE EXCEPTION 'OMT-G error at ast_arcnodenetwork.'
76 | USING DETAIL = 'Trigger must be fired with AFTER statement.';
77 | END IF;
78 |
79 | IF TG_LEVEL != 'STATEMENT' THEN
80 | RAISE EXCEPTION 'OMT-G error at ast_arcnodenetwork.'
81 | USING DETAIL = 'Trigger must be of STATEMENT level.';
82 | END IF;
83 |
84 | -- Validate input parameters
85 | IF TG_NARGS != 4 OR node_domain != 'ast_node' OR (arc_domain != 'ast_uniline' AND arc_domain != 'ast_biline' ) THEN
86 | RAISE EXCEPTION 'OMT-G error at ast_arcnodenetwork.'
87 | USING DETAIL = 'Invalid parameters.';
88 | END IF;
89 |
90 |
91 | IF TG_OP = 'INSERT' OR TG_OP ='UPDATE' THEN
92 |
93 | -- Check which table fired the trigger
94 | IF TG_TABLE_NAME = arc_tbl::TEXT THEN
95 | IF NOT _ast_arcnodenetwork_onarc(arc_tbl, node_tbl, arc_geom, node_geom) THEN
96 | RAISE EXCEPTION 'OMT-G Arc-Node network constraint violation at table %.', TG_TABLE_NAME
97 | USING DETAIL = 'For each arc at least two nodes must exist at the arc extrem points.';
98 | END IF;
99 | ELSIF TG_TABLE_NAME = node_tbl::TEXT THEN
100 | IF NOT _ast_arcnodenetwork_onnode(arc_tbl, node_tbl, arc_geom, node_geom) THEN
101 | RAISE EXCEPTION 'OMT-G Arc-Node network constraint violation at table %.', TG_TABLE_NAME
102 | USING DETAIL = 'For each node at least one arc must exist.';
103 | END IF;
104 | ELSE
105 | IF NOT _ast_arcnodenetwork_onnode(arc_tbl, node_tbl, arc_geom, node_geom) THEN
106 | RAISE EXCEPTION 'OMT-G error at ast_arcnodenetwork.'
107 | USING DETAIL = 'Was not possible to identify the table which fired the trigger.';
108 | END IF;
109 | END IF;
110 |
111 | ELSIF TG_OP = 'DELETE' THEN
112 |
113 | IF TG_TABLE_NAME = arc_tbl::TEXT THEN
114 | IF NOT _ast_arcnodenetwork_onnode(arc_tbl, node_tbl, arc_geom, node_geom) THEN
115 | RAISE EXCEPTION 'OMT-G Arc-Node network constraint violation at table %.', TG_TABLE_NAME
116 | USING DETAIL = 'Cannot delete the arc because there are nodes connected to it.';
117 | END IF;
118 | ELSIF TG_TABLE_NAME = node_tbl::TEXT THEN
119 | IF NOT _ast_arcnodenetwork_onarc(arc_tbl, node_tbl, arc_geom, node_geom) THEN
120 | RAISE EXCEPTION 'OMT-G Arc-Node network constraint violation at table %.', TG_TABLE_NAME
121 | USING DETAIL = 'Cannot delete the node because there are arcs connected to it.';
122 | END IF;
123 | ELSE
124 | IF NOT _ast_arcnodenetwork_onnode(arc_tbl, node_tbl, arc_geom, node_geom) THEN
125 | RAISE EXCEPTION 'OMT-G error at ast_arcnodenetwork.'
126 | USING DETAIL = 'Was not possible to identify the table which fired the trigger.';
127 | END IF;
128 | END IF;
129 |
130 | ELSE
131 | RAISE EXCEPTION 'OMT-G error at ast_arcnodenetwork.'
132 | USING DETAIL = 'Event not supported. Please create a trigger with INSERT, UPDATE or a DELETE event.';
133 | END IF;
134 |
135 | RETURN NULL;
136 | END;
137 | $$ LANGUAGE plpgsql;
138 |
139 |
140 |
141 | --
142 | -- Arc-Arc network.
143 | --
144 | CREATE FUNCTION ast_arcarcnetwork() RETURNS TRIGGER AS $$
145 | DECLARE
146 | arc_tbl CONSTANT REGCLASS := TG_ARGV[0];
147 | arc_geom CONSTANT TEXT := quote_ident(TG_ARGV[1]);
148 |
149 | arc_domain CONSTANT TEXT := _ast_getGeomColumnDomain(arc_tbl, arc_geom);
150 |
151 | res BOOLEAN;
152 | BEGIN
153 |
154 | IF TG_WHEN != 'AFTER' THEN
155 | RAISE EXCEPTION 'OMT-G error at ast_arcarcnetwork.'
156 | USING DETAIL = 'Trigger must be fired with AFTER statement.';
157 | END IF;
158 |
159 | IF TG_LEVEL != 'STATEMENT' THEN
160 | RAISE EXCEPTION 'OMT-G error at ast_arcarcnetwork.'
161 | USING DETAIL = 'Trigger must be of STATEMENT level.';
162 | END IF;
163 |
164 | IF TG_NARGS != 2 OR TG_TABLE_NAME != arc_tbl::TEXT OR (arc_domain != 'ast_uniline' AND arc_domain != 'ast_biline' ) THEN
165 | RAISE EXCEPTION 'OMT-G error at ast_arcarcnetwork.'
166 | USING DETAIL = 'Invalid parameters.';
167 | END IF;
168 |
169 | EXECUTE 'select exists(
170 | select 1
171 | from '|| arc_tbl ||' as a, '|| arc_tbl ||' as b
172 | where a.ctid < b.ctid
173 | and st_intersects(a.'|| arc_geom ||', b.'|| arc_geom ||')
174 | and not st_intersects(st_startpoint(a.'|| arc_geom ||'), st_startpoint(b.'|| arc_geom ||'))
175 | and not st_intersects(st_startpoint(a.'|| arc_geom ||'), st_endpoint(b.'|| arc_geom ||'))
176 | and not st_intersects(st_endpoint(a.'|| arc_geom ||'), st_startpoint(b.'|| arc_geom ||'))
177 | and not st_intersects(st_endpoint(a.'|| arc_geom ||'), st_endpoint(b.'|| arc_geom ||'))
178 | );' into res;
179 |
180 | IF res THEN
181 | RAISE EXCEPTION 'OMT-G Arc-Arc network constraint violation at table %.', TG_TABLE_NAME
182 | USING DETAIL = 'Each arc can only be connected to another arc on its start or end point.';
183 | END IF;
184 |
185 | RETURN NULL;
186 | END;
187 | $$ LANGUAGE plpgsql;
188 |
189 |
190 |
191 | --
192 | -- Spatial relationship.
193 | --
194 | CREATE FUNCTION ast_spatialrelationship() RETURNS TRIGGER AS $$
195 | DECLARE
196 | a_tbl CONSTANT REGCLASS := TG_ARGV[0];
197 | a_geom CONSTANT TEXT := quote_ident(TG_ARGV[1]);
198 |
199 | b_tbl CONSTANT REGCLASS := TG_ARGV[2];
200 | b_geom CONSTANT TEXT := quote_ident(TG_ARGV[3]);
201 |
202 | operator _ast_spatialrelationship := quote_ident(TG_ARGV[4]);
203 | dist REAL;
204 |
205 | res BOOLEAN;
206 | BEGIN
207 |
208 | IF TG_WHEN != 'AFTER' THEN
209 | RAISE EXCEPTION 'OMT-G error at ast_spatialrelationship.'
210 | USING DETAIL = 'Trigger must be fired with AFTER statement.';
211 | END IF;
212 |
213 | IF TG_LEVEL != 'STATEMENT' THEN
214 | RAISE EXCEPTION 'OMT-G error at ast_spatialrelationship.'
215 | USING DETAIL = 'Trigger must be of STATEMENT level.';
216 | END IF;
217 |
218 | IF (TG_NARGS != 5 AND TG_NARGS != 6) OR NOT _ast_isOMTGDomain(a_tbl, a_geom) OR NOT _ast_isOMTGDomain(b_tbl, b_geom) THEN
219 | RAISE EXCEPTION 'OMT-G error at ast_spatialrelationship.'
220 | USING DETAIL = 'Invalid parameters.';
221 | END IF;
222 |
223 |
224 | -- IF (TG_OP = 'INSERT' OR TG_OP = 'UPDATE') THEN
225 | --
226 | -- -- Trigger table must be the same used on the first parameter
227 | -- IF TG_TABLE_NAME != a_tbl::TEXT THEN
228 | -- RAISE EXCEPTION 'OMT-G error at ast_spatialrelationship.'
229 | -- USING DETAIL = 'Invalid parameters. Table that fires the trigger must be the first parameter of the function when firing after INSERT or UPDATE.';
230 | -- END IF;
231 | --
232 | -- ELSIF TG_OP = 'DELETE' THEN
233 | --
234 | -- -- Trigger table must be the same used on the second parameter
235 | -- IF TG_TABLE_NAME != b_tbl::TEXT THEN
236 | -- RAISE EXCEPTION 'OMT-G error at ast_spatialrelationship.'
237 | -- USING DETAIL = 'Invalid parameters. Table that fires the trigger must be the second parameter of the function when firing after a DELETE.';
238 | -- END IF;
239 | --
240 | -- ELSE
241 | -- RAISE EXCEPTION 'OMT-G error at ast_spatialrelationship.'
242 | -- USING DETAIL = 'Event not supported. Please create a trigger with INSERT, UPDATE or DELETE event.';
243 | -- END IF;
244 |
245 |
246 | -- Checks if the fourth argument is a number to perform near function or normal.
247 | IF operator = 'near' THEN
248 | dist := TG_ARGV[5];
249 |
250 | --raise notice 'NEAR %, %, %, %, %', a_tbl, b_tbl, a_geom, b_geom, dist;
251 |
252 | -- Near check
253 | EXECUTE 'SELECT EXISTS(
254 | SELECT 1
255 | FROM '|| a_tbl ||' AS a
256 | RIGHT JOIN '|| b_tbl ||' AS b
257 | ON ST_DWITHIN(a.'|| a_geom ||', b.'|| b_geom ||', '|| dist ||')
258 | WHERE a.'|| a_geom ||' IS NULL
259 | );' into res;
260 |
261 | IF res THEN
262 | RAISE EXCEPTION 'OMT-G Spatial Relationship constraint violation between % and %.', a_tbl, b_tbl
263 | USING DETAIL = 'Spatial objects are not inside the given distance.';
264 | END IF;
265 |
266 | ELSIF operator = 'distant' THEN
267 | dist := TG_ARGV[5];
268 |
269 | --raise notice 'DISTANT %, %, %, %, %', a_tbl, b_tbl, a_geom, b_geom, dist;
270 |
271 | -- Distant check
272 | EXECUTE 'SELECT EXISTS(
273 | SELECT 1
274 | FROM '|| a_tbl ||' AS a
275 | LEFT JOIN '|| b_tbl ||' AS b
276 | ON ST_DWITHIN(a.'|| a_geom ||', b.'|| b_geom ||', '|| dist ||')
277 | WHERE b.'|| b_geom ||' IS NOT NULL
278 | );' into res;
279 |
280 | IF res THEN
281 | RAISE EXCEPTION 'OMT-G Spatial Relationship constraint violation between ''%'' and ''%''.', a_tbl, b_tbl
282 | USING DETAIL = 'Spatial objects are not outside the given distance.';
283 | END IF;
284 |
285 |
286 | ELSE
287 | -- Topological test
288 | EXECUTE 'SELECT EXISTS(
289 | SELECT 1
290 | FROM '|| a_tbl ||' AS a
291 | LEFT JOIN '|| b_tbl ||' AS b
292 | ON st_'|| operator ||'(a.'|| a_geom ||', b.'|| b_geom ||')
293 | WHERE b.'|| b_geom ||' IS NULL
294 | );' into res;
295 |
296 | IF res THEN
297 | RAISE EXCEPTION 'OMT-G Spatial Relationship constraint violation (%) between tables ''%'' and ''%''.', operator::text, a_tbl, b_tbl;
298 | END IF;
299 |
300 | END IF;
301 |
302 | RETURN NULL;
303 | END;
304 | $$ LANGUAGE plpgsql;
305 |
306 |
307 |
308 | --
309 | -- Aggregation.
310 | --
311 | CREATE FUNCTION ast_aggregation() RETURNS TRIGGER AS $$
312 | DECLARE
313 |
314 | part_tbl CONSTANT REGCLASS := TG_ARGV[0];
315 | part_geom CONSTANT TEXT := quote_ident(TG_ARGV[1]);
316 |
317 | whole_tbl CONSTANT REGCLASS := TG_ARGV[2];
318 | whole_geom CONSTANT TEXT := quote_ident(TG_ARGV[3]);
319 |
320 | res1 BOOLEAN;
321 | res2 BOOLEAN;
322 | res3 BOOLEAN;
323 | BEGIN
324 |
325 | IF TG_WHEN != 'AFTER' THEN
326 | RAISE EXCEPTION 'OMT-G error at ast_aggregation.'
327 | USING DETAIL = 'Trigger must be fired with AFTER statement.';
328 | END IF;
329 |
330 | IF TG_LEVEL != 'STATEMENT' THEN
331 | RAISE EXCEPTION 'OMT-G error at ast_aggregation.'
332 | USING DETAIL = 'Trigger must be of STATEMENT level.';
333 | END IF;
334 |
335 | IF TG_NARGS != 4 OR TG_TABLE_NAME != part_tbl::TEXT OR NOT _ast_isOMTGDomain(whole_tbl, whole_geom) OR NOT _ast_isOMTGDomain(part_tbl, part_geom) THEN
336 | RAISE EXCEPTION 'OMT-G error at ast_aggregation.'
337 | USING DETAIL = 'Invalid parameters.';
338 | END IF;
339 |
340 | -- 1. Pi intersection W = Pi, for all i such as 0 <= i <= n
341 | EXECUTE 'SELECT EXISTS (
342 | select 1
343 | from '|| part_tbl ||' c
344 | where c.CTID not in
345 | (
346 | select b.CTID
347 | from '|| whole_tbl ||' a, '|| part_tbl ||' b
348 | where ST_Equals(ST_Intersection(a.'|| whole_geom ||', b.'|| part_geom ||'), b.'|| part_geom ||')
349 | )
350 | );' into res1;
351 |
352 | IF res1 THEN
353 | RAISE EXCEPTION 'OMT-G Aggregation constraint violation with tables % and %.', whole_tbl, part_tbl
354 | USING DETAIL = 'The geometry of each PART should be entirely contained within the geometry of the WHOLE.';
355 | END IF;
356 |
357 | -- 3. ((Pi touch Pj) or (Pi disjoint Pj)) = T for all i, j such as i != j
358 | EXECUTE 'SELECT EXISTS (
359 | select 1
360 | from '|| part_tbl ||' b1, '|| part_tbl ||' b2
361 | where b1.ctid < b2.ctid and
362 | (not st_touches(b1.'|| part_geom ||', b2.'|| part_geom ||') and not st_disjoint(b1.'|| part_geom ||', b2.'|| part_geom ||'))
363 | );' into res2;
364 |
365 | IF res2 THEN
366 | RAISE EXCEPTION 'OMT-G Aggregation constraint violation with tables % and %.', whole_tbl, part_tbl
367 | USING DETAIL = 'Overlapping among the PARTS is not allowed.';
368 | END IF;
369 |
370 | -- 2. (W intersection all P) = W
371 | EXECUTE 'SELECT NOT st_equals(st_union(a.'|| whole_geom ||'), st_union(b.'|| part_geom ||'))
372 | FROM '|| whole_tbl ||' a, '|| part_tbl ||' b' into res3;
373 |
374 | IF res3 THEN
375 | RAISE EXCEPTION 'OMT-G Aggregation constraint violation with tables % and %.', whole_tbl, part_tbl
376 | USING DETAIL = 'The geometry of the WHOLE should be fully covered by the geometry of the PARTS.';
377 | END IF;
378 |
379 |
380 | RETURN NULL;
381 | END;
382 | $$ LANGUAGE plpgsql;
383 |
384 |
385 |
386 | --
387 | -- This function returns the name of the column given its type.
388 | --
389 | CREATE FUNCTION _ast_createTriggerOnTable(tgrname text, tname text, procedure text, operation text) RETURNS void AS $$
390 | BEGIN
391 | -- Check if trigger already exists
392 | IF NOT _ast_isTriggerEnable(tgrname) THEN
393 | -- Suspend event trigger to avoid loop
394 | EXECUTE 'ALTER EVENT TRIGGER ast_validate_triggers DISABLE;';
395 |
396 | EXECUTE 'CREATE TRIGGER '|| tgrname ||' AFTER '|| operation ||' ON '|| tname ||'
397 | FOR EACH STATEMENT EXECUTE PROCEDURE '|| procedure ||';';
398 |
399 | --RAISE NOTICE 'Trigger created AFTER DELETE on table % with % procedure.', tname, procedure;
400 |
401 | -- Enable event trigger again
402 | EXECUTE 'ALTER EVENT TRIGGER ast_validate_triggers ENABLE;';
403 | END IF;
404 |
405 | END;
406 | $$ LANGUAGE plpgsql;
407 |
408 |
409 |
410 | --
411 | -- This function adds the right trigger to a table with a geometry omtg column.
412 | --
413 | CREATE FUNCTION _ast_validateTrigger() RETURNS event_trigger AS $$
414 | DECLARE
415 | r record;
416 | events text[];
417 | function_arguments text[];
418 | function_name text;
419 | row_statement text;
420 | timing text;
421 | table_name text;
422 |
423 | arc_domain text;
424 | node_domain text;
425 |
426 | on_tbl text;
427 | BEGIN
428 | FOR r IN SELECT * FROM pg_event_trigger_ddl_commands()
429 | LOOP
430 |
431 | -- verify that tags match
432 | IF r.command_tag = 'CREATE TRIGGER' THEN
433 |
434 | timing := (_ast_triggerParser(r.objid)).timing;
435 | function_name := (_ast_triggerParser(r.objid)).function_name;
436 | row_statement := (_ast_triggerParser(r.objid)).row_statement;
437 | function_arguments := _ast_arraylower((_ast_triggerParser(r.objid)).function_arguments);
438 | table_name := (_ast_triggerParser(r.objid)).table_name;
439 | events := _ast_arraylower((_ast_triggerParser(r.objid)).events);
440 |
441 | -- trigger must be fired after an statement
442 | IF timing != 'AFTER' or row_statement != 'STATEMENT' THEN
443 | RAISE EXCEPTION 'OMT-G error on trigger %.', r.object_identity
444 | USING DETAIL = 'Trigger must be fired AFTER a STATEMENT.';
445 | END IF;
446 |
447 | CASE function_name
448 |
449 | WHEN 'ast_arcarcnetwork' THEN
450 |
451 | -- number of arguments
452 | IF array_length(function_arguments, 1) != 2 THEN
453 | RAISE EXCEPTION 'OMT-G error at ARC-ARC NETWORK constraint, on trigger %.', r.object_identity
454 | USING DETAIL = 'Invalid procedure parameters. Usage: ast_arcarcnetwork(''arc_tbl'', ''arc_geom'').';
455 | END IF;
456 |
457 | -- table that fired the trigger must be the same of the parameter
458 | IF function_arguments[1] != table_name THEN
459 | RAISE EXCEPTION 'OMT-G error at ARC-ARC NETWORK constraint, on trigger %.', r.object_identity
460 | USING DETAIL = 'Invalid procedure parameters. Table associated with the trigger must be passed as the first parameter. Usage: ast_arcarcnetwork(''arc_table'', ''arc_geometry'').';
461 | END IF;
462 |
463 | -- domain must be an arc
464 | arc_domain := _ast_getGeomColumnDomain(function_arguments[1], function_arguments[2]);
465 | IF arc_domain != 'ast_uniline' AND arc_domain != 'ast_biline' THEN
466 | RAISE EXCEPTION 'OMT-G error at ARC-ARC NETWORK constraint, on trigger %.', r.object_identity
467 | USING DETAIL = 'Table passed as parameter does not contain an arc geometry (ast_uniline or ast_biline).';
468 | END IF;
469 |
470 | -- trigger events must be insert, delete and update
471 | IF not events @> '{insert}' or not events @> '{delete}' or not events @> '{update}' THEN
472 | RAISE EXCEPTION 'OMT-G error at ARC-ARC NETWORK constraint, on trigger %.', r.object_identity
473 | USING DETAIL = 'ARC-ARC trigger events must be INSERT OR UPDATE OR DELETE.';
474 | END IF;
475 |
476 |
477 | WHEN 'ast_arcnodenetwork' THEN
478 |
479 | -- number of arguments
480 | IF array_length(function_arguments, 1) != 4 THEN
481 | RAISE EXCEPTION 'OMT-G error at ARC-NODE NETWORK constraint, on trigger %.', r.object_identity
482 | USING DETAIL = 'Invalid procedure parameters. Usage: ast_arcnodenetwork(''arc_tbl'', ''arc_geom'', ''node_tbl'', ''node_geom'').';
483 | END IF;
484 |
485 | -- domain must be arc and node
486 | arc_domain := _ast_getGeomColumnDomain(function_arguments[1], function_arguments[2]);
487 | node_domain := _ast_getGeomColumnDomain(function_arguments[3], function_arguments[4]);
488 | IF node_domain != 'ast_node' OR (arc_domain != 'ast_uniline' AND arc_domain != 'ast_biline' ) THEN
489 | RAISE EXCEPTION 'OMT-G error at ARC-NODE NETWORK constraint, on trigger %.', r.object_identity
490 | USING DETAIL = 'Arc table must have AST_UNILINE or AST_BILINE geometry. Node table must have AST_NODE geometry.';
491 | END IF;
492 |
493 | IF table_name != function_arguments[1] AND table_name != function_arguments[3] THEN
494 | RAISE EXCEPTION 'OMT-G error at ARC-NODE NETWORK constraint, on trigger %.', r.object_identity
495 | USING DETAIL = 'Table that fires the trigger must be passed as a parameter.';
496 | END IF;
497 |
498 | -- only insert or update
499 | IF (not events @> '{insert}' or not events @> '{update}' or events @> '{delete}') THEN
500 | RAISE EXCEPTION 'OMT-G error at ARC-NODE NETWORK constraint, on trigger %.', r.object_identity
501 | USING DETAIL = 'ARC-NODE trigger events must be INSERT OR UPDATE.';
502 | END IF;
503 |
504 | IF table_name = function_arguments[1] THEN
505 | -- create trigger on delete on node
506 | on_tbl := function_arguments[3];
507 | ELSE
508 | -- create trigger on delete on arc
509 | on_tbl := function_arguments[1];
510 | END IF;
511 |
512 | PERFORM _ast_createTriggerOnTable(
513 | split_part(r.object_identity, ' ', 1) ||'_auto',
514 | on_tbl,
515 | 'ast_arcnodenetwork('|| function_arguments[1] ||', '|| function_arguments[2] ||', '|| function_arguments[3] ||', '|| function_arguments[4] ||')',
516 | 'delete'
517 | );
518 |
519 |
520 | WHEN 'ast_spatialrelationship' THEN
521 |
522 | -- number of arguments
523 | IF (array_length(function_arguments, 1) != 5 AND array_length(function_arguments, 1) != 6)
524 | OR NOT _ast_isOMTGDomain(function_arguments[1], function_arguments[2])
525 | OR NOT _ast_isOMTGDomain(function_arguments[3], function_arguments[4])
526 | OR (array_length(function_arguments, 1) = 6 AND NOT _ast_isnumeric(function_arguments[6]))
527 | THEN
528 | RAISE EXCEPTION 'OMT-G error at TOPOLOGICAL RELATIONSHIP constraint, on trigger %.', r.object_identity
529 | USING DETAIL = 'Invalid procedure parameters. Usage: ast_spatialrelationship(''a_tbl'', ''a_geom'', ''b_tbl'', ''b_geom'', ''spatial_relation'', ''''distance'''').';
530 | END IF;
531 |
532 | IF table_name != function_arguments[1] AND table_name != function_arguments[3] THEN
533 | RAISE EXCEPTION 'OMT-G error at TOPOLOGICAL RELATIONSHIP constraint, on trigger %.', r.object_identity
534 | USING DETAIL = 'Table that fires the trigger must be passed as the first parameter of the procedure.';
535 | END IF;
536 |
537 |
538 | IF (function_arguments[5] = 'distant') THEN
539 |
540 | -- INSERT OR UPDATE
541 | IF (not events @> '{insert}' or not events @> '{update}' or events @> '{delete}') THEN
542 | RAISE EXCEPTION 'OMT-G error at TOPOLOGICAL RELATIONSHIP DISTANT constraint, on trigger %.', r.object_identity
543 | USING DETAIL = 'TOPOLOGICAL RELATIONSHIP DISTANT trigger events must be INSERT OR UPDATE.';
544 | END IF;
545 |
546 | ELSIF (function_arguments[5] = 'near') THEN
547 |
548 | -- DELETE OR UPDATE
549 | IF (not events @> '{delete}' or not events @> '{update}' or events @> '{insert}') THEN
550 | RAISE EXCEPTION 'OMT-G error at TOPOLOGICAL RELATIONSHIP NEAR constraint, on trigger %.', r.object_identity
551 | USING DETAIL = 'TOPOLOGICAL RELATIONSHIP NEAR trigger events must be DELETE OR UPDATE.';
552 | END IF;
553 |
554 | ELSE
555 |
556 | -- INSERT OR UPDATE
557 | IF (not events @> '{insert}' or not events @> '{update}' or events @> '{delete}') THEN
558 | RAISE EXCEPTION 'OMT-G error at TOPOLOGICAL RELATIONSHIP constraint, on trigger %.', r.object_identity
559 | USING DETAIL = 'TOPOLOGICAL RELATIONSHIP trigger events must be INSERT OR UPDATE.';
560 | END IF;
561 |
562 | END IF;
563 |
564 | IF function_arguments[5] = 'near' or function_arguments[5] = 'distant' THEN
565 | PERFORM _ast_createTriggerOnTable(
566 | split_part(r.object_identity, ' ', 1) ||'_auto',
567 | function_arguments[3],
568 | 'ast_spatialrelationship('|| function_arguments[1] ||', '|| function_arguments[2] ||', '|| function_arguments[3] ||', '|| function_arguments[4] ||', '|| function_arguments[5] ||', '|| function_arguments[6] ||')',
569 | 'insert or update'
570 | );
571 | ELSE
572 | PERFORM _ast_createTriggerOnTable(
573 | split_part(r.object_identity, ' ', 1) ||'_auto',
574 | function_arguments[3],
575 | 'ast_spatialrelationship('|| function_arguments[1] ||', '|| function_arguments[2] ||', '|| function_arguments[3] ||', '|| function_arguments[4] ||', '|| function_arguments[5] ||')',
576 | 'delete'
577 | );
578 | END IF;
579 |
580 |
581 | WHEN 'ast_aggregation' THEN
582 |
583 | -- number of arguments
584 | IF array_length(function_arguments, 1) != 4 OR NOT _ast_isOMTGDomain(function_arguments[1], function_arguments[2]) OR NOT _ast_isOMTGDomain(function_arguments[3], function_arguments[4]) THEN
585 | RAISE EXCEPTION 'OMT-G error at AGGREGATION constraint, on trigger %.', r.object_identity
586 | USING DETAIL = 'Invalid procedure parameters. Usage: ast_aggregation(''part_tbl'', ''part_geom'', ''whole_tbl'', ''whole_geom'').';
587 | END IF;
588 |
589 | IF table_name != function_arguments[1] THEN
590 | RAISE EXCEPTION 'OMT-G error at AGGREGATION constraint, on trigger %.', r.object_identity
591 | USING DETAIL = 'Part table that fires the trigger must be passed as the first parameter of the procedure.';
592 | END IF;
593 |
594 | IF (not events @> '{insert}' or not events @> '{update}' or not events @> '{delete}') THEN
595 | RAISE EXCEPTION 'OMT-G error at AGGREGATION constraint, on trigger %.', r.object_identity
596 | USING DETAIL = 'AGGREGATION trigger events must be INSERT OR UPDATE OR DELETE.';
597 | END IF;
598 |
599 | ELSE RETURN;
600 |
601 | END CASE;
602 |
603 | END IF;
604 | END LOOP;
605 | END;
606 | $$ LANGUAGE plpgsql;
607 |
--------------------------------------------------------------------------------
/sql/tables.sql:
--------------------------------------------------------------------------------
1 | --
2 | -- Spatial error log table
3 | --
4 | CREATE TABLE ast_violation_log (
5 | time timestamp,
6 | type VARCHAR(50),
7 | description VARCHAR(150)
8 | );
9 |
10 | --
11 | -- Mark the ast_violation table as a configuration table, which will cause
12 | -- pg_dump to include the table's contents (not its definition) in dumps.
13 | --
14 | SELECT pg_catalog.pg_extension_config_dump('ast_violation_log', '');
15 |
--------------------------------------------------------------------------------
/sql/type_functions.sql:
--------------------------------------------------------------------------------
1 | --
2 | -- Check if the operator is a valid topological relationship
3 | --
4 | CREATE FUNCTION _ast_isSpatialRelationship(operator text) RETURNS BOOLEAN AS $$
5 | DECLARE
6 | tr _ast_spatialrelationship;
7 | BEGIN
8 | tr := operator;
9 | RETURN TRUE;
10 | EXCEPTION
11 | WHEN invalid_text_representation THEN
12 | RETURN FALSE;
13 | END;
14 | $$ LANGUAGE plpgsql;
15 |
--------------------------------------------------------------------------------
/sql/types.sql:
--------------------------------------------------------------------------------
1 | CREATE TYPE _ast_spatialrelationship AS ENUM
2 | (
3 | 'contains',
4 | 'containsproperly',
5 | 'covers',
6 | 'coveredby',
7 | 'crosses',
8 | 'disjoint',
9 | 'distant',
10 | 'intersects',
11 | 'near',
12 | 'overlaps',
13 | 'touches',
14 | 'within'
15 | );
16 |
--------------------------------------------------------------------------------
/sql/utils.sql:
--------------------------------------------------------------------------------
1 | --
2 | -- This function checks if the geometry is simple.
3 | --
4 | CREATE FUNCTION _ast_isSimpleGeometry(geom geometry) RETURNS BOOLEAN AS $$
5 | BEGIN
6 | IF NOT ST_IsSimple(geom) THEN
7 | RAISE EXCEPTION 'OMT-G integrity constraint violation.'
8 | USING DETAIL = 'Geometry has anomalous geometric points, such as self intersection or self tangency.';
9 | END IF;
10 |
11 | RETURN 'TRUE';
12 | END;
13 | $$ LANGUAGE plpgsql;
14 |
15 |
16 |
17 | --
18 | -- This function checks if the geometry is a triangle.
19 | --
20 | CREATE FUNCTION _ast_isTriangle(geom geometry) RETURNS BOOLEAN AS $$
21 | BEGIN
22 | IF ST_NPoints(geom) != 4 THEN
23 | RAISE EXCEPTION 'OMT-G integrity constraint violation.'
24 | USING DETAIL = 'Geometry is not a triangle.';
25 | END IF;
26 |
27 | RETURN 'TRUE';
28 | END;
29 | $$ LANGUAGE plpgsql;
30 |
31 |
32 |
33 | --
34 | -- This function returns the name of the column given its type.
35 | --
36 | CREATE FUNCTION _ast_getGeomColumnName(tbl regclass, omtgClass text) RETURNS TEXT AS $$
37 | DECLARE
38 | geoms text array;
39 | BEGIN
40 |
41 | geoms := array(
42 | SELECT attname::text AS type
43 | FROM pg_attribute
44 | WHERE attrelid = tbl AND attnum > 0 AND NOT attisdropped AND format_type(atttypid, atttypmod) = omtgClass
45 | );
46 |
47 | IF array_length(geoms, 1) < 1 THEN
48 | RAISE EXCEPTION 'OMT-G extension error at _ast_getGeomColumnName'
49 | USING DETAIL = 'Table has no column with the given OMT-G domain.';
50 | ELSIF array_length(geoms, 1) > 1 THEN
51 | RAISE EXCEPTION 'OMT-G extension error at _ast_getGeomColumnName'
52 | USING DETAIL = 'Table has multiple columns with the given OMT-G domain.';
53 | END IF;
54 |
55 | RETURN geoms[1];
56 | END;
57 | $$ LANGUAGE plpgsql;
58 |
59 |
60 |
61 | --
62 | -- This function checks if the geometry is a triangle.
63 | --
64 | CREATE FUNCTION _ast_isTriggerEnable(tgrname TEXT) RETURNS BOOLEAN AS $$
65 | BEGIN
66 | IF EXISTS (SELECT tgenabled
67 | FROM pg_trigger WHERE tgname=tgrname AND tgenabled != 'D') THEN
68 | RETURN 'TRUE';
69 | END IF;
70 | RETURN 'FALSE';
71 | END;
72 | $$ LANGUAGE plpgsql;
73 |
74 |
75 |
76 | --
77 | -- This function checks if the argument text can be converted to a numeric type
78 | --
79 | CREATE OR REPLACE FUNCTION _ast_isnumeric(text) RETURNS BOOLEAN AS $$
80 | DECLARE
81 | x NUMERIC;
82 | BEGIN
83 | x = $1::NUMERIC;
84 | RETURN TRUE;
85 | EXCEPTION WHEN others THEN
86 | RETURN FALSE;
87 | END;
88 | $$ LANGUAGE plpgsql;
89 |
90 |
91 |
92 | --
93 | -- This function parses a trigger and extracts its information.
94 | -- (Adapted from the work done by Jim Nasby, @see https://github.com/decibel/cat_tools)
95 | --
96 | CREATE OR REPLACE FUNCTION _ast_triggerParser(
97 | in trigger_oid oid,
98 | out timing text,
99 | out events text[],
100 | out defer text,
101 | out row_statement text,
102 | out when_clause text,
103 | out function_arguments text[],
104 | out function_name text,
105 | out table_name text
106 | ) AS $$
107 | DECLARE
108 | r_trigger pg_catalog.pg_trigger;
109 | v_triggerdef text;
110 | v_create_stanza text;
111 | v_on_clause text;
112 | v_execute_clause text;
113 |
114 | v_work text;
115 | v_array text[];
116 | BEGIN
117 | -- Do this first to make sure trigger exists
118 | v_triggerdef := pg_catalog.pg_get_triggerdef(trigger_oid, true);
119 | SELECT * INTO STRICT r_trigger FROM pg_catalog.pg_trigger WHERE oid = trigger_oid;
120 |
121 | v_create_stanza := format(
122 | 'CREATE %sTRIGGER %I '
123 | , CASE WHEN r_trigger.tgconstraint=0 THEN '' ELSE 'CONSTRAINT ' END
124 | , r_trigger.tgname
125 | );
126 | -- Strip CREATE [CONSTRAINT] TRIGGER ... off
127 | v_work := replace( v_triggerdef, v_create_stanza, '' );
128 |
129 | -- Get BEFORE | AFTER | INSTEAD OF
130 | timing := split_part( v_work, ' ', 1 );
131 | timing := timing || CASE timing WHEN 'INSTEAD' THEN ' OF' ELSE '' END;
132 |
133 | -- Strip off timing clause
134 | v_work := replace( v_work, timing || ' ', '' );
135 |
136 | -- Get array of events (INSERT, UPDATE [OF column, column], DELETE, TRUNCATE)
137 | v_on_clause := ' ON ' || r_trigger.tgrelid::regclass || ' ';
138 | v_array := regexp_split_to_array( v_work, v_on_clause );
139 | events := string_to_array( v_array[1], ' OR ' );
140 |
141 | -- Get the name of the table that fires the trigger
142 | table_name := r_trigger.tgrelid::regclass;
143 |
144 | -- Get everything after ON table_name
145 | v_work := v_array[2];
146 | -- RAISE DEBUG 'v_work "%"', v_work;
147 |
148 | -- Strip off FROM referenced_table if we have it
149 | IF r_trigger.tgconstrrelid<>0 THEN
150 | v_work := replace(
151 | v_work
152 | , 'FROM ' || r_trigger.tgconstrrelid::regclass || ' '
153 | , ''
154 | );
155 | END IF;
156 | -- RAISE DEBUG 'v_work "%"', v_work;
157 |
158 | -- Get function name
159 | function_name := r_trigger.tgfoid::regproc;
160 |
161 | -- Get function arguments
162 | v_execute_clause := ' EXECUTE FUNCTION ' || r_trigger.tgfoid::regproc || E'\\(';
163 | v_array := regexp_split_to_array( v_work, v_execute_clause );
164 | function_arguments := array_remove(regexp_split_to_array(rtrim( v_array[2], ')' ), '\W+'), '');
165 |
166 | -- Get everything prior to EXECUTE PROCEDURE ...
167 | v_work := v_array[1];
168 | -- RAISE DEBUG 'v_work "%"', v_work;
169 |
170 | row_statement := (regexp_matches( v_work, 'FOR EACH (ROW|STATEMENT)' ))[1];
171 |
172 | -- Get [ NOT DEFERRABLE | [ DEFERRABLE ] { INITIALLY IMMEDIATE | INITIALLY DEFERRED } ]
173 | v_array := regexp_split_to_array( v_work, 'FOR EACH (ROW|STATEMENT)' );
174 | -- RAISE DEBUG 'v_work = "%", v_array = "%"', v_work, v_array;
175 | defer := rtrim(v_array[1]);
176 |
177 | IF r_trigger.tgqual IS NOT NULL THEN
178 | when_clause := rtrim(
179 | (regexp_split_to_array( v_array[2], E' WHEN \\(' ))[2]
180 | , ')'
181 | );
182 | END IF;
183 |
184 | RETURN;
185 | END;
186 | $$ LANGUAGE plpgsql;
187 |
188 |
189 |
190 | --
191 | -- Convert array of text to lowercase
192 | --
193 | CREATE FUNCTION _ast_arraylower(p_input text[]) RETURNS text[] AS $$
194 | DECLARE
195 | el text;
196 | r text[];
197 | BEGIN
198 | IF p_input IS NULL THEN
199 | RETURN NULL;
200 | END IF;
201 |
202 | FOREACH el IN ARRAY p_input LOOP
203 | r := r || btrim(lower(el))::text;
204 | END LOOP;
205 | RETURN r;
206 | END;
207 | $$ LANGUAGE plpgsql;
208 |
209 |
210 |
211 | --
212 | -- This function returns the primary key column name.
213 | -- Returns only the first column of composite keys.
214 | --
215 | CREATE FUNCTION _ast_getPrimaryKeyColumn(tname text) RETURNS text AS $$
216 | DECLARE
217 | cname text;
218 | BEGIN
219 |
220 | EXECUTE 'SELECT a.attname
221 | FROM pg_index i
222 | JOIN pg_attribute a ON a.attrelid = i.indrelid AND a.attnum = ANY(i.indkey)
223 | WHERE i.indrelid = '''|| tname ||'''::regclass
224 | AND i.indisprimary;' into cname;
225 |
226 | IF char_length(cname) > 0 THEN
227 | return cname;
228 | else
229 | return '';
230 | END IF;
231 |
232 | END;
233 | $$ LANGUAGE plpgsql;
234 |
--------------------------------------------------------------------------------
/tests/aggregationTest.sql:
--------------------------------------------------------------------------------
1 | drop table tablea;
2 | create table tablea (
3 | id integer primary key,
4 | geom ast_polygon
5 | );
6 |
7 | drop table tableb;
8 | create table tableb (
9 | id integer primary key,
10 | geom ast_polygon
11 | );
12 |
13 | CREATE TRIGGER aggregation_trigger
14 | AFTER INSERT OR UPDATE OR DELETE ON tableb
15 | FOR EACH STATEMENT
16 | EXECUTE PROCEDURE ast_aggregation('tableb', 'geom', 'tablea', 'geom');
17 |
18 |
19 |
20 | delete from tablea;
21 | INSERT INTO tablea(id, geom) VALUES
22 | (1, ST_GeomFromText('MULTIPOLYGON(((1 1, 1 4, 4 4, 4 1, 1 1)))') );
23 |
24 | delete from tableb;
25 | INSERT INTO tableb(id, geom) VALUES
26 | (1, ST_GeomFromText('MULTIPOLYGON(((1 3, 1 4, 4 4, 4 3, 1 3)))') ),
27 | (2, ST_GeomFromText('MULTIPOLYGON(((2 2, 2 3, 3 3, 3 2, 2 2)))') ),
28 | (3, ST_GeomFromText('MULTIPOLYGON(((1 1, 1 3, 2 3, 2 1, 1 1)))') ),
29 | (4, ST_GeomFromText('MULTIPOLYGON(((2 1, 2 2, 3 2, 3 3, 4 3, 4 1, 2 1)))') );
30 |
31 |
32 |
33 | create table tabled (
34 | id integer primary key,
35 | geom ast_polygon
36 | );
37 |
38 | delete from tabled;
39 | INSERT INTO tabled(id, geom) VALUES
40 | (1, ST_GeomFromText('MULTIPOLYGON(((1 3, 1 4, 4 4, 4 3, 1 3)))') ),
41 | (2, ST_GeomFromText('MULTIPOLYGON(((2 2, 2 3, 3 3, 3 2, 2 2)))') ),
42 | (3, ST_GeomFromText('MULTIPOLYGON(((1 1, 1 3, 2 3, 2 1, 1 1)))') ),
43 | (4, ST_GeomFromText('MULTIPOLYGON(((2 1, 2 2, 3 2, 3 3, 4 3, 4 1, 2 1)))') ),
44 | (5, ST_GeomFromText('MULTIPOLYGON(((0.5 0.5, 0.5 3.5, 2.5 3.5, 2.5 0.5, 0.5 0.5)))') );
45 |
46 |
47 | SELECT *
48 | FROM tablea AS a
49 | LEFT JOIN tableb AS b
50 | ON NOT ST_COVERS(a.geom, b.geom)
51 | WHERE b.geom IS NOT NULL;
52 |
53 |
54 |
55 | -- 1. Pi intersection W = Pi, for all i such as 0 <= i <= n
56 | SELECT EXISTS (
57 | select 1
58 | from tablec c
59 | where c.CTID not in
60 | (
61 | select b.CTID
62 | from tablea a, tablec b
63 | where ST_Equals(ST_Intersection(a.geom, b.geom), b.geom)
64 | )
65 | );
66 |
67 | -- 3. ((Pi touch Pj) or (Pi disjoint Pj)) = T for all i, j such as i != j
68 | select *
69 | from tabled b1, tabled b2
70 | where b1.ctid < b2.ctid and
71 | (not st_touches(b1.geom, b2.geom) and not st_disjoint(b1.geom, b2.geom));
72 |
73 | --2. (W intersection all P) = W
74 | WITH union_geom AS (
75 | select st_union(geom) as geom
76 | from tableb
77 | )
78 | select st_equals(a.geom, b.geom)
79 | from tablea a, union_geom b;
80 |
81 | WITH union_geom AS (
82 | select st_union(geom) as geom
83 | from tablec
84 | )
85 | select st_equals(a.geom, b.geom)
86 | from tablea a left join union_geom b
87 | on st_intersects(a.geom, b.geom);
88 |
89 |
90 |
91 | delete from tablea;
92 | INSERT INTO tablea(id, geom) VALUES
93 | (1, ST_GeomFromText('MULTIPOLYGON(((1 1, 1 4, 4 4, 4 1, 1 1)))') ),
94 | (2, ST_GeomFromText('MULTIPOLYGON(((5 5, 5 6, 6 6, 6 5, 5 5)))') );
95 |
96 | delete from tableb;
97 | INSERT INTO tableb(id, geom) VALUES
98 | (1, ST_GeomFromText('MULTIPOLYGON(((1 3, 1 4, 4 4, 4 3, 1 3)))') ),
99 | (2, ST_GeomFromText('MULTIPOLYGON(((2 2, 2 3, 3 3, 3 2, 2 2)))') ),
100 | (3, ST_GeomFromText('MULTIPOLYGON(((1 1, 1 3, 2 3, 2 1, 1 1)))') ),
101 | (4, ST_GeomFromText('MULTIPOLYGON(((2 1, 2 2, 3 2, 3 3, 4 3, 4 1, 2 1)))') ),
102 | (5, ST_GeomFromText('MULTIPOLYGON(((5 5, 5 6, 6 6, 6 5, 5 5)))') );
103 |
--------------------------------------------------------------------------------
/tests/arcarcTest.sql:
--------------------------------------------------------------------------------
1 | drop table arc;
2 | create table arc (
3 | id integer,
4 | geom ast_biline
5 | );
6 |
7 | create trigger arcarc_trigger
8 | AFTER INSERT OR UPDATE OR DELETE ON arc
9 | FOR EACH STATEMENT
10 | EXECUTE PROCEDURE ast_arcarcnetwork('arc', 'geom');
11 |
12 | delete from arc;
13 | insert into arc (id, geom) values
14 | (1, ST_GeomFromText('LINESTRING(1 1, 1 2)')),
15 | (2, ST_GeomFromText('LINESTRING(1 1, 2 1)')),
16 | (3, ST_GeomFromText('LINESTRING(2 1, 2 2)')),
17 | (4, ST_GeomFromText('LINESTRING(1 2, 3 2)')),
18 | (6, ST_GeomFromText('LINESTRING(1 3, 3 3)'));
19 |
--------------------------------------------------------------------------------
/tests/arcnodeTest.sql:
--------------------------------------------------------------------------------
1 | drop table node;
2 | CREATE TABLE node (
3 | id serial primary key,
4 | geom ast_node
5 | );
6 |
7 | drop table arc;
8 | CREATE TABLE arc (
9 | id serial primary key,
10 | geom ast_uniline
11 | spatial_constraint(network, node(geom))
12 | );
13 |
14 | CREATE TRIGGER check_arcnode_trigger
15 | AFTER INSERT OR UPDATE OR DELETE ON arc
16 | FOR EACH STATEMENT
17 | EXECUTE PROCEDURE ast_arcnodenetwork('arc', 'geom', 'node', 'geom');
18 |
19 | INSERT INTO node(geom)
20 | VALUES (ST_GeomFromText('POINT(0 1)')),
21 | (ST_GeomFromText('POINT(1 1)')),
22 | (ST_GeomFromText('POINT(1 2)')),
23 | (ST_GeomFromText('POINT(2 1)')),
24 | (ST_GeomFromText('POINT(1 0)')),
25 | (ST_GeomFromText('POINT(2 0)'));
26 |
27 | INSERT INTO arc(geom)
28 | VALUES (ST_GeomFromText('LINESTRING(0 1, 0.5 1.0, 1 1)') ),
29 | (ST_GeomFromText('LINESTRING(1 2, 1.0 1.5, 1 1)') ),
30 | (ST_GeomFromText('LINESTRING(1 1, 1.0 0.5, 1 0)') ),
31 | (ST_GeomFromText('LINESTRING(1 1, 1.5 1.0, 2 1)') ),
32 | (ST_GeomFromText('LINESTRING(1 0, 1.5 0.0, 2 0)') );
33 |
--------------------------------------------------------------------------------
/tests/containsTest.sql:
--------------------------------------------------------------------------------
1 | drop table tablea;
2 | create table tablea (
3 | id integer primary key,
4 | geom ast_polygon
5 | );
6 |
7 | drop table tableb;
8 | create table tableb (
9 | id integer primary key,
10 | geom ast_point
11 | );
12 |
13 | delete from tablea;
14 | INSERT INTO tablea(id, geom) VALUES
15 | (1, ST_GeomFromText('MULTIPOLYGON(((0 0, 0 1, 1 1, 1 0, 0 0)))') ),
16 | (2, ST_GeomFromText('MULTIPOLYGON(((1 0, 1 1, 2 1, 2 0, 1 0)))') ),
17 | (3, ST_GeomFromText('MULTIPOLYGON(((1 1, 1 2, 2 2, 2 1, 1 1)))') );
18 |
19 | delete from tableb;
20 | INSERT INTO tableb(id, geom) VALUES
21 | (10, ST_GeomFromText('POINT(0.5 0.5)')),
22 | (11, ST_GeomFromText('POINT(1.5 0.5)')),
23 | (12, ST_GeomFromText('POINT(1.7 0.2)'));
24 |
25 |
26 | select a.id
27 | from tablea as a
28 | left join tableb as b
29 | on st_contains(a.geom, b.geom)
30 | where b.geom is null;
31 |
--------------------------------------------------------------------------------
/tests/crossesTest.sql:
--------------------------------------------------------------------------------
1 | drop table tablea;
2 | drop table tableb;
3 |
4 | create table tablea (
5 | id integer primary key,
6 | geom ast_line
7 | );
8 |
9 | drop table tableb;
10 | create table tableb (
11 | id integer primary key,
12 | geom ast_polygon
13 | );
14 |
15 | delete from tablea;
16 | INSERT INTO tablea(id, geom) VALUES
17 | (1, ST_GeomFromText('MULTILINESTRING((1 1, 5 1))') ),
18 | (2, ST_GeomFromText('MULTILINESTRING((1 3, 5 3))') );
19 |
20 |
21 | delete from tableb;
22 | INSERT INTO tableb(id, geom) VALUES
23 | (10, ST_GeomFromText('MULTIPOLYGON(((0 0, 0 2, 2 2, 2 0, 0 0)))') ),
24 | (20, ST_GeomFromText('MULTIPOLYGON(((2 0, 2 2, 4 2, 4 0, 2 0)))') );
25 |
26 |
27 | CREATE TRIGGER crosses_trigger
28 | AFTER INSERT OR UPDATE ON tablea
29 | FOR EACH STATEMENT
30 | EXECUTE PROCEDURE ast_spatialrelationship('tablea', 'geom', 'tableb', 'geom', 'crosses');
31 |
32 |
33 | select not exists(
34 | select 1
35 | from tablea as a
36 | left join tableb as b
37 | on st_crosses(a.geom, b.geom)
38 | where b.geom is null
39 | );
40 |
--------------------------------------------------------------------------------
/tests/disjointTest.sql:
--------------------------------------------------------------------------------
1 | drop table tablea;
2 | create table tablea (
3 | id integer primary key,
4 | geom ast_polygon
5 | );
6 |
7 | drop table tableb;
8 | create table tableb (
9 | id integer primary key,
10 | geom ast_point
11 | );
12 |
13 | delete from tablea;
14 | INSERT INTO tablea(id, geom) VALUES
15 | (1, ST_GeomFromText('MULTIPOLYGON(((0 0, 0 1, 1 1, 1 0, 0 0)))') ),
16 | (2, ST_GeomFromText('MULTIPOLYGON(((1 0, 1 1, 2 1, 2 0, 1 0)))') );
17 |
18 |
19 | delete from tableb;
20 | INSERT INTO tableb(id, geom) VALUES
21 | (10, ST_GeomFromText('POINT(0.5 0.5)'));
22 |
23 |
24 | select not exists (
25 | select 1
26 | from tablea as a
27 | left join tableb as b
28 | on st_disjoint(a.geom, b.geom)
29 | where b.geom is null
30 | );
31 |
--------------------------------------------------------------------------------
/tests/distantTest.sql:
--------------------------------------------------------------------------------
1 | create table school (
2 | id integer primary key,
3 | geom ast_point
4 | );
5 |
6 | create table gas_station (
7 | id integer primary key,
8 | geom ast_point
9 | );
10 |
11 | CREATE TRIGGER distant_trigger
12 | AFTER INSERT OR UPDATE ON school
13 | FOR EACH STATEMENT
14 | EXECUTE PROCEDURE ast_spatialrelationship('school', 'geom', 'gas_station', 'geom', 'distant', 2);
15 |
16 |
17 | delete from school;
18 | INSERT INTO school(id, geom) VALUES
19 | (10, ST_GeomFromText('POINT(0 0)')),
20 | (11, ST_GeomFromText('POINT(10 0)'));
21 |
22 |
23 | delete from gas_station;
24 | INSERT INTO gas_station(id, geom) VALUES
25 | (3, ST_GeomFromText('POINT(3 0)')),
26 | (4, ST_GeomFromText('POINT(4 0)')),
27 | (5, ST_GeomFromText('POINT(5 0)')),
28 | (6, ST_GeomFromText('POINT(6 0)')),
29 | (7, ST_GeomFromText('POINT(7 0)'));
30 |
--------------------------------------------------------------------------------
/tests/intersectsTest.sql:
--------------------------------------------------------------------------------
1 | drop table tablea;
2 | create table tablea (
3 | id integer primary key,
4 | geom ast_polygon
5 | );
6 |
7 | drop table tableb;
8 | create table tableb (
9 | id integer primary key,
10 | geom ast_point
11 | );
12 |
13 | delete from tablea;
14 | INSERT INTO tablea(id, geom) VALUES
15 | (1, ST_GeomFromText('MULTIPOLYGON(((0 0, 0 1, 1 1, 1 0, 0 0)))') ),
16 | (2, ST_GeomFromText('MULTIPOLYGON(((1 0, 1 1, 2 1, 2 0, 1 0)))') ),
17 | (3, ST_GeomFromText('MULTIPOLYGON(((1 1, 1 2, 2 2, 2 1, 1 1)))') );
18 |
19 | delete from tableb;
20 | INSERT INTO tableb(id, geom) VALUES
21 | (10, ST_GeomFromText('POINT(0.5 0.5)')),
22 | (11, ST_GeomFromText('POINT(1.5 0.5)')),
23 | (12, ST_GeomFromText('POINT(10.5 10.5)'));
24 |
25 |
26 | select not exists(
27 | select 1
28 | from tablea as a
29 | left join tableb as b
30 | on st_intersects(a.geom, b.geom)
31 | where b.geom is null
32 | );
33 |
--------------------------------------------------------------------------------
/tests/isolinesTest.sql:
--------------------------------------------------------------------------------
1 | DROP TABLE Curvas;
2 | CREATE TABLE Curvas (
3 | id SERIAL,
4 | name VARCHAR(50),
5 | geom ast_ISOLINE,
6 | CONSTRAINT pk_Temperature PRIMARY KEY (id)
7 | );
8 |
9 | -- Create the spatial index on geom column of Temperature
10 | CREATE INDEX Curvas_IDX
11 | ON Curvas
12 | USING GIST (geom);
13 |
14 |
15 |
16 | -- Test 1 - Separated
17 |
18 | delete from Curvas;
19 |
20 | INSERT INTO Curvas(name, geom)
21 | VALUES ( 'A', ST_GeomFromText('LINESTRING(0 0, 1 1, 2 0, 3 0)') );
22 |
23 | INSERT INTO Curvas(name, geom)
24 | VALUES ( 'B', ST_GeomFromText('LINESTRING(0 1, 1 2, 2 1, 3 1)') );
25 |
26 | INSERT INTO Curvas(name, geom)
27 | VALUES ( 'C', ST_GeomFromText('LINESTRING(0 2, 1 3, 2 2, 3 2)') );
28 |
29 |
30 |
31 |
32 | -- Test 2 - Separated with touch
33 |
34 | delete from Curvas;
35 |
36 | INSERT INTO Curvas(name, geom)
37 | VALUES ( 'A', ST_GeomFromText('LINESTRING(0 0, 1 0, 2 1, 3 0)') );
38 |
39 | INSERT INTO Curvas(name, geom)
40 | VALUES ( 'B', ST_GeomFromText('LINESTRING(0 1, 1 1, 2 2, 3 1)') );
41 |
42 | INSERT INTO Curvas(name, geom)
43 | VALUES ( 'C', ST_GeomFromText('LINESTRING(0 2, 1 2, 2 2, 3 2)') );
44 |
45 |
46 | -- Test 3 - Double Square
47 |
48 | delete from Curvas;
49 |
50 | INSERT INTO Curvas( name, geom)
51 | VALUES ('A', ST_GeomFromText('LINESTRING(0 0, 0 3, 3 3, 3 0, 0 0)') );
52 |
53 | INSERT INTO Curvas(name, geom)
54 | VALUES ('B', ST_GeomFromText('LINESTRING(1 1, 1 2, 2 2, 2 1, 1 1)') );
55 |
56 |
57 | -- Test 4 - Square and half square overlap
58 |
59 | delete from Curvas;
60 |
61 | INSERT INTO Curvas(name, geom)
62 | VALUES ('A', ST_GeomFromText('LINESTRING(0 0, 0 3, 3 3, 0 0)') );
63 |
64 | INSERT INTO Curvas(name, geom)
65 | VALUES ( 'B', ST_GeomFromText('LINESTRING(1 1, 1 2, 2 2, 2 1, 1 1)') );
66 |
67 |
68 | -- Test 5 - Swastika
69 |
70 | delete from Curvas;
71 |
72 | INSERT INTO Curvas(name, geom)
73 | VALUES ('A', ST_GeomFromText('LINESTRING(0 0, 0 1, 1 1, 2 1, 2 2)') );
74 |
75 | INSERT INTO Curvas(name, geom)
76 | VALUES ('B', ST_GeomFromText('LINESTRING(0 2, 1 2, 1 1, 1 0, 2 0)') );
77 |
--------------------------------------------------------------------------------
/tests/lineTest.sql:
--------------------------------------------------------------------------------
1 | drop table if exists walls;
2 |
3 | create table walls (
4 | id SERIAL,
5 | name VARCHAR(20),
6 | geom ast_LINE
7 | );
8 |
9 | INSERT INTO walls(name, geom)
10 | VALUES ('A', ST_GeomFromText('MULTILINESTRING((0 0, 0 1, 1 1, 1 0))') );
11 |
12 | INSERT INTO walls(name, geom)
13 | VALUES ('B', ST_GeomFromText('MULTILINESTRING((1 2, 1 3, 2 3, 2 2, 1 2))') );
14 |
15 | INSERT INTO walls(name, geom)
16 | VALUES ('c', ST_GeomFromText('MULTILINESTRING((0.5 0.5, 0 1, 1 1, 1 0, 0.5 0.5))') );
17 |
18 | INSERT INTO walls(name, geom)
19 | VALUES ('d', ST_GeomFromText('MULTILINESTRING((0 0, 2 0, 1 1, -1 -1))') );
20 |
21 | INSERT INTO walls(name, geom)
22 | VALUES ('e', ST_GeomFromText('MULTILINESTRING((0 0, 2 0, 1 1))') );
23 |
--------------------------------------------------------------------------------
/tests/nearTest.sql:
--------------------------------------------------------------------------------
1 | drop table tablea;
2 | create table tablea (
3 | id integer primary key,
4 | geom ast_point
5 | );
6 |
7 | drop table tableb;
8 | create table tableb (
9 | id integer primary key,
10 | geom ast_point
11 | );
12 |
13 | delete from tableb;
14 | INSERT INTO tableb(id, geom) VALUES
15 | (10, ST_GeomFromText('POINT(0 0)')),
16 | (11, ST_GeomFromText('POINT(10 0)'));
17 |
18 |
19 | delete from tablea;
20 | INSERT INTO tablea(id, geom) VALUES
21 | (1, ST_GeomFromText('POINT(1 0)')),
22 | (2, ST_GeomFromText('POINT(2 0)')),
23 | (3, ST_GeomFromText('POINT(3 0)')),
24 | (4, ST_GeomFromText('POINT(4 0)')),
25 | (5, ST_GeomFromText('POINT(5 0)'));
26 |
27 | delete from tablec;
28 | INSERT INTO tablec(id, geom)
29 | VALUES (ST_GeomFromText('LINESTRING(0 0, 20 0)') );
30 |
31 |
32 | select exists(
33 | select 1
34 | from tablea as a
35 | left join tableb as b
36 | on st_dwithin(a.geom, b.geom, 0.5)
37 | where b.geom is not null
38 | );
39 |
--------------------------------------------------------------------------------
/tests/planarsubdivisionTest.sql:
--------------------------------------------------------------------------------
1 | drop table if exists cities;
2 |
3 | create table cities (
4 | id SERIAL,
5 | name VARCHAR(20),
6 | geom ast_PLANARSUBDIVISION
7 | );
8 |
9 | -- Test 1 - No gaps
10 |
11 | delete from cities;
12 |
13 | INSERT INTO cities(name, geom)
14 | VALUES ('A', ST_GeomFromText('MULTIPOLYGON(((0 0, 0 1, 1 1, 1 0, 0 0)))') );
15 |
16 | INSERT INTO cities(name, geom)
17 | VALUES ('B', ST_GeomFromText('MULTIPOLYGON(((0 1, 0 2, 1 2, 1 1, 0 1)))') );
18 |
19 | INSERT INTO cities(name, geom)
20 | VALUES ('C', ST_GeomFromText('MULTIPOLYGON(((1 1, 1 2, 2 2, 2 1, 1 1)))') );
21 |
22 | INSERT INTO cities(name, geom)
23 | VALUES ('D', ST_GeomFromText('MULTIPOLYGON(((1 0, 1 1, 2 1, 2 0, 1 0)))') );
24 |
25 | INSERT INTO cities(name, geom)
26 | VALUES ('E', ST_GeomFromText('MULTIPOLYGON(((2 0, 2 2, 3 2, 3 0, 2 0)))') );
27 |
28 |
29 | -- Test 3 - No gaps - 1 overlap
30 |
31 | delete from cities;
32 |
33 | INSERT INTO cities(name, geom)
34 | VALUES ('A', ST_GeomFromText('MULTIPOLYGON(((0 0, 0 1, 1 1, 1 0, 0 0)))') );
35 |
36 | INSERT INTO cities(name, geom)
37 | VALUES ('B', ST_GeomFromText('MULTIPOLYGON(((0 1, 0 2, 1 2, 1 1, 0 1)))') );
38 |
39 | INSERT INTO cities(name, geom)
40 | VALUES ('C', ST_GeomFromText('MULTIPOLYGON(((1 1, 1 2, 2 2, 2 1, 1 1)))') );
41 |
42 | INSERT INTO cities(name, geom)
43 | VALUES ('D', ST_GeomFromText('MULTIPOLYGON(((1 0, 1 1, 2 1, 2 0, 1 0)))') );
44 |
45 | INSERT INTO cities(name, geom)
46 | VALUES ('F', ST_GeomFromText('MULTIPOLYGON(((1.5 1.5, 1.5 2.5, 2.5 2.5, 2.5 1.5, 1.5 1.5)))') );
47 |
--------------------------------------------------------------------------------
/tests/polygonTest.sql:
--------------------------------------------------------------------------------
1 | drop table if exists cities;
2 |
3 | create table cities (
4 | id SERIAL,
5 | name VARCHAR(20),
6 | geom ast_POLYGON
7 | );
8 |
9 | INSERT INTO cities(name, geom)
10 | VALUES ('A', ST_GeomFromText('MULTIPOLYGON(((0 0, 0 1, 1 1, 1 0, 0 0)))') );
11 |
12 | INSERT INTO cities(name, geom)
13 | VALUES ('B', ST_GeomFromText('MULTIPOLYGON(((1 2, 1 3, 2 3, 2 2, 1 2)))') );
14 |
15 | INSERT INTO cities(name, geom)
16 | VALUES ('c', ST_GeomFromText('MULTIPOLYGON(((0.5 0.5, 0 1, 1 1, 1 0, 0.5 0.5)))') );
17 |
--------------------------------------------------------------------------------
/tests/touchesTest.sql:
--------------------------------------------------------------------------------
1 | drop table tablea;
2 | create table tablea (
3 | id integer primary key,
4 | geom ast_polygon
5 | );
6 |
7 | drop table tableb;
8 | create table tableb (
9 | id integer primary key,
10 | geom ast_polygon
11 | );
12 |
13 | delete from tablea;
14 | INSERT INTO tablea(id, geom) VALUES
15 | (1, ST_GeomFromText('MULTIPOLYGON(((1 0, 1 1, 2 1, 2 0, 1 0)))') ),
16 | (2, ST_GeomFromText('MULTIPOLYGON(((4 0, 4 1, 5 1, 5 0, 4 0)))') ),
17 | (3, ST_GeomFromText('MULTIPOLYGON(((6 0, 6 1, 7 1, 7 0, 6 0)))') );
18 |
19 |
20 |
21 | delete from tableb;
22 | INSERT INTO tableb(id, geom) VALUES
23 | (10, ST_GeomFromText('MULTIPOLYGON(((0 0, 0 1, 1 1, 1 0, 0 0)))') ),
24 | (20, ST_GeomFromText('MULTIPOLYGON(((3 0, 3 1, 4 1, 4 0, 3 0)))') );
25 |
26 |
27 |
28 | select not exists(
29 | select 1
30 | from tablea as a
31 | left join tableb as b
32 | on st_touches(a.geom, b.geom)
33 | where b.geom is null
34 | );
35 |
--------------------------------------------------------------------------------
/tests/withinTest.sql:
--------------------------------------------------------------------------------
1 | drop table tablea;
2 | create table tablea (
3 | id integer primary key,
4 | geom ast_polygon
5 | );
6 |
7 | drop table tableb;
8 | create table tableb (
9 | id integer primary key,
10 | geom ast_point
11 | );
12 |
13 | delete from tablea;
14 | INSERT INTO tablea(id, geom) VALUES
15 | (1, ST_GeomFromText('MULTIPOLYGON(((0 0, 0 1, 1 1, 1 0, 0 0)))') ),
16 | (2, ST_GeomFromText('MULTIPOLYGON(((1 0, 1 1, 2 1, 2 0, 1 0)))') ),
17 | (3, ST_GeomFromText('MULTIPOLYGON(((1 1, 1 2, 2 2, 2 1, 1 1)))') );
18 |
19 | delete from tableb;
20 | INSERT INTO tableb(id, geom) VALUES
21 | (10, ST_GeomFromText('POINT(0.5 0.5)')),
22 | (11, ST_GeomFromText('POINT(1.5 0.5)')),
23 | (12, ST_GeomFromText('POINT(10 10)'));
24 |
25 |
26 | select a.id
27 | from tablea as a
28 | left join tableb as b
29 | on st_within(a.geom, b.geom)
30 | where b.geom is null;
31 |
--------------------------------------------------------------------------------