Skip to content
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
47 changes: 29 additions & 18 deletions db/deploy/001.sql
Original file line number Diff line number Diff line change
Expand Up @@ -5,13 +5,13 @@ BEGIN;
CREATE SCHEMA pgosm_flex_faker;


CREATE PROCEDURE pgosm_flex_faker.location_in_place_landuse()
CREATE PROCEDURE pgosm_flex_faker.point_in_place_landuse()
LANGUAGE plpgsql
AS $$
BEGIN

-- Define a custom `place_osm_types` table before executing to customize areas
CREATE TEMP TABLE IF NOT EXISTS place_osm_types AS
-- Define a custom `landuse_osm_types` table before executing to customize areas
CREATE TEMP TABLE IF NOT EXISTS landuse_osm_types AS
SELECT 'retail' AS osm_type
UNION
SELECT 'commercial' AS osm_type
Expand All @@ -24,16 +24,19 @@ BEGIN
WITH base AS (
SELECT osm_id, name, osm_type, admin_level, nest_level,
-- Rounding is assuming SRID 3857, or another unit in Meters or Feet.
ROUND(public.ST_Area(geom)::NUMERIC, 0) AS geom_area, geom
ROUND(public.ST_Area(geom)::NUMERIC, 0) AS geom_area,
geom
FROM osm.place_polygon_nested
-- Using innermost places to reduce likelihood over overlap
WHERE innermost
AND name <> ''
AND admin_level < 99
-- originally had following more strict checks, considering leaving
-- them off to make more flexible
/*AND name <> ''
AND admin_level < 99*/
), with_space AS (
-- Within each Place, find how many places are "near" (intersects)
-- or contain the types of places (commercial, retail, residential, etc)
-- defined in place_osm_types
-- defined in landuse_osm_types
SELECT b.osm_id,
COUNT(lp.osm_id) AS near_areas,
COALESCE(SUM(public.ST_Area(lp.geom)), 0) AS near_space,
Expand All @@ -42,10 +45,10 @@ BEGIN
FROM base b
LEFT JOIN osm.landuse_polygon lp
ON public.ST_Intersects(b.geom, lp.geom)
AND lp.osm_type IN (SELECT osm_type FROM place_osm_types)
AND lp.osm_type IN (SELECT osm_type FROM landuse_osm_types)
LEFT JOIN osm.landuse_polygon c
ON public.ST_Contains(b.geom, c.geom)
AND c.osm_type IN (SELECT osm_type FROM place_osm_types)
AND c.osm_type IN (SELECT osm_type FROM landuse_osm_types)
GROUP BY b.osm_id
)
SELECT b.*, ws.contained_areas, ws.contained_space,
Expand Down Expand Up @@ -117,6 +120,7 @@ BEGIN
CREATE TEMP TABLE selected AS
WITH a AS (
SELECT p.osm_id,
-- Range of total_score: .02 - .65
s.contained_space_score + s.near_space_score
AS total_score,
random() as rnd
Expand Down Expand Up @@ -179,21 +183,28 @@ BEGIN
;


-----------------------------------------
-- Identify roads where a building could be
-- Not using actual buildings / addresses because:
---- a) privacy
---- b) coverage
/*
Identify roads where a building could be
Not using actual buildings / addresses because:
a) privacy
b) coverage

Main limitation of this is the point chosen on the road could extend far
outside of the landuse.
As I'm writing these initial versions I don't care, consider splitting road
lines on the place boundaries to limit in the future if desired.
*/
DROP TABLE IF EXISTS selected_roads ;
CREATE TEMP TABLE selected_roads AS
WITH road_ranks AS (
SELECT p.osm_id AS place_osm_id, p.name AS place_name,
SELECT p.osm_id AS place_osm_id, p.osm_type AS place_osm_type,
p.name AS place_name,
rr.normalized_rnk AS road_type_score,
r.osm_id AS road_osm_id
FROM faker_place_polygon p
INNER JOIN osm.landuse_polygon c
ON public.ST_Contains(p.geom, c.geom)
AND c.osm_type IN (SELECT osm_type FROM place_osm_types)
AND c.osm_type IN (SELECT osm_type FROM landuse_osm_types)
INNER JOIN osm.road_line r
ON c.geom && r.geom
AND r.route_motor
Expand All @@ -216,8 +227,8 @@ BEGIN

DROP TABLE IF EXISTS faker_store_location;
CREATE TEMP TABLE faker_store_location AS
SELECT a.place_osm_id, a.place_name, a.road_osm_id,
r.osm_type, r.name, r.ref,
SELECT a.place_osm_id, a.place_osm_type, a.place_name, a.road_osm_id,
r.osm_type AS road_osm_type, r.name AS road_name, r.ref AS road_ref,
public.ST_LineInterpolatePoint(public.ST_LineMerge(r.geom), random()) AS geom
FROM selected_roads a
INNER JOIN osm.road_line r ON a.road_osm_id = r.osm_id
Expand Down
1 change: 1 addition & 0 deletions docs/src/SUMMARY.md
Original file line number Diff line number Diff line change
Expand Up @@ -2,3 +2,4 @@

- [What is PgOSM Flex Faker?](pgosm-flex-faker.md)
- [Quick Start](quick-start.md)
- [Docker image](docker-image.md)
11 changes: 11 additions & 0 deletions docs/src/docker-image.md
Original file line number Diff line number Diff line change
@@ -0,0 +1,11 @@
# Docker image

## Building the image

Build latest. Occasionally run with `--no-cache` to force some software updates.

```bash
docker pull rustprooflabs/pgosm-flex:latest
docker build -t rustprooflabs/pgosm-flex-faker:latest .
```

41 changes: 36 additions & 5 deletions docs/src/quick-start.md
Original file line number Diff line number Diff line change
Expand Up @@ -15,8 +15,7 @@ mkdir ~/pgosm-data
export POSTGRES_USER=postgres
export POSTGRES_PASSWORD=mysecretpassword

docker stop pgosm-faker
docker build -t rustprooflabs/pgosm-flex-faker .
docker pull rustprooflabs/pgosm-flex-faker:latest

docker run --name pgosm-faker -d --rm \
-v ~/pgosm-data:/app/output \
Expand All @@ -35,6 +34,8 @@ docker exec -it \
```


## Load Faker Objects

After the data completes processing, load the PgOSM Flex Faker database structures.
This is done using Sqitch.

Expand All @@ -48,16 +49,46 @@ Connect to the database and call this stored procedure. The generated data
is left in a temp table, each run of the stored procedure will produce new,
random results.

## Run Faker generation

```sql
CALL pgosm_flex_faker.location_in_place_landuse();
CALL pgosm_flex_faker.point_in_place_landuse();
SELECT COUNT(*) FROM faker_store_location;
```


Save the data somewhere you want, in a non-temp table.

```sql
CREATE TABLE AS my_fake_stores AS
CREATE TABLE my_fake_stores AS
SELECT *
FROM faker_store_locations
FROM faker_store_location
;
```


Rerun, save second set.

```sql
CALL pgosm_flex_faker.point_in_place_landuse();
CREATE TABLE my_fake_stores_v2 AS
SELECT *
FROM faker_store_location
;
```

## Custom Places for Shops

The procedure `pgosm_flex_faker.point_in_place_landuse()` allows overriding
the inclusion of `retail` and `commercial` landuse.

```sql
DROP TABLE IF EXISTS landuse_osm_types;
CREATE TEMP TABLE IF NOT EXISTS landuse_osm_types AS
SELECT 'college' AS osm_type
UNION
SELECT 'recreation_ground' AS osm_type
UNION
SELECT 'vineyard' AS osm_type
;
```