Skip to content

Commit

Permalink
Merge pull request #4292 from pnorman/pointonsurface_index
Browse files Browse the repository at this point in the history
Use custom indexes to speed up ST_PointOnSurface queries
  • Loading branch information
pnorman committed Jan 28, 2021
2 parents faead20 + 31c649a commit 42a6baf
Show file tree
Hide file tree
Showing 5 changed files with 36 additions and 28 deletions.
2 changes: 1 addition & 1 deletion INSTALL.md
Original file line number Diff line number Diff line change
Expand Up @@ -27,7 +27,7 @@ osm2pgsql -G --hstore --style openstreetmap-carto.style --tag-transform-script o
You can find a more detailed guide to setting up a database and loading data with osm2pgsql at [switch2osm.org](https://switch2osm.org/manually-building-a-tile-server-16-04-2-lts/).

### Custom indexes
Custom indexes are not required, but will speed up rendering, particularly for full planet databases, heavy load, or other production environments. They will not be as helpful with development using small extracts.
Custom indexes are required for rendering performance and are essential on full planet databases.

```
psql -d gis -f indexes.sql
Expand Down
5 changes: 4 additions & 1 deletion indexes.sql
Original file line number Diff line number Diff line change
Expand Up @@ -17,11 +17,14 @@ CREATE INDEX planet_osm_line_waterway
CREATE INDEX planet_osm_point_place
ON planet_osm_point USING GIST (way)
WHERE place IS NOT NULL AND name IS NOT NULL;
CREATE INDEX planet_osm_polygon_admin
ON planet_osm_polygon USING GIST (ST_PointOnSurface(way))
WHERE name IS NOT NULL AND boundary = 'administrative' AND admin_level IN ('0', '1', '2', '3', '4');
CREATE INDEX planet_osm_polygon_military
ON planet_osm_polygon USING GIST (way)
WHERE (landuse = 'military' OR military = 'danger_area') AND building IS NULL;
CREATE INDEX planet_osm_polygon_name
ON planet_osm_polygon USING GIST (way)
ON planet_osm_polygon USING GIST (ST_PointOnSurface(way))
WHERE name IS NOT NULL;
CREATE INDEX planet_osm_polygon_nobuilding
ON planet_osm_polygon USING GIST (way)
Expand Down
4 changes: 4 additions & 0 deletions indexes.yml
Original file line number Diff line number Diff line change
Expand Up @@ -18,7 +18,11 @@ line:
polygon:
# The polygon table is by far the largest, and generally the slowest
name:
function: ST_PointOnSurface(way)
where: name IS NOT NULL
admin:
function: ST_PointOnSurface(way)
where: name IS NOT NULL AND boundary = 'administrative' AND admin_level IN ('0', '1', '2', '3', '4')
nobuilding:
where: building IS NULL
military:
Expand Down
37 changes: 19 additions & 18 deletions project.mml
Original file line number Diff line number Diff line change
Expand Up @@ -1187,10 +1187,10 @@ Layer:
way_area/NULLIF(POW(!scale_denominator!*0.001*0.28,2),0) AS way_pixels,
name
FROM planet_osm_polygon
WHERE way && !bbox!
WHERE ST_PointOnSurface(way) && !bbox!
AND name IS NOT NULL
AND boundary = 'administrative'
AND admin_level = '2'
AND name IS NOT NULL
AND way_area > 100*POW(!scale_denominator!*0.001*0.28,2)
AND way_area < 4000000*POW(!scale_denominator!*0.001*0.28,2)
AND osm_id < 0
Expand Down Expand Up @@ -1233,10 +1233,10 @@ Layer:
admin_level,
ref
FROM planet_osm_polygon
WHERE way && !bbox!
WHERE ST_PointOnSurface(way) && !bbox!
AND name IS NOT NULL
AND boundary = 'administrative'
AND admin_level = '4'
AND name IS NOT NULL
AND way_area > 3000*POW(!scale_denominator!*0.001*0.28,2)
AND way_area < 4000000*POW(!scale_denominator!*0.001*0.28,2)
AND osm_id < 0
Expand Down Expand Up @@ -1343,7 +1343,7 @@ Layer:
tags->'station' AS station,
way_area
FROM planet_osm_polygon
WHERE way && !bbox!
WHERE way && !bbox! -- Not ST_PointOnSurface(way) because name might be NULL
AND way_area < 768000*POW(!scale_denominator!*0.001*0.28,2)
UNION ALL
SELECT
Expand Down Expand Up @@ -1396,7 +1396,7 @@ Layer:
name,
way_area/NULLIF(POW(!scale_denominator!*0.001*0.28,2),0) AS way_pixels
FROM planet_osm_polygon
WHERE way && !bbox!
WHERE way && !bbox! -- Not ST_PointOnSurface(way) because name might be NULL
AND junction = 'yes'
AND way_area < 768000*POW(!scale_denominator!*0.001*0.28,2)
ORDER BY way_pixels DESC NULLS LAST
Expand All @@ -1415,7 +1415,8 @@ Layer:
man_made,
name
FROM planet_osm_polygon
WHERE way && !bbox!
WHERE ST_PointOnSurface(way) && !bbox!
AND name IS NOT NULL
AND man_made = 'bridge'
AND way_area > 125*POW(!scale_denominator!*0.001*0.28,2)
AND way_area < 768000*POW(!scale_denominator!*0.001*0.28,2)
Expand All @@ -1435,10 +1436,10 @@ Layer:
name,
admin_level
FROM planet_osm_polygon
WHERE way && !bbox!
WHERE ST_PointOnSurface(way) && !bbox!
AND name IS NOT NULL
AND boundary = 'administrative'
AND admin_level IN ('5', '6')
AND name IS NOT NULL
AND way_area > 12000*POW(!scale_denominator!*0.001*0.28,2)
AND way_area < 196000*POW(!scale_denominator!*0.001*0.28,2)
AND osm_id < 0
Expand Down Expand Up @@ -1621,7 +1622,7 @@ Layer:
tags,
way_area
FROM planet_osm_polygon
WHERE way && !bbox!
WHERE way && !bbox! -- Not ST_PointOnSurface(way) because name might be NULL
AND way_area < 768000*POW(!scale_denominator!*0.001*0.28,2)
UNION ALL
SELECT
Expand Down Expand Up @@ -1810,13 +1811,13 @@ Layer:
highway,
name
FROM planet_osm_polygon
WHERE way && !bbox!
WHERE ST_PointOnSurface(way) && !bbox!
AND name IS NOT NULL
AND (highway IN ('pedestrian', 'footway', 'service', 'living_street', 'platform')
OR (railway IN ('platform')
AND (tags->'location' NOT IN ('underground') OR (tags->'location') IS NULL)
AND (tunnel NOT IN ('yes', 'building_passage') OR tunnel IS NULL)
AND (covered NOT IN ('yes') OR covered IS NULL)))
AND name IS NOT NULL
AND way_area > 3000*POW(!scale_denominator!*0.001*0.28,2)
AND way_area < 768000*POW(!scale_denominator!*0.001*0.28,2)
ORDER BY way_area DESC
Expand Down Expand Up @@ -1980,7 +1981,8 @@ Layer:
name,
CASE WHEN building = 'no' OR building IS NULL THEN 'no' ELSE 'yes' END AS is_building -- always no with the where conditions
FROM planet_osm_polygon
WHERE way && !bbox!
WHERE ST_PointOnSurface(way) && !bbox!
AND name IS NOT NULL
AND (landuse IN ('forest', 'military', 'farmland')
OR military IN ('danger_area')
OR "natural" IN ('wood', 'glacier', 'sand', 'scree', 'shingle', 'bare_rock', 'water', 'bay', 'strait')
Expand All @@ -1989,7 +1991,6 @@ Layer:
OR (boundary = 'protected_area' AND tags->'protect_class' IN ('1','1a','1b','2','3','4','5','6'))
OR leisure IN ('nature_reserve'))
AND building IS NULL
AND name IS NOT NULL
AND way_area > 100*POW(!scale_denominator!*0.001*0.28,2)
AND way_area < 768000*POW(!scale_denominator!*0.001*0.28,2)
ORDER BY way_area DESC
Expand Down Expand Up @@ -2048,10 +2049,10 @@ Layer:
ST_PointOnSurface(way) AS way,
way_area/NULLIF(POW(!scale_denominator!*0.001*0.28,2),0) AS way_pixels
FROM planet_osm_polygon
WHERE way && !bbox!
WHERE ST_PointOnSurface(way) && !bbox!
AND name IS NOT NULL
AND building IS NOT NULL
AND building NOT IN ('no')
AND name IS NOT NULL
AND way_area < 4000000*POW(!scale_denominator!*0.001*0.28,2)
ORDER BY way_area DESC
) AS building_text
Expand Down Expand Up @@ -2084,7 +2085,7 @@ Layer:
tags->'addr:flats' AS addr_flats,
way_area/NULLIF(POW(!scale_denominator!*0.001*0.28,2),0) AS way_pixels
FROM planet_osm_polygon
WHERE way && !bbox!
WHERE way && !bbox! -- Not ST_PointOnSurface(way) because name might be NULL
AND (("addr:housenumber" IS NOT NULL) OR ("addr:housename" IS NOT NULL) OR ((tags->'addr:unit') IS NOT NULL) OR ((tags->'addr:flats') IS NOT NULL))
AND building IS NOT NULL
AND way_area < 4000000*POW(!scale_denominator!*0.001*0.28,2)
Expand Down Expand Up @@ -2221,7 +2222,7 @@ Layer:
tags,
way_area
FROM planet_osm_polygon
WHERE way && !bbox!
WHERE way && !bbox! -- Not ST_PointOnSurface(way) because name might be NULL
AND way_area < 768000*POW(!scale_denominator!*0.001*0.28,2)
UNION ALL
SELECT
Expand Down
16 changes: 8 additions & 8 deletions scripts/indexes.py
Original file line number Diff line number Diff line change
Expand Up @@ -8,15 +8,15 @@

import argparse, sys, os, yaml

def index_statement(table, name, conditions=None, concurrent=False,notexist=False, fillfactor=None):
def index_statement(table, name, function, conditions=None, concurrent=False,notexist=False, fillfactor=None):
options = ' CONCURRENTLY' if concurrent else ''
options += ' IF NOT EXISTS' if notexist else ''
storage = '' if fillfactor is None else '\n WITH (fillfactor={})'.format(fillfactor)
where = '' if conditions is None else '\n WHERE {}'.format(conditions)
return ('CREATE INDEX{options} {table}_{name}\n' +
' ON {table} USING GIST (way)' +
' ON {table} USING GIST ({function})' +
'{storage}' +
'{where};\n').format(table="planet_osm_"+table, name=name,
'{where};\n').format(table="planet_osm_"+table, name=name, function=function,
storage=storage, options=options, where=where)

def parse(cb):
Expand All @@ -25,7 +25,7 @@ def parse(cb):

for table, data in sorted(indexes.items()):
for name, definition in sorted(data.items()):
cb(table, name, definition["where"])
cb(table, name, definition.get("function", "way"), definition["where"])

# The same as parse, but for osm2pgsql-built indexes
def osm2pgsql_parse(cb):
Expand All @@ -42,16 +42,16 @@ def osm2pgsql_parse(cb):
parser.add_argument('--reindex', help='Rebuild existing indexes', action='store_true', default=False)
args = parser.parse_args()

def cb (table, name, where):
print(index_statement(table, name, where, args.concurrent, args.notexist, args.fillfactor), end='')
def cb (table, name, function, where):
print(index_statement(table, name, function, where, args.concurrent, args.notexist, args.fillfactor), end='')

def reindex_cb(table, name, where):
def reindex_cb(table, name, function, where):
if not args.concurrent:
print('REINDEX planet_osm_{table}_{name};'.format(table=table, name=name))
else:
# Rebuilding indexes concurently requires making a new index, dropping the old one, and renaming.
print('ALTER INDEX planet_osm_{table}_{name} RENAME TO planet_osm_{table}_{name}_old;'.format(table=table, name=name))
cb(table, name, where)
cb(table, name, function, where)
print('DROP INDEX planet_osm_{table}_{name}_old;\n'.format(table=table, name=name))

print(('-- These are optional but suggested indexes for rendering OpenStreetMap Carto\n'+
Expand Down

0 comments on commit 42a6baf

Please sign in to comment.