From: Paul Ramsey Date: Thu, 9 Sep 2004 17:38:41 +0000 (+0000) Subject: Added example spatial SQL section. X-Git-Tag: pgis_0_9_1~4 X-Git-Url: https://granicus.if.org/sourcecode?a=commitdiff_plain;h=f74c3659ff006869466e73ae5f2892d81ad69072;p=postgis Added example spatial SQL section. git-svn-id: http://svn.osgeo.org/postgis/trunk@790 b70326c6-7e19-0410-871a-916f4a2858ee --- diff --git a/doc/Makefile b/doc/Makefile index d9902f0b8..4aa8e2ca4 100644 --- a/doc/Makefile +++ b/doc/Makefile @@ -7,7 +7,7 @@ postgis-out.xml: postgis.xml html: postgis-out.xml xsltproc \ - --output postgis.html \ + --output html/postgis.html \ --param shade.verbatim 1 \ --param chunk.section.depth 0 \ --stringparam html.stylesheet style.css \ diff --git a/doc/postgis.xml b/doc/postgis.xml index 8de915262..f2b952099 100644 --- a/doc/postgis.xml +++ b/doc/postgis.xml @@ -1343,7 +1343,7 @@ WHERE - -b + -b Use a binary cursor. This will help reduce the likelihood @@ -1553,7 +1553,7 @@ WHERE the_geom && 'BOX3D(90900 190900, 100100 200100)'::box3d ------------+-------------------+------------------- gid | integer | Unique ID name | character varying | Road Name - type | character varying | Road Type Number + the_geom | geometry | Location Geometry (Linestring) The table definition for the bc_municipality table is: @@ -1569,27 +1569,168 @@ WHERE the_geom && 'BOX3D(90900 190900, 100100 200100)'::box3d - Find all the roads within 1 kilometer of a point. + What is the total length of all roads, expressed in + kilometers? You can answer this question with a very simple piece of SQL: - SELECT * FROM geom_table WHERE Distance( the_geom, + postgis=# SELECT sum(length(the_geom))/1000 AS km_roads FROM bc_roads; + km_roads +------------------ + 70842.1243039643 +(1 row) - Find the length of all roads + How large is the city of Prince George, in + hectares? - You can answer this question with a very simple piece of - SQL: + This query combines an attribute condition (on the + municipality name) with a spatial calculation (of the + area): + + postgis=# SELECT area(the_geom)/10000 AS hectares FROM bc_municipality + WHERE name = 'PRINCE GEORGE'; + hectares +------------------ + 32657.9103824927 +(1 row) + + + + + + What is the largest municipality in the province, by + area? + + + + This query brings a spatial measurement into the query + condition. There are several ways of approaching this problem, + but the most efficient is below: + + postgis=# SELECT name, area(the_geom)/10000 AS hectares + FROM bc_municipality + ORDER BY hectares DESC + LIMIT 1; + name | hectares +---------------+----------------- + TUMBLER RIDGE | 155020.02556131 +(1 row) - SELECT * FROM geom_table WHERE Distance( the_geom, + Note that in order to answer this query we have to + calculate the area of every polygon. If we were doing this a + lot it would make sense to add an area column to the table + that we could separately index for performance. By ordering + the results in a descending direction, and them using the + PostgreSQL "LIMIT" command we can easily pick off the largest + value without using an aggregate function like max(). + + + + + + What is the length of roads fully contained within each + municipality? + + + + This is an example of a "spatial join", because we are + bringing together data from two tables (doing a join) but + using a spatial interaction condition ("contained") as the + join condition rather than the usual relational approach of + joining on a common key: + + postgis=# SELECT m.name, sum(length(r.the_geom))/1000 as roads_km + FROM bc_roads AS r,bc_municipality AS m + WHERE r.the_geom && m.the_geom + AND contains(m.the_geom,r.the_geom) + GROUP BY m.name + ORDER BY roads_km; + + name | roads_km +----------------------------+------------------ + SURREY | 1539.47553551242 + VANCOUVER | 1450.33093486576 + LANGLEY DISTRICT | 833.793392535662 + BURNABY | 773.769091404338 + PRINCE GEORGE | 694.37554369147 + ... + + This query takes a while, because every road in the + table is summarized into the final result (about 250K roads + for our particular example table). For smaller overlays + (several thousand records on several hundred) the response can + be very fast. + + + + + + Create a new table with all the roads within the city of + Prince George. + + + + This is an example of an "overlay", which takes in two + tables and outputs a new table that consists of spatially + clipped or cut resultants. Unlike the "spatial join" + demonstrated above, this query actually creates new + geometries. An overlay is like a turbo-charged spatial join, + and is useful for more exact analysis work: + + postgis=# CREATE TABLE pg_roads as + SELECT intersection(r.the_geom, m.the_geom) AS intersection_geom, + length(r.the_geom) AS rd_orig_length, + r.* + FROM bc_roads AS r, bc_municipality AS m + WHERE r.the_geom && m.the_geom + AND intersects(r.the_geom, m.the_geom) + AND m.name = 'PRINCE GEORGE'; + + + + + + What is the length in kilometers of "Douglas St" in + Victoria? + + + + postgis=# SELECT sum(length(r.the_geom))/1000 AS kilometers + FROM bc_roads r, bc_municipality m + WHERE r.the_geom && m.the_geom + AND r.name = 'Douglas St' + AND m.name = 'VICTORIA'; + kilometers +------------------ + 4.89151904172838 +(1 row) + + + + + + What is the largest municipality polygon that has a + hole? + + + + postgis=# SELECT gid, name, area(the_geom) AS area + FROM bc_municipality + WHERE nrings(the_geom) > 1 + ORDER BY area DESC LIMIT 1; + gid | name | area +-----+--------------+------------------ + 12 | SPALLUMCHEEN | 257374619.430216 +(1 row) @@ -3568,14 +3709,12 @@ FROM geometry_table; Return a modified [multi]polygon having no ring segment - longer then the given distance. Interpolated points will - have Z and M values (if needed) set to 0. Distance computation - is performed in 2d only. - + longer then the given distance. Interpolated points will have Z + and M values (if needed) set to 0. Distance computation is + performed in 2d only. - - + \ No newline at end of file