1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176 177 178 179 180 181 182 183 184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213 214 215 216 217 218 219 220 221 222 223 224 225 226 227 228 229 230 231 232 233 234 235 236 237 238 239 240 241 242 243 244 245 246 247 248 249 250 251 252 253 254 255 256 257 258 259 260 261 262 263 264 265 266 267 268 269 270 271 272 273 274 275 276 277 278 279 280 281 282 283 284 285 286 287 288 289 290 291 292 293 294 295 296 297 298 299 300 301 302 303 304 305 306 307 308 309 310 311 312 313 314 315 316 317 318 319 320 321 322 323 324 325 326 327 328 329 330 331 332 333 334 335 336 337 338 339 340 341 342 343 344 345 346 347 348 349 350 351 352 353 354 355 356 357 358 359 360 361 362 363 364 365 366 367 368 369 370 371 372 373 374 375 376 377 378 379 380 381 382 383 384 385 386 387 388 389 390 391 392 393 394 395 396 397 398 399 400 401 402 403 404 405 406 407 408 409 410 411 412 413 414 415 416 417 418 419 420 421 422 423 424 425 426 427 428 429 430 431 432 433 434 435 436 437 438 439 440 441 442 443 444 445 446 447 448 449 450 451 452 453 454 455 456 457 458 459 460 461 462 463 464 465 466 467 468 469 470 471 472 473 474 475 476 477 478 479 480 481 482 483 484 485 486 487 488 489 490 491 492 493 494 495 496 497 498 499 500 501 502 503 504 505 506 507 508 509 510 511 512 513 514 515 516 517 518 519 520 521 522 523 524 525 526 527 528 529 530 531 532 533 534 535 536 537 538 539 540 541 542 543 544 545 546 547 548 549 550 551 552 553 554 555 556 557 558 559 560 561 562 563 564 565 566 567 568 569 570 571 572 573 574 575 576 577 578 579 580 581 582 583 584 585 586 587 588 589 590 591 592 593 594 595 596 597 598 599 600 601 602 603 604 605 606 607 608 609 610 611 612 613 614 615 616 617 618 619 620 621 622 623 624 625 626 627 628 629 630 631 632 633 634 635 636 637 638 639 640 641 642 643 644 645 646 647 648 649 650 651 652 653 654 655 656 657 658 659 660 661 662 663 664 665 666 667 668 669 670 671 672 673 674 675 676 677 678 679 680 681 682 683 684 685 686 687 688 689 690 691 692 693 694 695 696 697 698 699 700 701 702 703 704 705 706 707 708 709 710 711 712 713 714 715 716 717 718 719 720 721 722 723 724 725 726 727 728 729 730 731 732 733 734 735 736 737 738 739 740 741 742 743 744 745 746 747 748 749 750 751 752 753 754 755 756 757 758 759 760 761 762 763 764 765 766 767 768 769 770 771 772 773 774 775 776 777 778 779 780 781 782 783 784 785 786 787 788 789 790 791 792 793 794 795 796 797 798 799 800 801 802 803 804 805 806 807 808 809 810 811 812 813 814 815 816 817 818 819 820 821 822 823 824 825 826 827 828 829 830 831 832 833 834 835 836 837 838 839 840 841 842 843 844 845 846 847 848 849 850 851 852 853 854 855 856 857 858 859 860 861 862 863 864 865 866 867 868 869 870 871 872 873 874 875 876 877 878 879 880 881 882 883 884 885 886 887 888 889 890 891 892 893 894 895 896 897 898 899 900 901 902 903 904 905 906 907 908 909 910 911 912 913 914 915 916 917 918 919 920 921 922 923 924 925 926 927 928 929 930 931 932 933 934 935 936 937 938 939 940 941 942 943 944 945 946 947 948 949 950 951 952 953 954 955 956 957 958 959 960 961 962 963 964 965 966 967 968 969 970 971 972 973 974 975 976 977 978 979 980 981 982 983 984 985 986 987 988 989 990 991 992 993 994 995 996 997 998 999 1000 1001 1002 1003 1004 1005 1006 1007 1008 1009 1010 1011 1012 1013 1014 1015 1016 1017 1018 1019 1020 1021 1022 1023 1024 1025 1026 1027 1028 1029 1030 1031 1032 1033 1034 1035 1036 1037 1038 1039 1040 1041 1042 1043 1044 1045 1046 1047 1048 1049 1050 1051 1052 1053 1054 1055 1056 1057 1058 1059 1060 1061 1062 1063 1064 1065 1066 1067 1068 1069 1070 1071 1072 1073 1074 1075 1076 1077 1078 1079 1080 1081 1082 1083 1084 1085 1086 1087 1088 1089 1090 1091 1092 1093 1094 1095 1096 1097 1098 1099 1100 1101 1102 1103 1104 1105 1106 1107 1108 1109 1110 1111 1112 1113 1114 1115 1116 1117 1118 1119 1120 1121 1122 1123 1124 1125 1126 1127 1128 1129 1130 1131 1132 1133 1134 1135 1136 1137 1138 1139 1140 1141 1142 1143 1144 1145 1146 1147 1148 1149 1150 1151 1152 1153 1154 1155 1156 1157 1158 1159 1160 1161 1162 1163 1164 1165 1166 1167 1168 1169 1170 1171 1172 1173 1174 1175 1176 1177 1178 1179 1180 1181 1182 1183 1184 1185 1186 1187 1188 1189 1190 1191 1192 1193 1194 1195 1196 1197 1198 1199 1200 1201 1202 1203 1204 1205 1206 1207 1208 1209 1210 1211 1212 1213 1214 1215 1216 1217 1218 1219 1220 1221 1222 1223 1224 1225 1226 1227 1228 1229 1230 1231 1232 1233 1234 1235 1236 1237 1238 1239 1240 1241 1242 1243 1244 1245 1246 1247 1248 1249 1250 1251 1252 1253 1254 1255 1256 1257 1258 1259 1260 1261 1262 1263 1264 1265 1266 1267 1268 1269 1270 1271 1272 1273 1274 1275 1276 1277 1278 1279 1280 1281 1282 1283 1284 1285 1286 1287 1288 1289 1290 1291 1292 1293 1294 1295 1296 1297 1298 1299 1300 1301 1302 1303 1304 1305 1306 1307 1308 1309 1310 1311 1312 1313 1314 1315 1316 1317 1318 1319 1320 1321 1322 1323 1324 1325 1326 1327 1328 1329 1330 1331 1332 1333 1334 1335 1336 1337 1338 1339 1340 1341 1342 1343 1344 1345 1346 1347 1348 1349 1350 1351 1352 1353 1354 1355 1356 1357 1358 1359 1360 1361 1362 1363 1364 1365 1366 1367 1368 1369 1370 1371 1372 1373 1374 1375 1376 1377 1378 1379 1380 1381 1382 1383 1384 1385 1386 1387 1388 1389 1390 1391 1392 1393 1394 1395 1396 1397 1398 1399 1400 1401 1402 1403 1404 1405 1406 1407 1408 1409 1410 1411 1412 1413 1414 1415 1416 1417 1418 1419 1420 1421 1422 1423 1424 1425 1426 1427 1428 1429 1430 1431 1432 1433 1434 1435 1436 1437 1438 1439 1440 1441 1442 1443 1444 1445 1446 1447 1448 1449 1450 1451 1452 1453 1454 1455 1456 1457 1458 1459 1460 1461 1462 1463 1464 1465 1466 1467 1468 1469 1470 1471 1472 1473 1474 1475 1476 1477 1478 1479 1480 1481 1482 1483 1484 1485 1486 1487 1488 1489 1490 1491 1492 1493 1494 1495 1496 1497 1498 1499 1500 1501 1502 1503 1504 1505 1506 1507 1508 1509 1510 1511 1512 1513 1514 1515 1516 1517 1518 1519 1520 1521 1522 1523 1524 1525 1526 1527 1528 1529 1530 1531 1532 1533 1534 1535 1536 1537 1538 1539 1540 1541 1542 1543 1544 1545 1546 1547 1548 1549 1550 1551 1552 1553 1554 1555 1556 1557 1558 1559 1560 1561 1562 1563 1564 1565 1566 1567 1568 1569 1570 1571 1572 1573 1574 1575 1576 1577 1578 1579 1580 1581 1582 1583 1584 1585 1586 1587 1588 1589 1590 1591 1592 1593 1594 1595 1596 1597 1598 1599 1600 1601 1602 1603 1604 1605 1606 1607 1608 1609 1610 1611 1612 1613 1614 1615 1616 1617 1618 1619 1620 1621 1622 1623 1624 1625 1626 1627 1628 1629 1630 1631 1632 1633 1634 1635 1636 1637 1638 1639 1640 1641 1642 1643 1644 1645 1646 1647 1648 1649 1650 1651 1652 1653 1654 1655 1656 1657 1658 1659 1660 1661 1662 1663 1664 1665 1666 1667 1668 1669 1670 1671 1672 1673 1674 1675 1676 1677 1678 1679 1680 1681 1682 1683 1684 1685 1686 1687 1688 1689 1690 1691 1692 1693 1694 1695 1696 1697 1698 1699 1700 1701 1702 1703 1704 1705 1706 1707 1708 1709 1710 1711 1712 1713 1714 1715 1716 1717 1718 1719 1720 1721 1722 1723 1724 1725 1726 1727 1728 1729 1730 1731 1732 1733 1734 1735 1736 1737 1738 1739 1740 1741 1742 1743 1744 1745 1746 1747 1748 1749 1750 1751 1752 1753 1754 1755 1756 1757 1758 1759 1760 1761 1762 1763 1764 1765 1766 1767 1768 1769 1770 1771 1772 1773 1774 1775 1776 1777 1778 1779 1780 1781 1782 1783 1784 1785 1786 1787 1788 1789 1790 1791 1792 1793 1794 1795 1796 1797 1798 1799 1800 1801 1802 1803 1804 1805 1806 1807 1808 1809 1810 1811 1812 1813 1814 1815 1816 1817 1818 1819 1820 1821 1822 1823 1824 1825 1826 1827 1828 1829 1830 1831 1832 1833 1834 1835 1836 1837 1838 1839 1840 1841 1842 1843 1844 1845 1846 1847 1848 1849 1850 1851 1852 1853 1854 1855 1856 1857 1858 1859 1860 1861 1862 1863 1864 1865 1866 1867 1868 1869 1870 1871 1872 1873 1874 1875 1876 1877 1878 1879 1880 1881 1882 1883 1884 1885 1886 1887 1888 1889 1890 1891 1892 1893 1894 1895 1896 1897 1898 1899 1900 1901 1902 1903 1904 1905 1906 1907 1908 1909 1910 1911 1912 1913 1914 1915 1916 1917 1918 1919 1920 1921 1922 1923 1924 1925 1926 1927 1928 1929 1930 1931 1932 1933 1934 1935 1936 1937 1938 1939 1940 1941 1942 1943 1944 1945 1946 1947 1948 1949 1950 1951 1952 1953 1954 1955 1956 1957 1958 1959 1960 1961 1962 1963 1964 1965 1966 1967 1968 1969 1970 1971 1972 1973 1974 1975 1976 1977 1978 1979 1980 1981 1982 1983 1984 1985 1986 1987 1988 1989 1990 1991 1992 1993 1994 1995 1996 1997 1998 1999 2000 2001 2002 2003 2004 2005 2006 2007 2008 2009 2010 2011 2012 2013 2014 2015 2016 2017 2018 2019 2020 2021 2022 2023 2024 2025 2026 2027 2028 2029 2030 2031 2032 2033 2034 2035 2036 2037 2038 2039 2040 2041 2042 2043 2044 2045 2046 2047 2048 2049 2050 2051 2052 2053 2054 2055 2056 2057 2058 2059 2060 2061 2062 2063 2064 2065 2066 2067 2068 2069 2070
|
-- - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - -
--
--
-- PostGIS - Spatial Types for PostgreSQL
-- http://postgis.net
--
-- Copyright (C) 2010, 2011 Sandro Santilli <strk@kbt.io>
-- Copyright (C) 2005 Refractions Research Inc.
--
-- This is free software; you can redistribute and/or modify it under
-- the terms of the GNU General Public Licence. See the COPYING file.
--
-- Author: Sandro Santilli <strk@kbt.io>
--
-- - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - -
--
-- STATUS:
--
-- All objects are created in the 'topology' schema.
--
-- We have PostGIS-specific objects and SQL/MM objects.
-- PostGIS-specific objects have no prefix, SQL/MM ones
-- have the ``ST_' prefix.
--
-- [PostGIS-specific]
--
-- TABLE topology
-- Table storing topology info (name, srid, precision)
--
-- TYPE TopoGeometry
-- Complex type storing topology_id, layer_id, geometry type
-- and topogeometry id.
--
-- DOMAIN TopoElement
-- An array of two elements: element_id and element_type.
-- In fact, an array of integers.
--
-- DOMAIN TopoElementArray
-- An array of element_id,element_type values.
-- In fact, a bidimensional array of integers:
-- '{{id,type}, {id,type}, ...}'
--
-- FUNCTION CreateTopology(name, [srid], [precision])
-- Initialize a new topology (creating schema with
-- edge,face,node,relation) and add a record into
-- the topology.topology table.
-- TODO: add triggers (or rules, or whatever) enforcing
-- precision to the edge and node tables.
--
-- FUNCTION DropTopology(name)
-- Delete a topology removing reference from the
-- topology.topology table
--
-- FUNCTION GetTopologyId(name)
-- FUNCTION GetTopologySRID(name)
-- FUNCTION GetTopologyName(id)
-- Return info about a Topology
--
-- FUNCTION AddTopoGeometryColumn(toponame, schema, table, column, geomtype)
-- Add a TopoGeometry column to a table, making it a topology layer.
-- Returns created layer id.
--
-- FUNCTION DropTopoGeometryColumn(schema, table, column)
-- Drop a TopoGeometry column, unregister the associated layer,
-- cleanup the relation table.
--
-- FUNCTION CreateTopoGeom(toponame, geomtype, layer_id, topo_objects)
-- Create a TopoGeometry object from existing Topology elements.
-- The "topo_objects" parameter is of TopoElementArray type.
--
-- FUNCTION GetTopoGeomElementArray(toponame, layer_id, topogeom_id)
-- FUNCTION GetTopoGeomElementArray(TopoGeometry)
-- Returns a TopoElementArray object containing the topological
-- elements of the given TopoGeometry.
--
-- FUNCTION GetTopoGeomElements(toponame, layer_id, topogeom_id)
-- FUNCTION GetTopoGeomElements(TopoGeometry)
-- Returns a set of TopoElement objects containing the
-- topological elements of the given TopoGeometry (primitive
-- elements)
--
-- FUNCTION ValidateTopology(toponame)
-- Run validity checks on the topology, returning, for each
-- detected error, a 3-columns row containing error string
-- and references to involved topo elements: error, id1, id2
--
-- - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - -
--
-- Overloaded functions for TopoGeometry inputs
--
-- FUNCTION intersects(TopoGeometry, TopoGeometry)
-- FUNCTION equals(TopoGeometry, TopoGeometry)
--
-- - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - -
--
-- FUNCTION TopoGeo_AddPoint(toponame, point)
-- Add a Point geometry to the topology
-- TODO: accept a topology/layer id
-- rework to use existing node if existent
--
-- FUNCTION TopoGeo_AddLinestring(toponame, line)
-- Add a LineString geometry to the topology
-- TODO: accept a topology/layer id
-- rework to use existing nodes/edges
-- splitting them if required
--
-- FUNCTION TopoGeo_AddPolygon(toponame, polygon)
-- Add a Polygon geometry to the topology
-- TODO: implement
--
-- TYPE GetFaceEdges_ReturnType
-- Complex type used to return tuples from ST_GetFaceEdges
--
-- - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - -
--
-- [SQL/MM]
--
-- ST_InitTopoGeo
-- Done, can be modified to include explicit sequences or
-- more constraints. Very noisy due to implicit index creations
-- for primary keys and sequences for serial fields...
--
-- ST_CreateTopoGeo
-- Complete
--
-- ST_AddIsoNode
-- Complete
--
-- ST_RemoveIsoNode
-- Complete
--
-- ST_MoveIsoNode
-- Complete
--
-- ST_AddIsoEdge
-- Complete
--
-- ST_RemoveIsoEdge
-- Complete, exceptions untested
--
-- ST_ChangeEdgeGeom
-- Complete
--
-- ST_NewEdgesSplit
-- Complete
-- Also updates the Relation table
--
-- ST_ModEdgeSplit
-- Complete
-- Also updates the Relation table
--
-- ST_AddEdgeNewFaces
-- Complete
-- Also updates the Relation table
--
-- ST_AddEdgeModFace
-- Complete
-- Also updates the Relation table
--
-- ST_GetFaceEdges
-- Complete
--
-- ST_ModEdgeHeal
-- Complete
-- Also updates the Relation table
--
-- ST_NewEdgeHeal
-- Complete
-- Also updates the Relation table
--
-- ST_GetFaceGeometry
-- Implemented using ST_BuildArea()
--
-- ST_RemEdgeNewFace
-- Complete
-- Also updates the Relation table
--
-- ST_RemEdgeModFace
-- Complete
-- Also updates the Relation table
--
-- ST_ValidateTopoGeo
-- Unimplemented (probably a wrapper around ValidateTopology)
--
--
-- Uninstalling previous installation isn't really a good habit ...
-- Let people decide about that
-- DROP SCHEMA topology CASCADE;
#include "../postgis/sqldefines.h"
CREATE SCHEMA topology;
COMMENT ON SCHEMA topology IS 'PostGIS Topology schema';
-- Doing everything outside of a transaction helps
-- upgrading in the best case.
BEGIN;
--={ ----------------------------------------------------------------
-- POSTGIS-SPECIFIC block
--
-- This part contains function NOT in the SQL/MM specification
--
---------------------------------------------------------------------
--
-- Topology table.
-- Stores id,name,precision and SRID of topologies.
--
CREATE TABLE topology.topology (
id SERIAL NOT NULL PRIMARY KEY,
name VARCHAR NOT NULL UNIQUE,
SRID INTEGER NOT NULL,
precision FLOAT8 NOT NULL,
hasz BOOLEAN NOT NULL DEFAULT false
);
--{ LayerTrigger()
--
-- Layer integrity trigger
--
CREATE OR REPLACE FUNCTION topology.LayerTrigger()
RETURNS trigger
AS
$$
DECLARE
rec RECORD;
ok BOOL;
toponame varchar;
query TEXT;
BEGIN
--RAISE NOTICE 'LayerTrigger called % % at % level', TG_WHEN, TG_OP, TG_LEVEL;
IF TG_OP = 'INSERT' THEN
RAISE EXCEPTION 'LayerTrigger not meant to be called on INSERT';
ELSIF TG_OP = 'UPDATE' THEN
RAISE EXCEPTION 'The topology.layer table cannot be updated';
END IF;
-- Check for existance of any feature column referencing
-- this layer
FOR rec IN SELECT * FROM pg_namespace n, pg_class c, pg_attribute a
WHERE text(n.nspname) = OLD.schema_name
AND c.relnamespace = n.oid
AND text(c.relname) = OLD.table_name
AND a.attrelid = c.oid
AND text(a.attname) = OLD.feature_column
LOOP
query = 'SELECT * '
' FROM ' || quote_ident(OLD.schema_name)
|| '.' || quote_ident(OLD.table_name)
|| ' WHERE layer_id('
|| quote_ident(OLD.feature_column)||') '
'=' || OLD.layer_id
|| ' LIMIT 1';
--RAISE NOTICE '%', query;
FOR rec IN EXECUTE query
LOOP
RAISE NOTICE 'A feature referencing layer % of topology % still exists in %.%.%', OLD.layer_id, OLD.topology_id, OLD.schema_name, OLD.table_name, OLD.feature_column;
RETURN NULL;
END LOOP;
END LOOP;
-- Get topology name
SELECT name FROM topology.topology INTO toponame
WHERE id = OLD.topology_id;
IF toponame IS NULL THEN
RAISE NOTICE 'Could not find name of topology with id %',
OLD.layer_id;
END IF;
-- Check if any record in the relation table references this layer
FOR rec IN SELECT c.oid FROM pg_namespace n, pg_class c
WHERE text(n.nspname) = toponame AND c.relnamespace = n.oid
AND c.relname = 'relation'
LOOP
query = 'SELECT * '
' FROM ' || quote_ident(toponame)
|| '.relation '
' WHERE layer_id = '|| OLD.layer_id
|| ' LIMIT 1';
--RAISE NOTICE '%', query;
FOR rec IN EXECUTE query
LOOP
RAISE NOTICE 'A record in %.relation still references layer %', toponame, OLD.layer_id;
RETURN NULL;
END LOOP;
END LOOP;
RETURN OLD;
END;
$$
LANGUAGE 'plpgsql' VOLATILE STRICT;
--} LayerTrigger()
--{
-- Layer table.
-- Stores topology layer informations
--
CREATE TABLE topology.layer (
topology_id INTEGER NOT NULL
REFERENCES topology.topology(id),
layer_id integer NOT NULL,
schema_name VARCHAR NOT NULL,
table_name VARCHAR NOT NULL,
feature_column VARCHAR NOT NULL,
feature_type integer NOT NULL,
level INTEGER NOT NULL DEFAULT 0,
child_id INTEGER DEFAULT NULL,
UNIQUE(schema_name, table_name, feature_column),
PRIMARY KEY(topology_id, layer_id)
);
CREATE TRIGGER layer_integrity_checks BEFORE UPDATE OR DELETE
ON topology.layer FOR EACH ROW EXECUTE PROCEDURE topology.LayerTrigger();
--} Layer table.
--
-- Type returned by ValidateTopology
--
CREATE TYPE topology.ValidateTopology_ReturnType AS (
error varchar,
id1 integer,
id2 integer
);
--
-- TopoGeometry type
--
CREATE TYPE topology.TopoGeometry AS (
topology_id integer,
layer_id integer,
id integer,
type integer -- 1: [multi]point, 2: [multi]line,
-- 3: [multi]polygon, 4: collection
);
--
-- TopoElement domain
--
-- This is an array of two elements: element_id and element_type.
--
-- When used to define _simple_ TopoGeometries,
-- element_type can be:
-- 0: a node
-- 1: an edge
-- 2: a face
-- and element_id will be the node, edge or face identifier
--
-- When used to define _hierarchical_ TopoGeometries,
-- element_type will be the child layer identifier and
-- element_id will be composing TopoGoemetry identifier
--
CREATE DOMAIN topology.TopoElement AS integer[]
CONSTRAINT DIMENSIONS CHECK (
array_upper(VALUE, 2) IS NULL
AND array_upper(VALUE, 1) = 2
);
ALTER DOMAIN topology.TopoElement ADD
CONSTRAINT lower_dimension CHECK (
array_lower(VALUE, 1) = 1
);
ALTER DOMAIN topology.TopoElement DROP CONSTRAINT
#if POSTGIS_PGSQL_VERSION >= 92
IF EXISTS
#endif
type_range;
ALTER DOMAIN topology.TopoElement ADD
CONSTRAINT type_range CHECK (
VALUE[2] > 0
);
--
-- TopoElementArray domain
--
CREATE DOMAIN topology.TopoElementArray AS integer[][]
CONSTRAINT DIMENSIONS CHECK (
array_upper(VALUE, 2) IS NOT NULL
AND array_upper(VALUE, 2) = 2
AND array_upper(VALUE, 3) IS NULL
);
--{ RelationTrigger()
--
-- Relation integrity trigger
--
CREATE OR REPLACE FUNCTION topology.RelationTrigger()
RETURNS trigger
AS
$$
DECLARE
toponame varchar;
topoid integer;
plyr RECORD; -- parent layer
rec RECORD;
ok BOOL;
BEGIN
IF TG_NARGS != 2 THEN
RAISE EXCEPTION 'RelationTrigger called with wrong number of arguments';
END IF;
topoid = TG_ARGV[0];
toponame = TG_ARGV[1];
--RAISE NOTICE 'RelationTrigger called % % on %.relation for a %', TG_WHEN, TG_OP, toponame, TG_LEVEL;
IF TG_OP = 'DELETE' THEN
RAISE EXCEPTION 'RelationTrigger not meant to be called on DELETE';
END IF;
-- Get layer info (and verify it exists)
ok = false;
FOR plyr IN EXECUTE 'SELECT * FROM topology.layer '
'WHERE '
' topology_id = ' || topoid
|| ' AND'
' layer_id = ' || NEW.layer_id
LOOP
ok = true;
EXIT;
END LOOP;
IF NOT ok THEN
RAISE EXCEPTION 'Layer % does not exist in topology %',
NEW.layer_id, topoid;
RETURN NULL;
END IF;
IF plyr.level > 0 THEN -- this is hierarchical layer
-- ElementType must be the layer child id
IF NEW.element_type != plyr.child_id THEN
RAISE EXCEPTION 'Type of elements in layer % must be set to its child layer id %', plyr.layer_id, plyr.child_id;
RETURN NULL;
END IF;
-- ElementId must be an existent TopoGeometry in child layer
ok = false;
FOR rec IN EXECUTE 'SELECT topogeo_id FROM '
|| quote_ident(toponame) || '.relation '
' WHERE layer_id = ' || plyr.child_id
|| ' AND topogeo_id = ' || NEW.element_id
LOOP
ok = true;
EXIT;
END LOOP;
IF NOT ok THEN
RAISE EXCEPTION 'TopoGeometry % does not exist in the child layer %', NEW.element_id, plyr.child_id;
RETURN NULL;
END IF;
ELSE -- this is a basic layer
-- ElementType must be compatible with layer type
IF plyr.feature_type != 4
AND plyr.feature_type != NEW.element_type
THEN
RAISE EXCEPTION 'Element of type % is not compatible with layer of type %', NEW.element_type, plyr.feature_type;
RETURN NULL;
END IF;
--
-- Now lets see if the element is consistent, which
-- is it exists in the topology tables.
--
--
-- Element is a Node
--
IF NEW.element_type = 1
THEN
ok = false;
FOR rec IN EXECUTE 'SELECT node_id FROM '
|| quote_ident(toponame) || '.node '
' WHERE node_id = ' || NEW.element_id
LOOP
ok = true;
EXIT;
END LOOP;
IF NOT ok THEN
RAISE EXCEPTION 'Node % does not exist in topology %', NEW.element_id, toponame;
RETURN NULL;
END IF;
--
-- Element is an Edge
--
ELSIF NEW.element_type = 2
THEN
ok = false;
FOR rec IN EXECUTE 'SELECT edge_id FROM '
|| quote_ident(toponame) || '.edge_data '
' WHERE edge_id = ' || abs(NEW.element_id)
LOOP
ok = true;
EXIT;
END LOOP;
IF NOT ok THEN
RAISE EXCEPTION 'Edge % does not exist in topology %', NEW.element_id, toponame;
RETURN NULL;
END IF;
--
-- Element is a Face
--
ELSIF NEW.element_type = 3
THEN
IF NEW.element_id = 0 THEN
RAISE EXCEPTION 'Face % cannot be associated with any feature', NEW.element_id;
RETURN NULL;
END IF;
ok = false;
FOR rec IN EXECUTE 'SELECT face_id FROM '
|| quote_ident(toponame) || '.face '
' WHERE face_id = ' || NEW.element_id
LOOP
ok = true;
EXIT;
END LOOP;
IF NOT ok THEN
RAISE EXCEPTION 'Face % does not exist in topology %', NEW.element_id, toponame;
RETURN NULL;
END IF;
END IF;
END IF;
RETURN NEW;
END;
$$
LANGUAGE 'plpgsql' VOLATILE STRICT;
--} RelationTrigger()
--{
-- AddTopoGeometryColumn(toponame, schema, table, colum, type, [child])
--
-- Add a TopoGeometry column to a table, making it a topology layer.
-- Returns created layer id.
--
--
CREATE OR REPLACE FUNCTION topology.AddTopoGeometryColumn(toponame varchar, schema varchar, tbl varchar, col varchar, ltype varchar, child integer)
RETURNS integer
AS
$$
DECLARE
intltype integer;
newlevel integer;
topoid integer;
rec RECORD;
newlayer_id integer;
query text;
BEGIN
-- Get topology id
SELECT id INTO topoid
FROM topology.topology WHERE name = toponame;
IF NOT FOUND THEN
RAISE EXCEPTION 'Topology % does not exist', quote_literal(toponame);
END IF;
IF ltype ILIKE '%POINT%' OR ltype ILIKE 'PUNTAL' THEN
intltype = 1;
ELSIF ltype ILIKE '%LINE%' OR ltype ILIKE 'LINEAL' THEN
intltype = 2;
ELSIF ltype ILIKE '%POLYGON%' OR ltype ILIKE 'AREAL' THEN
intltype = 3;
ELSIF ltype ILIKE '%COLLECTION%' OR ltype ILIKE 'GEOMETRY' THEN
intltype = 4;
ELSE
RAISE EXCEPTION 'Layer type must be one of POINT,LINE,POLYGON,COLLECTION';
END IF;
--
-- Add new TopoGeometry column in schema.table
--
EXECUTE 'ALTER TABLE ' || quote_ident(schema)
|| '.' || quote_ident(tbl)
|| ' ADD COLUMN ' || quote_ident(col)
|| ' topology.TopoGeometry;';
--
-- See if child id exists and extract its level
--
IF child IS NOT NULL THEN
SELECT level + 1 FROM topology.layer
WHERE layer_id = child
AND topology_id = topoid
INTO newlevel;
IF newlevel IS NULL THEN
RAISE EXCEPTION 'Child layer % does not exist in topology "%"', child, toponame;
END IF;
END IF;
--
-- Get new layer id from sequence
--
EXECUTE 'SELECT nextval(' ||
quote_literal(
quote_ident(toponame) || '.layer_id_seq'
) || ')' INTO STRICT newlayer_id;
EXECUTE 'INSERT INTO '
'topology.layer(topology_id, '
'layer_id, level, child_id, schema_name, '
'table_name, feature_column, feature_type) '
'VALUES ('
|| topoid || ','
|| newlayer_id || ',' || COALESCE(newlevel, 0) || ','
|| COALESCE(child::text, 'NULL') || ','
|| quote_literal(schema) || ','
|| quote_literal(tbl) || ','
|| quote_literal(col) || ','
|| intltype || ');';
--
-- Create a sequence for TopoGeometries in this new layer
--
EXECUTE 'CREATE SEQUENCE ' || quote_ident(toponame)
|| '.topogeo_s_' || newlayer_id;
--
-- Add constraints on TopoGeom column
--
EXECUTE 'ALTER TABLE ' || quote_ident(schema)
|| '.' || quote_ident(tbl)
|| ' ADD CONSTRAINT "check_topogeom_' || col || '" CHECK ('
'topology_id(' || quote_ident(col) || ') = ' || topoid
|| ' AND '
'layer_id(' || quote_ident(col) || ') = ' || newlayer_id
|| ' AND '
'type(' || quote_ident(col) || ') = ' || intltype
|| ');';
--
-- Add dependency of the feature column on the topology schema
--
query = 'INSERT INTO pg_catalog.pg_depend SELECT '
'fcat.oid, fobj.oid, fsub.attnum, tcat.oid, '
'tobj.oid, 0, ''n'' '
'FROM pg_class fcat, pg_namespace fnsp, '
' pg_class fobj, pg_attribute fsub, '
' pg_class tcat, pg_namespace tobj '
' WHERE fcat.relname = ''pg_class'' '
' AND fnsp.nspname = ' || quote_literal(schema)
|| ' AND fobj.relnamespace = fnsp.oid '
' AND fobj.relname = ' || quote_literal(tbl)
|| ' AND fsub.attrelid = fobj.oid '
' AND fsub.attname = ' || quote_literal(col)
|| ' AND tcat.relname = ''pg_namespace'' '
' AND tobj.nspname = ' || quote_literal(toponame);
--
-- The only reason to add this dependency is to avoid
-- simple drop of a feature column. Still, drop cascade
-- will remove both the feature column and the sequence
-- corrupting the topology anyway ...
--
#if 0
--
-- Add dependency of the topogeom sequence on the feature column
-- This is a dirty hack ...
--
query = 'INSERT INTO pg_catalog.pg_depend SELECT '
'scat.oid, sobj.oid, 0, fcat.oid, '
'fobj.oid, fsub.attnum, ''n'' '
'FROM pg_class fcat, pg_namespace fnsp, '
' pg_class fobj, pg_attribute fsub, '
' pg_class scat, pg_class sobj, '
' pg_namespace snsp '
' WHERE fcat.relname = ''pg_class'' '
' AND fnsp.nspname = ' || quote_literal(schema)
|| ' AND fobj.relnamespace = fnsp.oid '
' AND fobj.relname = ' || quote_literal(tbl)
|| ' AND fsub.attrelid = fobj.oid '
' AND fsub.attname = ' || quote_literal(col)
|| ' AND scat.relname = ''pg_class'' '
' AND snsp.nspname = ' || quote_literal(toponame)
|| ' AND sobj.relnamespace = snsp.oid '
' AND sobj.relname = '
' ''topogeo_s_' || newlayer_id || ''' ';
RAISE NOTICE '%', query;
EXECUTE query;
#endif
RETURN newlayer_id;
END;
$$
LANGUAGE 'plpgsql' VOLATILE;
--}{ AddTopoGeometryColumn
CREATE OR REPLACE FUNCTION topology.AddTopoGeometryColumn(varchar, varchar, varchar, varchar, varchar)
RETURNS integer
AS
$$
SELECT topology.AddTopoGeometryColumn($1, $2, $3, $4, $5, NULL);
$$
LANGUAGE 'sql' VOLATILE;
--
--} AddTopoGeometryColumn
--{
-- DropTopoGeometryColumn(schema, table, colum)
--
-- Drop a TopoGeometry column, unregister the associated layer,
-- cleanup the relation table.
--
--
CREATE OR REPLACE FUNCTION topology.DropTopoGeometryColumn(schema varchar, tbl varchar, col varchar)
RETURNS text
AS
$$
DECLARE
rec RECORD;
lyrinfo RECORD;
ok BOOL;
result text;
BEGIN
-- Get layer and topology info
ok = false;
FOR rec IN EXECUTE 'SELECT t.name as toponame, l.* FROM '
'topology.topology t, topology.layer l '
' WHERE l.topology_id = t.id'
' AND l.schema_name = ' || quote_literal(schema)
|| ' AND l.table_name = ' || quote_literal(tbl)
|| ' AND l.feature_column = ' || quote_literal(col)
LOOP
ok = true;
lyrinfo = rec;
END LOOP;
-- Layer not found
IF NOT ok THEN
RAISE EXCEPTION 'No layer registered on %.%.%',
schema,tbl,col;
END IF;
-- Clean up the topology schema
BEGIN
-- Cleanup the relation table
EXECUTE 'DELETE FROM ' || quote_ident(lyrinfo.toponame)
|| '.relation '
' WHERE '
'layer_id = ' || lyrinfo.layer_id;
-- Drop the sequence for topogeoms in this layer
EXECUTE 'DROP SEQUENCE ' || quote_ident(lyrinfo.toponame)
|| '.topogeo_s_' || lyrinfo.layer_id;
EXCEPTION
WHEN UNDEFINED_TABLE THEN
RAISE NOTICE '%', SQLERRM;
WHEN OTHERS THEN
RAISE EXCEPTION 'Got % (%)', SQLERRM, SQLSTATE;
END;
ok = false;
FOR rec IN SELECT * FROM pg_namespace n, pg_class c, pg_attribute a
WHERE text(n.nspname) = schema
AND c.relnamespace = n.oid
AND text(c.relname) = tbl
AND a.attrelid = c.oid
AND text(a.attname) = col
LOOP
ok = true;
EXIT;
END LOOP;
IF ok THEN
-- Set feature column to NULL to bypass referential integrity
-- checks
EXECUTE 'UPDATE ' || quote_ident(schema) || '.'
|| quote_ident(tbl)
|| ' SET ' || quote_ident(col)
|| ' = NULL';
END IF;
-- Delete the layer record
EXECUTE 'DELETE FROM topology.layer '
' WHERE topology_id = ' || lyrinfo.topology_id
|| ' AND layer_id = ' || lyrinfo.layer_id;
IF ok THEN
-- Drop the layer column
EXECUTE 'ALTER TABLE ' || quote_ident(schema) || '.'
|| quote_ident(tbl)
|| ' DROP ' || quote_ident(col)
|| ' cascade';
END IF;
result = 'Layer ' || lyrinfo.layer_id || ' ('
|| schema || '.' || tbl || '.' || col
|| ') dropped';
RETURN result;
END;
$$
LANGUAGE 'plpgsql' VOLATILE;
--
--} DropTopoGeometryColumn
-- {
--
-- populate_topology_layer
--
-- Register missing layers into topology.topology, looking at
-- their constraints.
--
-- The function doesn't attempt to determine if a layer is
-- hierarchical or primitive, but always assumes primitive.
--
-- }{
DROP FUNCTION IF EXISTS topology.populate_topology_layer();
CREATE OR REPLACE FUNCTION topology.populate_topology_layer()
RETURNS TABLE(schema_name text, table_name text, feature_column text)
AS
$$
INSERT INTO topology.layer
WITH checks AS (
SELECT
n.nspname sch, r.relname tab,
replace(c.conname, 'check_topogeom_', '') col,
--c.consrc src,
regexp_matches(c.consrc,
'\.topology_id = (\d+).*\.layer_id = (\d+).*\.type = (\d+)') inf
FROM pg_constraint c, pg_class r, pg_namespace n
WHERE c.conname LIKE 'check_topogeom_%'
AND r.oid = c.conrelid
AND n.oid = r.relnamespace
), newrows AS (
SELECT inf[1]::int as topology_id,
inf[2]::int as layer_id,
sch, tab, col, inf[3]::int as feature_type --, src
FROM checks c
WHERE NOT EXISTS (
SELECT * FROM topology.layer l
WHERE l.schema_name = c.sch
AND l.table_name = c.tab
AND l.feature_column = c.col
)
)
SELECT topology_id, layer_id, sch,
tab, col, feature_type,
0, NULL
FROM newrows RETURNING schema_name,table_name,feature_column;
$$
LANGUAGE 'sql' VOLATILE;
--{
-- CreateTopoGeom(topology_name, topogeom_type, layer_id, elements)
--
-- Create a TopoGeometry object from Topology elements.
-- The elements parameter is a two-dimensional array.
-- Every element of the array is either a Topology element represented by
-- (id, type) or a TopoGeometry element represented by (id, layer).
-- The actual semantic depends on the TopoGeometry layer, either at
-- level 0 (elements are topological primitives) or higer (elements
-- are TopoGeoms from child layer).
--
-- @param toponame Topology name
--
-- @param tg_type Spatial type of geometry
-- 1:[multi]point (puntal)
-- 2:[multi]line (lineal)
-- 3:[multi]poly (areal)
-- 4:collection (mixed)
--
-- @param layer_id Layer identifier
--
-- @param tg_objs Array of components
--
-- Return a topology.TopoGeometry object.
--
CREATE OR REPLACE FUNCTION topology.CreateTopoGeom(toponame varchar, tg_type integer, layer_id integer, tg_objs topology.TopoElementArray)
RETURNS topology.TopoGeometry
AS
$$
DECLARE
i integer;
dims varchar;
outerdims varchar;
innerdims varchar;
obj_type integer;
obj_id integer;
ret topology.TopoGeometry;
rec RECORD;
layertype integer;
layerlevel integer;
layerchild integer;
BEGIN
IF tg_type < 1 OR tg_type > 4 THEN
RAISE EXCEPTION 'Invalid TopoGeometry type % (must be in the range 1..4)', tg_type;
END IF;
-- Get topology id into return TopoGeometry
SELECT id INTO ret.topology_id
FROM topology.topology WHERE name = toponame;
IF NOT FOUND THEN
RAISE EXCEPTION 'Topology % does not exist', quote_literal(toponame);
END IF;
--
-- Get layer info
--
layertype := NULL;
FOR rec IN EXECUTE 'SELECT * FROM topology.layer'
' WHERE topology_id = ' || ret.topology_id
|| ' AND layer_id = ' || layer_id
LOOP
layertype = rec.feature_type;
layerlevel = rec.level;
layerchild = rec.child_id;
END LOOP;
-- Check for existence of given layer id
IF layertype IS NULL THEN
RAISE EXCEPTION 'No layer with id % is registered with topology %', layer_id, toponame;
END IF;
-- Verify compatibility between layer geometry type and
-- TopoGeom requested geometry type
IF layertype != 4 and layertype != tg_type THEN
RAISE EXCEPTION 'A Layer of type % cannot contain a TopoGeometry of type %', layertype, tg_type;
END IF;
-- Set layer id and type in return object
ret.layer_id = layer_id;
ret.type = tg_type;
--
-- Get new TopoGeo id from sequence
--
FOR rec IN EXECUTE 'SELECT nextval(' ||
quote_literal(
quote_ident(toponame) || '.topogeo_s_' || layer_id
) || ')'
LOOP
ret.id = rec.nextval;
END LOOP;
-- Loop over outer dimension
i = array_lower(tg_objs, 1);
LOOP
obj_id = tg_objs[i][1];
obj_type = tg_objs[i][2];
-- Elements of type 0 represent emptiness, just skip them
IF obj_type = 0 THEN
IF obj_id != 0 THEN
RAISE EXCEPTION 'Malformed empty topo element {0,%} -- id must be 0 as well', obj_id;
END IF;
ELSE
IF layerlevel = 0 THEN -- array specifies lower-level objects
IF tg_type != 4 and tg_type != obj_type THEN
RAISE EXCEPTION 'A TopoGeometry of type % cannot contain topology elements of type %', tg_type, obj_type;
END IF;
ELSE -- array specifies lower-level topogeometries
IF obj_type != layerchild THEN
RAISE EXCEPTION 'TopoGeom element layer do not match TopoGeom child layer';
END IF;
-- TODO: verify that the referred TopoGeometry really
-- exists in the relation table ?
END IF;
--RAISE NOTICE 'obj:% type:% id:%', i, obj_type, obj_id;
--
-- Insert record into the Relation table
--
EXECUTE 'INSERT INTO '||quote_ident(toponame)
|| '.relation(topogeo_id, layer_id, '
'element_id,element_type) '
' VALUES ('||ret.id
||','||ret.layer_id
|| ',' || obj_id || ',' || obj_type || ');';
END IF;
i = i+1;
IF i > array_upper(tg_objs, 1) THEN
EXIT;
END IF;
END LOOP;
RETURN ret;
END
$$
LANGUAGE 'plpgsql' VOLATILE STRICT;
--} CreateTopoGeom(toponame,topogeom_type, layer_id, TopoElementArray)
--{
-- CreateTopoGeom(topology_name, topogeom_type, layer_id) - creates the empty topogeom
CREATE OR REPLACE FUNCTION topology.CreateTopoGeom(toponame varchar, tg_type integer, layer_id integer)
RETURNS topology.TopoGeometry
AS
$$
SELECT topology.CreateTopoGeom($1,$2,$3,'{{0,0}}');
$$ LANGUAGE 'sql' VOLATILE STRICT;
--} CreateTopoGeom(toponame, topogeom_type, layer_id)
--{
-- GetTopologyName(topology_id)
--
-- TODO: rewrite in SQL ?
--
CREATE OR REPLACE FUNCTION topology.GetTopologyName(topoid integer)
RETURNS varchar
AS
$$
DECLARE
ret varchar;
BEGIN
SELECT name FROM topology.topology into ret
WHERE id = topoid;
RETURN ret;
END
$$
LANGUAGE 'plpgsql' STABLE STRICT;
--} GetTopologyName(topoid)
--{
-- GetTopologyId(toponame)
--
-- TODO: rewrite in SQL ?
--
CREATE OR REPLACE FUNCTION topology.GetTopologyId(toponame varchar)
RETURNS integer
AS
$$
DECLARE
ret integer;
BEGIN
SELECT id INTO ret
FROM topology.topology WHERE name = toponame;
IF NOT FOUND THEN
RAISE EXCEPTION 'Topology % does not exist', quote_literal(toponame);
END IF;
RETURN ret;
END
$$
LANGUAGE 'plpgsql' STABLE STRICT;
--} GetTopologyId(toponame)
--{
-- GetTopologySRID(toponame)
--
CREATE OR REPLACE FUNCTION topology.GetTopologySRID(toponame varchar)
RETURNS integer
AS $$
SELECT SRID FROM topology.topology WHERE name = $1;
$$ LANGUAGE 'sql' STABLE STRICT;
--} GetTopologySRID(toponame)
--{
-- GetTopoGeomElementArray(toponame, layer_id, topogeom_id)
-- GetTopoGeomElementArray(TopoGeometry)
--
-- Returns a set of element_id,element_type
--
CREATE OR REPLACE FUNCTION topology.GetTopoGeomElementArray(toponame varchar, layer_id integer, tgid integer)
RETURNS topology.TopoElementArray
AS
$$
DECLARE
rec RECORD;
tg_objs varchar := '{';
i integer;
query text;
BEGIN
query = 'SELECT * FROM topology.GetTopoGeomElements('
|| quote_literal(toponame) || ','
|| quote_literal(layer_id) || ','
|| quote_literal(tgid)
|| ') as obj ORDER BY obj';
#ifdef POSTGIS_TOPOLOGY_DEBUG
RAISE DEBUG 'Query: %', query;
#endif
-- TODO: why not using array_agg here ?
i = 1;
FOR rec IN EXECUTE query
LOOP
IF i > 1 THEN
tg_objs = tg_objs || ',';
END IF;
tg_objs = tg_objs || '{'
|| rec.obj[1] || ',' || rec.obj[2]
|| '}';
i = i+1;
END LOOP;
tg_objs = tg_objs || '}';
RETURN tg_objs;
END;
$$
LANGUAGE 'plpgsql' STABLE STRICT;
CREATE OR REPLACE FUNCTION topology.GetTopoGeomElementArray(tg topology.TopoGeometry)
RETURNS topology.TopoElementArray
AS
$$
DECLARE
toponame varchar;
BEGIN
toponame = topology.GetTopologyName(tg.topology_id);
RETURN topology.GetTopoGeomElementArray(toponame, tg.layer_id, tg.id);
END;
$$
LANGUAGE 'plpgsql' STABLE STRICT;
--} GetTopoGeomElementArray()
--{
-- GetTopoGeomElements(toponame, layer_id, topogeom_id)
-- GetTopoGeomElements(TopoGeometry)
--
-- Returns a set of element_id,element_type
--
CREATE OR REPLACE FUNCTION topology.GetTopoGeomElements(toponame varchar, layerid integer, tgid integer)
RETURNS SETOF topology.TopoElement
AS
$$
DECLARE
ret topology.TopoElement;
rec RECORD;
rec2 RECORD;
query text;
query2 text;
lyr RECORD;
ok bool;
topoid INTEGER;
BEGIN
-- Get topology id
SELECT id INTO topoid
FROM topology.topology WHERE name = toponame;
IF NOT FOUND THEN
RAISE EXCEPTION 'Topology % does not exist', quote_literal(toponame);
END IF;
-- Get layer info
ok = false;
FOR rec IN EXECUTE 'SELECT * FROM topology.layer '
' WHERE layer_id = $1 AND topology_id = $2'
USING layerid, topoid
LOOP
lyr = rec;
ok = true;
END LOOP;
IF NOT ok THEN
RAISE EXCEPTION 'Layer % does not exist', layerid;
END IF;
query = 'SELECT abs(element_id) as element_id, element_type FROM '
|| quote_ident(toponame) || '.relation WHERE '
' layer_id = ' || layerid
|| ' AND topogeo_id = ' || quote_literal(tgid)
|| ' ORDER BY element_type, element_id';
--RAISE NOTICE 'Query: %', query;
FOR rec IN EXECUTE query
LOOP
IF lyr.level > 0 THEN
query2 = 'SELECT * from topology.GetTopoGeomElements('
|| quote_literal(toponame) || ','
|| rec.element_type
|| ','
|| rec.element_id
|| ') as ret;';
--RAISE NOTICE 'Query2: %', query2;
FOR rec2 IN EXECUTE query2
LOOP
RETURN NEXT rec2.ret;
END LOOP;
ELSE
ret = '{' || rec.element_id || ',' || rec.element_type || '}';
RETURN NEXT ret;
END IF;
END LOOP;
RETURN;
END;
$$
LANGUAGE 'plpgsql' STABLE STRICT;
CREATE OR REPLACE FUNCTION topology.GetTopoGeomElements(tg topology.TopoGeometry)
RETURNS SETOF topology.TopoElement
AS
$$
DECLARE
toponame varchar;
rec RECORD;
BEGIN
toponame = topology.GetTopologyName(tg.topology_id);
FOR rec IN SELECT * FROM topology.GetTopoGeomElements(toponame,
tg.layer_id,tg.id) as ret
LOOP
RETURN NEXT rec.ret;
END LOOP;
RETURN;
END;
$$
LANGUAGE 'plpgsql' STABLE STRICT;
--} GetTopoGeomElements()
--{
-- Geometry(TopoGeometry)
--
-- Construct a Geometry from a TopoGeometry.
--
-- }{
CREATE OR REPLACE FUNCTION topology.Geometry(topogeom topology.TopoGeometry)
RETURNS Geometry
AS $$
DECLARE
toponame varchar;
geom geometry;
rec RECORD;
plyr RECORD;
clyr RECORD;
sql TEXT;
BEGIN
-- Get topology name
SELECT name FROM topology.topology
WHERE id = topogeom.topology_id
INTO toponame;
IF toponame IS NULL THEN
RAISE EXCEPTION 'Invalid TopoGeometry (unexistent topology id %)', topogeom.topology_id;
END IF;
-- Get layer info
SELECT * FROM topology.layer
WHERE topology_id = topogeom.topology_id
AND layer_id = topogeom.layer_id
INTO plyr;
IF plyr IS NULL THEN
RAISE EXCEPTION 'Could not find TopoGeometry layer % in topology %', topogeom.layer_id, topogeom.topology_id;
END IF;
--
-- If this feature layer is on any level > 0 we will
-- compute the topological union of all child features
-- in fact recursing.
--
IF plyr.level > 0 THEN -- {
-- Get child layer info
SELECT * FROM topology.layer WHERE layer_id = plyr.child_id
AND topology_id = topogeom.topology_id
INTO clyr;
IF clyr IS NULL THEN
RAISE EXCEPTION 'Invalid layer % in topology % (unexistent child layer %)', topogeom.layer_id, topogeom.topology_id, plyr.child_id;
END IF;
sql := 'SELECT st_multi(st_union(topology.Geometry('
|| quote_ident(clyr.feature_column)
|| '))) as geom FROM '
|| quote_ident(clyr.schema_name) || '.'
|| quote_ident(clyr.table_name)
|| ', ' || quote_ident(toponame) || '.relation pr'
' WHERE '
' pr.topogeo_id = ' || topogeom.id
|| ' AND '
' pr.layer_id = ' || topogeom.layer_id
|| ' AND '
' id('||quote_ident(clyr.feature_column)
|| ') = pr.element_id '
' AND '
'layer_id('||quote_ident(clyr.feature_column)
|| ') = pr.element_type ';
--RAISE DEBUG '%', query;
EXECUTE sql INTO geom;
ELSIF topogeom.type = 3 THEN -- [multi]polygon -- }{
sql := 'SELECT st_multi(st_union('
'topology.ST_GetFaceGeometry('
|| quote_literal(toponame) || ','
|| 'element_id))) as g FROM '
|| quote_ident(toponame)
|| '.relation WHERE topogeo_id = '
|| topogeom.id || ' AND layer_id = '
|| topogeom.layer_id || ' AND element_type = 3 ';
EXECUTE sql INTO geom;
ELSIF topogeom.type = 2 THEN -- [multi]line -- }{
sql :=
'SELECT st_multi(ST_LineMerge(ST_Collect(e.geom))) as g FROM '
|| quote_ident(toponame) || '.edge e, '
|| quote_ident(toponame) || '.relation r '
' WHERE r.topogeo_id = ' || topogeom.id
|| ' AND r.layer_id = ' || topogeom.layer_id
|| ' AND r.element_type = 2 '
' AND abs(r.element_id) = e.edge_id';
EXECUTE sql INTO geom;
ELSIF topogeom.type = 1 THEN -- [multi]point -- }{
sql :=
'SELECT st_multi(st_union(n.geom)) as g FROM '
|| quote_ident(toponame) || '.node n, '
|| quote_ident(toponame) || '.relation r '
' WHERE r.topogeo_id = ' || topogeom.id
|| ' AND r.layer_id = ' || topogeom.layer_id
|| ' AND r.element_type = 1 '
' AND r.element_id = n.node_id';
EXECUTE sql INTO geom;
ELSIF topogeom.type = 4 THEN -- mixed collection -- }{
sql := 'WITH areas AS ( SELECT ST_Union('
'topology.ST_GetFaceGeometry('
|| quote_literal(toponame) || ','
|| 'element_id)) as g FROM '
|| quote_ident(toponame)
|| '.relation WHERE topogeo_id = '
|| topogeom.id || ' AND layer_id = '
|| topogeom.layer_id || ' AND element_type = 3), '
'lines AS ( SELECT ST_LineMerge(ST_Collect(e.geom)) as g FROM '
|| quote_ident(toponame) || '.edge e, '
|| quote_ident(toponame) || '.relation r '
' WHERE r.topogeo_id = ' || topogeom.id
|| ' AND r.layer_id = ' || topogeom.layer_id
|| ' AND r.element_type = 2 '
' AND abs(r.element_id) = e.edge_id ), '
' points as ( SELECT st_union(n.geom) as g FROM '
|| quote_ident(toponame) || '.node n, '
|| quote_ident(toponame) || '.relation r '
' WHERE r.topogeo_id = ' || topogeom.id
|| ' AND r.layer_id = ' || topogeom.layer_id
|| ' AND r.element_type = 1 '
' AND r.element_id = n.node_id ), '
' un as ( SELECT g FROM areas UNION ALL SELECT g FROM lines '
' UNION ALL SELECT g FROM points ) '
'SELECT ST_Multi(ST_Collect(g)) FROM un';
EXECUTE sql INTO geom;
ELSE -- }{
RAISE EXCEPTION 'Invalid TopoGeometries (unknown type %)', topogeom.type;
END IF; -- }
IF geom IS NULL THEN
IF topogeom.type = 3 THEN -- [multi]polygon
geom := 'MULTIPOLYGON EMPTY';
ELSIF topogeom.type = 2 THEN -- [multi]line
geom := 'MULTILINESTRING EMPTY';
ELSIF topogeom.type = 1 THEN -- [multi]point
geom := 'MULTIPOINT EMPTY';
ELSE
geom := 'GEOMETRYCOLLECTION EMPTY';
END IF;
END IF;
RETURN geom;
END
$$
LANGUAGE 'plpgsql' VOLATILE STRICT;
--} Geometry(TopoGeometry)
-- 7.3+ explicit cast
CREATE CAST (topology.TopoGeometry AS Geometry) WITH FUNCTION topology.Geometry(topology.TopoGeometry) AS IMPLICIT;
--{
-- ValidateTopology(toponame)
--
-- Return a Set of ValidateTopology_ReturnType containing
-- informations on all topology inconsistencies
--
CREATE OR REPLACE FUNCTION topology.ValidateTopology(toponame varchar)
RETURNS setof topology.ValidateTopology_ReturnType
AS
$$
DECLARE
retrec topology.ValidateTopology_ReturnType;
rec RECORD;
rec2 RECORD;
i integer;
invalid_edges integer[];
invalid_faces integer[];
sql text;
BEGIN
-- Check for coincident nodes
FOR rec IN EXECUTE 'SELECT a.node_id as id1, b.node_id as id2 FROM '
|| quote_ident(toponame) || '.node a, '
|| quote_ident(toponame) || '.node b '
'WHERE a.node_id < b.node_id '
' AND ST_DWithin(a.geom, b.geom, 0)' -- NOTE: see #1625 and #1789
LOOP
retrec.error = 'coincident nodes';
retrec.id1 = rec.id1;
retrec.id2 = rec.id2;
RETURN NEXT retrec;
END LOOP;
-- Check for edge crossed nodes
-- TODO: do this in the single edge loop
FOR rec IN EXECUTE 'SELECT n.node_id as nid, e.edge_id as eid FROM '
|| quote_ident(toponame) || '.node n, '
|| quote_ident(toponame) || '.edge e '
'WHERE e.start_node != n.node_id '
'AND e.end_node != n.node_id '
'AND ST_Within(n.geom, e.geom)'
LOOP
retrec.error = 'edge crosses node';
retrec.id1 = rec.eid; -- edge_id
retrec.id2 = rec.nid; -- node_id
RETURN NEXT retrec;
END LOOP;
-- Scan all edges
FOR rec IN EXECUTE 'SELECT e.geom, e.edge_id as id1, e.left_face, e.right_face FROM '
|| quote_ident(toponame) || '.edge e ORDER BY edge_id'
LOOP
-- Any invalid edge becomes a cancer for higher level complexes
IF NOT ST_IsValid(rec.geom) THEN
retrec.error = 'invalid edge';
retrec.id1 = rec.id1;
retrec.id2 = NULL;
RETURN NEXT retrec;
invalid_edges := array_append(invalid_edges, rec.id1);
IF invalid_faces IS NULL OR NOT rec.left_face = ANY ( invalid_faces )
THEN
invalid_faces := array_append(invalid_faces, rec.left_face);
END IF;
IF rec.right_face != rec.left_face AND ( invalid_faces IS NULL OR
NOT rec.right_face = ANY ( invalid_faces ) )
THEN
invalid_faces := array_append(invalid_faces, rec.right_face);
END IF;
CONTINUE;
END IF;
IF NOT ST_IsSimple(rec.geom) THEN
retrec.error = 'edge not simple';
retrec.id1 = rec.id1;
retrec.id2 = NULL;
RETURN NEXT retrec;
END IF;
END LOOP;
-- Check for edge crossing
sql := 'SELECT e1.edge_id as id1, e2.edge_id as id2, '
' e1.geom as g1, e2.geom as g2, '
'ST_Relate(e1.geom, e2.geom) as im FROM '
|| quote_ident(toponame) || '.edge e1, '
|| quote_ident(toponame) || '.edge e2 '
'WHERE e1.edge_id < e2.edge_id '
' AND e1.geom && e2.geom ';
IF invalid_edges IS NOT NULL THEN
sql := sql || ' AND NOT e1.edge_id = ANY ('
|| quote_literal(invalid_edges) || ')'
|| ' AND NOT e2.edge_id = ANY ('
|| quote_literal(invalid_edges) || ')';
END IF;
FOR rec IN EXECUTE sql
LOOP
IF ST_RelateMatch(rec.im, 'FF1F**1*2') THEN
CONTINUE; -- no interior intersection
--
-- Closed lines have no boundary, so endpoint
-- intersection would be considered interior
-- See http://trac.osgeo.org/postgis/ticket/770
-- See also full explanation in topology.AddEdge
--
ELSIF ST_RelateMatch(rec.im, 'FF10F01F2') THEN
-- first line (g1) is open, second (g2) is closed
-- first boundary has puntual intersection with second interior
--
-- compute intersection, check it equals second endpoint
IF ST_Equals(ST_Intersection(rec.g2, rec.g1),
ST_StartPoint(rec.g2))
THEN
CONTINUE;
END IF;
ELSIF ST_RelateMatch(rec.im, 'F01FFF102') THEN
-- second line (g2) is open, first (g1) is closed
-- second boundary has puntual intersection with first interior
--
-- compute intersection, check it equals first endpoint
IF ST_Equals(ST_Intersection(rec.g2, rec.g1),
ST_StartPoint(rec.g1))
THEN
CONTINUE;
END IF;
ELSIF ST_RelateMatch(rec.im, '0F1FFF1F2') THEN
-- both lines are closed (boundary intersects nothing)
-- they have puntual intersection between interiors
--
-- compute intersection, check it's a single point
-- and equals first StartPoint _and_ second StartPoint
IF ST_Equals(ST_Intersection(rec.g1, rec.g2),
ST_StartPoint(rec.g1)) AND
ST_Equals(ST_StartPoint(rec.g1), ST_StartPoint(rec.g2))
THEN
CONTINUE;
END IF;
END IF;
retrec.error = 'edge crosses edge';
retrec.id1 = rec.id1;
retrec.id2 = rec.id2;
RETURN NEXT retrec;
END LOOP;
-- Check for edge start_node geometry mis-match
-- TODO: move this in the first edge table scan
FOR rec IN EXECUTE 'SELECT e.edge_id as id1, n.node_id as id2 FROM '
|| quote_ident(toponame) || '.edge e, '
|| quote_ident(toponame) || '.node n '
'WHERE e.start_node = n.node_id '
'AND NOT ST_Equals(ST_StartPoint(e.geom), n.geom)'
LOOP
retrec.error = 'edge start node geometry mis-match';
retrec.id1 = rec.id1;
retrec.id2 = rec.id2;
RETURN NEXT retrec;
END LOOP;
-- Check for edge end_node geometry mis-match
-- TODO: move this in the first edge table scan
FOR rec IN EXECUTE 'SELECT e.edge_id as id1, n.node_id as id2 FROM '
|| quote_ident(toponame) || '.edge e, '
|| quote_ident(toponame) || '.node n '
'WHERE e.end_node = n.node_id '
'AND NOT ST_Equals(ST_EndPoint(e.geom), n.geom)'
LOOP
retrec.error = 'edge end node geometry mis-match';
retrec.id1 = rec.id1;
retrec.id2 = rec.id2;
RETURN NEXT retrec;
END LOOP;
-- Check for faces w/out edges
FOR rec IN EXECUTE 'SELECT face_id as id1 FROM '
|| quote_ident(toponame) || '.face '
|| 'WHERE face_id > 0 EXCEPT ( SELECT left_face FROM '
|| quote_ident(toponame) || '.edge '
|| ' UNION SELECT right_face FROM '
|| quote_ident(toponame) || '.edge '
|| ')'
LOOP
retrec.error = 'face without edges';
retrec.id1 = rec.id1;
retrec.id2 = NULL;
RETURN NEXT retrec;
END LOOP;
-- Now create a temporary table to construct all face geometries
-- for checking their consistency
sql := 'CREATE TEMP TABLE face_check ON COMMIT DROP AS '
'SELECT face_id, topology.ST_GetFaceGeometry('
|| quote_literal(toponame) || ', face_id) as geom, mbr FROM '
|| quote_ident(toponame) || '.face WHERE face_id > 0';
IF invalid_faces IS NOT NULL THEN
sql := sql || ' AND NOT face_id = ANY ('
|| quote_literal(invalid_faces) || ')';
END IF;
EXECUTE sql;
-- Build a gist index on geom
EXECUTE 'CREATE INDEX "face_check_gist" ON '
'face_check USING gist (geom);';
-- Build a btree index on id
EXECUTE 'CREATE INDEX "face_check_bt" ON '
'face_check (face_id);';
-- Scan the table looking for NULL geometries
FOR rec IN EXECUTE
'SELECT f1.face_id FROM '
'face_check f1 WHERE f1.geom IS NULL OR ST_IsEmpty(f1.geom)'
LOOP
-- Face missing !
retrec.error := 'face has no rings';
retrec.id1 := rec.face_id;
retrec.id2 := NULL;
RETURN NEXT retrec;
END LOOP;
-- Scan the table looking for overlap or containment
-- TODO: also check for MBR consistency
FOR rec IN EXECUTE
'SELECT f1.geom, f1.face_id as id1, f2.face_id as id2, '
' ST_Relate(f1.geom, f2.geom) as im'
' FROM '
'face_check f1, '
'face_check f2 '
'WHERE f1.face_id < f2.face_id'
' AND f1.geom && f2.geom'
LOOP
-- Face overlap
IF ST_RelateMatch(rec.im, 'T*T***T**') THEN
retrec.error = 'face overlaps face';
retrec.id1 = rec.id1;
retrec.id2 = rec.id2;
RETURN NEXT retrec;
END IF;
-- Face 1 is within face 2
IF ST_RelateMatch(rec.im, 'T*F**F***') THEN
retrec.error = 'face within face';
retrec.id1 = rec.id1;
retrec.id2 = rec.id2;
RETURN NEXT retrec;
END IF;
-- Face 1 contains face 2
IF ST_RelateMatch(rec.im, 'T*****FF*') THEN
retrec.error = 'face within face';
retrec.id1 = rec.id2;
retrec.id2 = rec.id1;
RETURN NEXT retrec;
END IF;
END LOOP;
#if 0
-- Check SRID consistency
FOR rec in EXECUTE
'SELECT count(*) FROM ( getSRID(geom) FROM '
|| quote_ident(toponame) || '.edge '
' UNION '
'SELECT getSRID(geom) FROM '
|| quote_ident(toponame) || '.node )'
LOOP
IF rec.count > 1 THEN
retrec.error = 'mixed SRIDs';
retrec.id1 = NULL;
retrec.id2 = NULL;
RETURN NEXT retrec;
END IF;
END LOOP;
#endif
DROP TABLE face_check;
RETURN;
END
$$
LANGUAGE 'plpgsql' VOLATILE STRICT;
-- } ValidateTopology(toponame)
--{
-- CreateTopology(name, SRID, precision, hasZ)
--
-- Create a topology schema, add a topology info record
-- in the topology.topology relation, return it's numeric
-- id.
--
CREATE OR REPLACE FUNCTION topology.CreateTopology(atopology varchar, srid integer, prec float8, hasZ boolean)
RETURNS integer
AS
$$
DECLARE
rec RECORD;
topology_id integer;
ndims integer;
BEGIN
-- FOR rec IN SELECT * FROM pg_namespace WHERE text(nspname) = atopology
-- LOOP
-- RAISE EXCEPTION 'SQL/MM Spatial exception - schema already exists';
-- END LOOP;
ndims = 2;
IF hasZ THEN ndims = 3; END IF;
------ Fetch next id for the new topology
FOR rec IN SELECT nextval('topology.topology_id_seq')
LOOP
topology_id = rec.nextval;
END LOOP;
EXECUTE 'CREATE SCHEMA ' || quote_ident(atopology);
-------------{ face CREATION
EXECUTE
'CREATE TABLE ' || quote_ident(atopology) || '.face ('
'face_id SERIAL,'
' CONSTRAINT face_primary_key PRIMARY KEY(face_id)'
');';
-- Add mbr column to the face table
EXECUTE
'SELECT AddGeometryColumn('||quote_literal(atopology)
||',''face'',''mbr'','||quote_literal(srid)
||',''POLYGON'',2)'; -- 2d only mbr is good enough
-- Face standard view description
EXECUTE 'COMMENT ON TABLE ' || quote_ident(atopology)
|| '.face IS '
'''Contains face topology primitives''';
-------------} END OF face CREATION
--------------{ node CREATION
EXECUTE
'CREATE TABLE ' || quote_ident(atopology) || '.node ('
'node_id SERIAL,'
--|| 'geom GEOMETRY,'
'containing_face INTEGER,'
'CONSTRAINT node_primary_key PRIMARY KEY(node_id),'
--|| 'CONSTRAINT node_geometry_type CHECK '
--|| '( GeometryType(geom) = ''POINT'' ),'
'CONSTRAINT face_exists FOREIGN KEY(containing_face) '
'REFERENCES ' || quote_ident(atopology) || '.face(face_id)'
');';
-- Add geometry column to the node table
EXECUTE
'SELECT AddGeometryColumn('||quote_literal(atopology)
||',''node'',''geom'','||quote_literal(srid)
||',''POINT'',' || ndims || ')';
-- Node standard view description
EXECUTE 'COMMENT ON TABLE ' || quote_ident(atopology)
|| '.node IS '
'''Contains node topology primitives''';
--------------} END OF node CREATION
--------------{ edge CREATION
-- edge_data table
EXECUTE
'CREATE TABLE ' || quote_ident(atopology) || '.edge_data ('
'edge_id SERIAL NOT NULL PRIMARY KEY,'
'start_node INTEGER NOT NULL,'
'end_node INTEGER NOT NULL,'
'next_left_edge INTEGER NOT NULL,'
'abs_next_left_edge INTEGER NOT NULL,'
'next_right_edge INTEGER NOT NULL,'
'abs_next_right_edge INTEGER NOT NULL,'
'left_face INTEGER NOT NULL,'
'right_face INTEGER NOT NULL,'
-- 'geom GEOMETRY NOT NULL,'
-- 'CONSTRAINT edge_geometry_type CHECK '
-- '( GeometryType(geom) = ''LINESTRING'' ),'
'CONSTRAINT start_node_exists FOREIGN KEY(start_node)'
' REFERENCES ' || quote_ident(atopology) || '.node(node_id),'
'CONSTRAINT end_node_exists FOREIGN KEY(end_node) '
' REFERENCES ' || quote_ident(atopology) || '.node(node_id),'
'CONSTRAINT left_face_exists FOREIGN KEY(left_face) '
'REFERENCES ' || quote_ident(atopology) || '.face(face_id),'
'CONSTRAINT right_face_exists FOREIGN KEY(right_face) '
'REFERENCES ' || quote_ident(atopology) || '.face(face_id),'
'CONSTRAINT next_left_edge_exists FOREIGN KEY(abs_next_left_edge)'
' REFERENCES ' || quote_ident(atopology)
|| '.edge_data(edge_id)'
' DEFERRABLE INITIALLY DEFERRED,'
'CONSTRAINT next_right_edge_exists '
'FOREIGN KEY(abs_next_right_edge)'
' REFERENCES ' || quote_ident(atopology)
|| '.edge_data(edge_id) '
' DEFERRABLE INITIALLY DEFERRED'
');';
-- Add geometry column to the edge_data table
EXECUTE
'SELECT AddGeometryColumn('||quote_literal(atopology)
||',''edge_data'',''geom'','||quote_literal(srid)
||',''LINESTRING'',' || ndims || ')';
-- edge standard view (select rule)
EXECUTE 'CREATE VIEW ' || quote_ident(atopology)
|| '.edge AS SELECT '
' edge_id, start_node, end_node, next_left_edge, '
' next_right_edge, '
' left_face, right_face, geom FROM '
|| quote_ident(atopology) || '.edge_data';
-- Edge standard view description
EXECUTE 'COMMENT ON VIEW ' || quote_ident(atopology)
|| '.edge IS '
'''Contains edge topology primitives''';
EXECUTE 'COMMENT ON COLUMN ' || quote_ident(atopology)
|| '.edge.edge_id IS '
'''Unique identifier of the edge''';
EXECUTE 'COMMENT ON COLUMN ' || quote_ident(atopology)
|| '.edge.start_node IS '
'''Unique identifier of the node at the start of the edge''';
EXECUTE 'COMMENT ON COLUMN ' || quote_ident(atopology)
|| '.edge.end_node IS '
'''Unique identifier of the node at the end of the edge''';
EXECUTE 'COMMENT ON COLUMN ' || quote_ident(atopology)
|| '.edge.next_left_edge IS '
'''Unique identifier of the next edge of the face on the left (when looking in the direction from START_NODE to END_NODE), moving counterclockwise around the face boundary''';
EXECUTE 'COMMENT ON COLUMN ' || quote_ident(atopology)
|| '.edge.next_right_edge IS '
'''Unique identifier of the next edge of the face on the right (when looking in the direction from START_NODE to END_NODE), moving counterclockwise around the face boundary''';
EXECUTE 'COMMENT ON COLUMN ' || quote_ident(atopology)
|| '.edge.left_face IS '
'''Unique identifier of the face on the left side of the edge when looking in the direction from START_NODE to END_NODE''';
EXECUTE 'COMMENT ON COLUMN ' || quote_ident(atopology)
|| '.edge.right_face IS '
'''Unique identifier of the face on the right side of the edge when looking in the direction from START_NODE to END_NODE''';
EXECUTE 'COMMENT ON COLUMN ' || quote_ident(atopology)
|| '.edge.geom IS '
'''The geometry of the edge''';
-- edge standard view (insert rule)
EXECUTE 'CREATE RULE edge_insert_rule AS ON INSERT '
'TO ' || quote_ident(atopology)
|| '.edge DO INSTEAD '
' INSERT into ' || quote_ident(atopology)
|| '.edge_data '
' VALUES (NEW.edge_id, NEW.start_node, NEW.end_node, '
' NEW.next_left_edge, abs(NEW.next_left_edge), '
' NEW.next_right_edge, abs(NEW.next_right_edge), '
' NEW.left_face, NEW.right_face, NEW.geom);';
--------------} END OF edge CREATION
--------------{ layer sequence
EXECUTE 'CREATE SEQUENCE '
|| quote_ident(atopology) || '.layer_id_seq;';
--------------} layer sequence
--------------{ relation CREATION
--
EXECUTE
'CREATE TABLE ' || quote_ident(atopology) || '.relation ('
' topogeo_id integer NOT NULL, '
' layer_id integer NOT NULL, '
' element_id integer NOT NULL, '
' element_type integer NOT NULL, '
' UNIQUE(layer_id,topogeo_id,element_id,element_type));';
EXECUTE
'CREATE TRIGGER relation_integrity_checks '
'BEFORE UPDATE OR INSERT ON '
|| quote_ident(atopology) || '.relation FOR EACH ROW '
' EXECUTE PROCEDURE topology.RelationTrigger('
||topology_id||','||quote_literal(atopology)||')';
--------------} END OF relation CREATION
------- Default (world) face
EXECUTE 'INSERT INTO ' || quote_ident(atopology) || '.face(face_id) VALUES(0);';
------- GiST index on face
EXECUTE 'CREATE INDEX face_gist ON '
|| quote_ident(atopology)
|| '.face using gist (mbr);';
------- GiST index on node
EXECUTE 'CREATE INDEX node_gist ON '
|| quote_ident(atopology)
|| '.node using gist (geom);';
------- GiST index on edge
EXECUTE 'CREATE INDEX edge_gist ON '
|| quote_ident(atopology)
|| '.edge_data using gist (geom);';
------- Indexes on left_face and right_face of edge_data
------- NOTE: these indexes speed up GetFaceGeometry (and thus
------- TopoGeometry::Geometry) by a factor of 10 !
------- See http://trac.osgeo.org/postgis/ticket/806
EXECUTE 'CREATE INDEX edge_left_face_idx ON '
|| quote_ident(atopology)
|| '.edge_data (left_face);';
EXECUTE 'CREATE INDEX edge_right_face_idx ON '
|| quote_ident(atopology)
|| '.edge_data (right_face);';
------- Indexes on start_node and end_node of edge_data
------- NOTE: this indexes speed up node deletion
------- by a factor of 1000 !
------- See http://trac.osgeo.org/postgis/ticket/2082
EXECUTE 'CREATE INDEX edge_start_node_idx ON '
|| quote_ident(atopology)
|| '.edge_data (start_node);';
EXECUTE 'CREATE INDEX edge_end_node_idx ON '
|| quote_ident(atopology)
|| '.edge_data (end_node);';
-- TODO: consider also adding an index on node.containing_face
------- Add record to the "topology" metadata table
EXECUTE 'INSERT INTO topology.topology '
|| '(id, name, srid, precision, hasZ) VALUES ('
|| quote_literal(topology_id) || ','
|| quote_literal(atopology) || ','
|| quote_literal(srid) || ',' || quote_literal(prec)
|| ',' || hasZ
|| ')';
RETURN topology_id;
END
$$
LANGUAGE 'plpgsql' VOLATILE STRICT;
--} CreateTopology
--{ CreateTopology wrappers for unspecified srid or precision or hasZ
-- CreateTopology(name, SRID, precision) -- hasZ = false
CREATE OR REPLACE FUNCTION topology.CreateTopology(toponame varchar, srid integer, prec float8)
RETURNS integer AS
' SELECT topology.CreateTopology($1, $2, $3, false);'
LANGUAGE 'sql' VOLATILE STRICT;
-- CreateTopology(name, SRID) -- precision = 0
CREATE OR REPLACE FUNCTION topology.CreateTopology(varchar, integer)
RETURNS integer AS
' SELECT topology.CreateTopology($1, $2, 0); '
LANGUAGE 'sql' VOLATILE STRICT;
-- CreateTopology(name) -- srid = unknown, precision = 0
CREATE OR REPLACE FUNCTION topology.CreateTopology(varchar)
RETURNS integer AS
$$ SELECT topology.CreateTopology($1, ST_SRID('POINT EMPTY'::geometry), 0); $$
LANGUAGE 'sql' VOLATILE STRICT;
--} CreateTopology
--{
-- DropTopology(name)
--
-- Drops a topology schema getting rid of every dependent object.
--
CREATE OR REPLACE FUNCTION topology.DropTopology(atopology varchar)
RETURNS text
AS
$$
DECLARE
topoid integer;
rec RECORD;
BEGIN
-- Get topology id
SELECT id INTO topoid
FROM topology.topology WHERE name = atopology;
IF NOT FOUND THEN
RAISE EXCEPTION 'Topology % does not exist', quote_literal(atopology);
END IF;
RAISE NOTICE 'Dropping all layers from topology % (%)',
quote_literal(atopology), topoid;
-- Drop all layers in the topology
FOR rec IN EXECUTE 'SELECT * FROM topology.layer WHERE '
|| ' topology_id = ' || topoid
LOOP
EXECUTE 'SELECT topology.DropTopoGeometryColumn('
|| quote_literal(rec.schema_name)
|| ','
|| quote_literal(rec.table_name)
|| ','
|| quote_literal(rec.feature_column)
|| ')';
END LOOP;
-- Delete record from topology.topology
EXECUTE 'DELETE FROM topology.topology WHERE id = '
|| topoid;
-- Drop the schema (if it exists)
FOR rec IN SELECT * FROM pg_namespace WHERE text(nspname) = atopology
LOOP
EXECUTE 'DROP SCHEMA '||quote_ident(atopology)||' CASCADE';
END LOOP;
RETURN 'Topology ' || quote_literal(atopology) || ' dropped';
END
$$
LANGUAGE 'plpgsql' VOLATILE STRICT;
--} DropTopology
#include "sql/manage/TopologySummary.sql.in"
#include "sql/manage/CopyTopology.sql.in"
-- Spatial predicates
#include "sql/predicates.sql.in"
-- Querying
#include "sql/query/getnodebypoint.sql.in"
#include "sql/query/getedgebypoint.sql.in"
#include "sql/query/getfacebypoint.sql.in"
-- Populating
#include "sql/populate.sql.in"
#include "sql/polygonize.sql.in"
-- TopoElement
#include "sql/topoelement/topoelement_agg.sql.in"
-- TopoGeometry
#include "sql/topogeometry/type.sql.in"
#include "sql/topogeometry/cleartopogeom.sql.in"
#include "sql/topogeometry/simplify.sql.in"
#include "sql/topogeometry/totopogeom.sql.in"
#include "sql/topogeometry/topogeom_edit.sql.in"
-- Exports
#include "sql/export/gml.sql.in"
#include "sql/export/TopoJSON.sql.in"
--=} POSTGIS-SPECIFIC block
-- SQL/MM block
#include "sql/sqlmm.sql.in"
-- The following files needs getfaceedges_returntype, defined in sqlmm.sql
#include "sql/query/GetRingEdges.sql.in"
#include "sql/query/GetNodeEdges.sql.in"
--general management --
#include "sql/manage/ManageHelper.sql.in"
CREATE OR REPLACE FUNCTION topology.postgis_topology_scripts_installed() RETURNS text
AS _POSTGIS_SQL_SELECT_POSTGIS_SCRIPTS_VERSION
LANGUAGE 'sql' IMMUTABLE;
-- Make sure topology is in database search path --
SELECT topology.AddToSearchPath('topology');
COMMIT;
|