9.5 KiB
9.5 KiB
OpenStreetMap Database Summary and Operations Guide
Current Database State
- Database name:
planet
- User:
osmadmin
- Content: Partial world data, including France, Italy, and possibly other European countries
- Notable points: Eiffel Tower (Paris), Colosseum (Rome), detailed data including small businesses
Connecting to the Database
To connect to the database using psql:
psql -d planet -U osmadmin
Importing New Data
Single File Import
To import a single .osm.pbf file:
osm2pgsql -d planet -U osmadmin -a --slim --drop --hstore --multi-geometry -C 28000 -W --number-processes 8 /path/to/your/new_file.osm.pbf
Explanation of options:
-d planet
: Database name-U osmadmin
: Database user-a
: Append mode (adds to existing data)--slim
: Memory-efficient mode for large imports--drop
: Drops temporary tables after import--hstore
: Stores all tags in an hstore column--multi-geometry
: Allows for multi-polygon geometries-C 28000
: Sets cache size to 28GB (adjust based on available RAM)-W
: Uses disk for temporary storage--number-processes 8
: Enables parallel processing (adjust based on CPU cores)
Batch Import Script
For importing multiple files, create a shell script named import_osm.sh
:
#!/bin/bash
FILES="/home/ed/share/map/extract/pbf/*.osm.pbf"
for f in $FILES
do
echo "Processing $f"
osm2pgsql -d planet -U osmadmin -a --slim --drop --hstore --multi-geometry -C 28000 -W --number-processes 8 "$f"
done
echo "All files processed. Running VACUUM ANALYZE."
psql -d planet -U osmadmin -c "VACUUM ANALYZE;"
Make the script executable and run it:
chmod +x import_osm.sh
./import_osm.sh
This script will process all .osm.pbf files in the specified directory and optimize the database afterward.
Post-Import Optimization
After importing data, always run:
VACUUM ANALYZE;
This optimizes the database for better query performance.
Useful Queries for Data Verification
-
Count total points:
SELECT COUNT(*) FROM planet_osm_point;
-
Search for specific locations:
SELECT osm_id, name, ST_AsText(ST_Transform(way, 4326)) AS lonlat_location FROM planet_osm_point WHERE name ILIKE '%eiffel%' LIMIT 5;
-
Check data extent:
SELECT ST_AsText(ST_Envelope(ST_Collect(way))) AS bounding_box FROM planet_osm_point;
Remember to adjust file paths, database name, and user as necessary for your specific setup.
planet=# \d planet_osm_point
Table "public.planet_osm_point"
Column | Type | Collation | Nullable | Default
--------------------+----------------------+-----------+----------+---------
osm_id | bigint | | |
access | text | | |
addr:housename | text | | |
addr:housenumber | text | | |
addr:interpolation | text | | |
admin_level | text | | |
aerialway | text | | |
aeroway | text | | |
amenity | text | | |
area | text | | |
barrier | text | | |
bicycle | text | | |
brand | text | | |
bridge | text | | |
boundary | text | | |
building | text | | |
capital | text | | |
construction | text | | |
covered | text | | |
culvert | text | | |
cutting | text | | |
denomination | text | | |
disused | text | | |
ele | text | | |
embankment | text | | |
foot | text | | |
generator:source | text | | |
harbour | text | | |
highway | text | | |
historic | text | | |
horse | text | | |
intermittent | text | | |
junction | text | | |
landuse | text | | |
layer | text | | |
leisure | text | | |
lock | text | | |
man_made | text | | |
military | text | | |
motorcar | text | | |
name | text | | |
natural | text | | |
office | text | | |
oneway | text | | |
operator | text | | |
place | text | | |
population | text | | |
power | text | | |
power_source | text | | |
public_transport | text | | |
railway | text | | |
ref | text | | |
religion | text | | |
route | text | | |
service | text | | |
shop | text | | |
sport | text | | |
surface | text | | |
toll | text | | |
tourism | text | | |
tower:type | text | | |
tunnel | text | | |
water | text | | |
waterway | text | | |
wetland | text | | |
width | text | | |
wood | text | | |
z_order | integer | | |
tags | hstore | | |
way | geometry(Point,3857) | | |
Indexes:
"planet_osm_point_osm_id_idx" btree (osm_id)
"planet_osm_point_way_idx" gist (way)
Triggers:
planet_osm_point_osm2pgsql_valid BEFORE INSERT OR UPDATE ON planet_osm_point FOR EACH ROW EXECUTE FUNCTION planet_osm_point_osm2pgsql_valid()