PostGIS Snippets

Aus Geoinformation HSR
Version vom 22. Januar 2016, 14:43 Uhr von Stefan (Diskussion | Beiträge) (Point Constructors)

Wechseln zu: Navigation, Suche

See also:

Point Constructors

Point constructors for geometry and geography types: Howto construct and print a coordinate in EPSG:4326 and in lon/lat format in either textual or 'symbolic' form?

Works...

 /*1 */ SELECT ST_AsEWKT(ST_GeomFromText('POINT(-71.06 42.28)', 4326)) -- ok, preferred if text input
 /*2 */ SELECT ST_AsEWKT(ST_GeomFromText('SRID=4326;POINT(-71.06 42.28)')) --  ok (if srid 'inline')
 /*3 */ SELECT ST_AsEWKT(ST_GeomFromEWKT('SRID=4326;POINT(-71.06 42.28)')) -- ok, but why then ST_GeomFromText?
 /*4 */ SELECT ST_AsEWKT('SRID=4326;POINT(-71.06 42.28)'::geometry) -- ok, but prefer 1/ST_GeomFromText
 /*5 */ SELECT ST_AsEWKT(ST_SetSRID('POINT(-71.06 42.28)'::geometry, 4326)) -- ok, but prefer 1/ST_GeomFromText
 /*6 */ SELECT ST_AsEWKT(ST_MakePoint(-71.06, 42.28, 4326)) -- ok for 'symbolic' form. But why no EWKT returning?

...does not work with geography:

 /*1 */ SELECT ST_AsEWKT(ST_GeogFromText('POINT(-71.06 42.28)', 4326)) -- ERROR: unknown ST_GeogFromText()
 /*2a*/ SELECT ST_AsEWKT(ST_GeogFromText('SRID=4326;POINT(-71.06 42.28)')) -- ERROR: no ST_AsEWKT.  
 /*2b*/ SELECT ST_AsText(ST_GeogFromText('SRID=4326;POINT(-71.06 42.28)')) -- ok (if srid 'inline'); (there's no AsEWKT)
 /*3 */ SELECT ST_AsText(ST_GeogFromEWKT('SRID=4326;POINT(-71.06 42.28)')) -- ERROR: no ST_GeogFromEWKT. 
 /*4 */ SELECT ST_AsText('SRID=4326;POINT(-71.06 42.28)'::geography) -- ok (no AsEWKT), but prefer 1/ST_GeomFromText
 /*5 */ SELECT ST_AsText(ST_SetSRID('POINT(-71.06 42.28)'::geography, 4326)) -- ERROR: ok SetSRID w. geography unnecessary
 /*6 */ Equivalent to ST_MakePoint for geography types missing: => ST_MakePointG?

Wishlist for future(!) PostGIS developments:

  • Create ST_AsEWKT for geography and harmonize ST_AsText (depreciate with EWKT).
  • Create ST_GeogFromEWKT for geography and harmonize ST_GeogFromText (depreciate with EWKT).

Bounding Box (bbox, box, mbr, ...) Constructors

-- Works:

 SELECT ST_AsText(ST_SetSRID('BOX3D(572126 5671279,1258837 6154972)'::box3d, 900913))
 SELECT ST_AsText(ST_SetSRID('BOX(572126 5671279,1258837 6154972)'::box2d, 900913))
 SELECT ST_AsText(ST_SetSRID(ST_MakeBox2D(ST_Point(572126, 5671279), ST_Point(1258837, 6154972)), 900913))
 SELECT ST_AsText(ST_SetSRID(ST_MakeBox3D(ST_Point(572126, 5671279), ST_Point(1258837, 6154972)), 900913))

-- ...does not work:

 SELECT ST_AsText(SetSRID('BOX2D(572126 5671279,1258837 6154972)'::box2d, 900913))
 SELECT ST_AsText(ST_GeomFromText('BOX2D(572126 5671279,1258837 6154972)', 900913))
 SELECT ST_AsText(ST_GeomFromText('BOX3D(572126 5671279,1258837 6154972)', 900913))


hstore

Key-Value data type of PostgreSQL.

Index

Create index for a field of type hstore:

 DROP INDEX planet_osm_point_tags;
 CREATE INDEX planet_osm_point_tags 
   ON planet_osm_point 
   USING gin (tags)

Create a index with expression:

 DROP INDEX planet_osm_point_tags2;
 CREATE INDEX planet_osm_point_tags2 
   ON planet_osm_point 
   USING btree (tags)
   WHERE tags->'natural'='peak';

Statistics: Counting the different values in hstore

 SELECT lower(tags->'cuisine') as tags, count(*) AS count 
 FROM planet_osm_point WHERE tags ? 'cuisine'
 GROUP BY 1
 ORDER BY 2 DESC;
 "regional";416
 "italian";197
 "pizza";123
 
 SELECT count(*) AS c, cuisine FROM (
   SELECT lower(tags->'cuisine') AS cuisine FROM planet_osm_point WHERE tags ? 'cuisine'
   UNION ALL
   SELECT lower(tags->'cuisine') AS cuisine FROM planet_osm_polygon WHERE tags ? 'cuisine'
 ) AS t GROUP BY cuisine ORDER BY c DESC;