Skip to content

Commit

Permalink
Add county and state to addresses
Browse files Browse the repository at this point in the history
  • Loading branch information
dunkelstern committed Jul 14, 2022
1 parent 22a6cd5 commit d2e5512
Show file tree
Hide file tree
Showing 3 changed files with 32 additions and 0 deletions.
24 changes: 24 additions & 0 deletions osmgeocoder/data/sql/geocoder/003-forward_geocoding.sql
Original file line number Diff line number Diff line change
Expand Up @@ -41,13 +41,17 @@ AS $$
h.house_number::text,
c.postcode::text,
NULLIF(c.name, '')::text as city,
NULLIF(a6.name, '')::text as county,
NULLIF(a4.name, '')::text as "state",
h.geometry::gis.geometry(point, 3857),
gis.ST_Distance(h.geometry, center) as distance,
'00000000-0000-0000-0000-000000000000'::uuid as license_id
FROM
public.osm_struct_streets s
JOIN public.osm_struct_cities c ON s.city_id = c.id
JOIN public.osm_struct_house h ON h.street_id = s.id
LEFT JOIN public.osm_admin a4 ON gis.ST_Contains(a4.geometry, h.geometry::gis.geometry(point, 3857)) and a4.admin_level = 4
LEFT JOIN public.osm_admin a6 ON gis.ST_Contains(a6.geometry, h.geometry::gis.geometry(point, 3857)) and a6.admin_level = 6
WHERE
(center IS NULL OR gis.ST_DWithin(h.geometry, center, radius)) -- only search around center if center is not null
AND s.name % search_term
Expand Down Expand Up @@ -92,13 +96,17 @@ BEGIN
h.house_number::text,
c.postcode::text,
NULLIF(c.name, '')::text as city,
NULLIF(a6.name, '')::text as county,
NULLIF(a4.name, '')::text as "state",
h.geometry::gis.geometry(point, 3857),
gis.ST_Distance(h.geometry, center) as distance,
'00000000-0000-0000-0000-000000000000'::uuid as license_id
FROM
public.osm_struct_streets s
JOIN public.osm_struct_cities c ON s.city_id = c.id
JOIN public.osm_struct_house h ON h.street_id = s.id
LEFT JOIN public.osm_admin a4 ON gis.ST_Contains(a4.geometry, h.geometry::gis.geometry(point, 3857)) and a4.admin_level = 4
LEFT JOIN public.osm_admin a6 ON gis.ST_Contains(a6.geometry, h.geometry::gis.geometry(point, 3857)) and a6.admin_level = 6
WHERE
(center IS NULL OR gis.ST_DWithin(h.geometry, center, radius)) -- only search around center if center is not null
AND gis.ST_Within(gis.ST_Centroid(h.geometry), country_poly) -- intersect with country polygon
Expand Down Expand Up @@ -177,13 +185,17 @@ $$
h.house_number::text,
c.postcode::text,
NULLIF(c.name, '')::text as city,
NULLIF(a6.name, '')::text as county,
NULLIF(a4.name, '')::text as "state",
h.geometry::gis.geometry(point, 3857),
gis.ST_Distance(h.geometry, center) as distance,
'00000000-0000-0000-0000-000000000000'::uuid as license_id
FROM
public.osm_struct_streets s
JOIN public.osm_struct_cities c ON s.city_id = c.id
JOIN public.osm_struct_house h ON h.street_id = s.id
LEFT JOIN public.osm_admin a4 ON gis.ST_Contains(a4.geometry, h.geometry::gis.geometry(point, 3857)) and a4.admin_level = 4
LEFT JOIN public.osm_admin a6 ON gis.ST_Contains(a6.geometry, h.geometry::gis.geometry(point, 3857)) and a6.admin_level = 6
WHERE
(center IS NULL OR gis.ST_DWithin(h.geometry, center, radius)) -- only search around center if center is not null
AND c.name % search_city
Expand Down Expand Up @@ -232,13 +244,17 @@ BEGIN
h.house_number::text,
c.postcode::text,
NULLIF(c.name, '')::text as city,
NULLIF(a6.name, '')::text as county,
NULLIF(a4.name, '')::text as "state",
h.geometry::gis.geometry(point, 3857),
gis.ST_Distance(h.geometry, center) as distance,
'00000000-0000-0000-0000-000000000000'::uuid as license_id
FROM
public.osm_struct_streets s
JOIN public.osm_struct_cities c ON s.city_id = c.id
JOIN public.osm_struct_house h ON h.street_id = s.id
LEFT JOIN public.osm_admin a4 ON gis.ST_Contains(a4.geometry, h.geometry::gis.geometry(point, 3857)) and a4.admin_level = 4
LEFT JOIN public.osm_admin a6 ON gis.ST_Contains(a6.geometry, h.geometry::gis.geometry(point, 3857)) and a6.admin_level = 6
WHERE
(center IS NULL OR gis.ST_DWithin(h.geometry, center, radius)) -- only search around center if center is not null
AND gis.ST_Within(gis.ST_Centroid(h.geometry), country_poly) -- intersect with country polygon
Expand Down Expand Up @@ -314,13 +330,17 @@ $$
h.house_number::text,
c.postcode::text,
NULLIF(c.name, '')::text as city,
NULLIF(a6.name, '')::text as county,
NULLIF(a4.name, '')::text as "state",
h.geometry::gis.geometry(point, 3857),
gis.ST_Distance(h.geometry, center) as distance,
'00000000-0000-0000-0000-000000000000'::uuid as license_id
FROM
public.osm_struct_streets s
JOIN public.osm_struct_cities c ON s.city_id = c.id
JOIN public.osm_struct_house h ON h.street_id = s.id
LEFT JOIN public.osm_admin a4 ON gis.ST_Contains(a4.geometry, h.geometry::gis.geometry(point, 3857)) and a4.admin_level = 4
LEFT JOIN public.osm_admin a6 ON gis.ST_Contains(a6.geometry, h.geometry::gis.geometry(point, 3857)) and a6.admin_level = 6
WHERE
(center IS NULL OR gis.ST_DWithin(h.geometry, center, radius)) -- only search around center if center is not null
AND s.name % search_term
Expand Down Expand Up @@ -369,13 +389,17 @@ BEGIN
h.house_number::text,
c.postcode::text,
NULLIF(c.name, '')::text as city,
NULLIF(a6.name, '')::text as county,
NULLIF(a4.name, '')::text as "state",
h.geometry::gis.geometry(point, 3857),
gis.ST_Distance(h.geometry, center) as distance,
'00000000-0000-0000-0000-000000000000'::uuid as license_id
FROM
public.osm_struct_streets s
JOIN public.osm_struct_cities c ON s.city_id = c.id
JOIN public.osm_struct_house h ON h.street_id = s.id
LEFT JOIN public.osm_admin a4 ON gis.ST_Contains(a4.geometry, h.geometry::gis.geometry(point, 3857)) and a4.admin_level = 4
LEFT JOIN public.osm_admin a6 ON gis.ST_Contains(a6.geometry, h.geometry::gis.geometry(point, 3857)) and a6.admin_level = 6
WHERE
(center IS NULL OR gis.ST_DWithin(h.geometry, center, radius)) -- only search around center if center is not null
AND gis.ST_Within(gis.ST_Centroid(h.geometry), country_poly) -- intersect with country polygon
Expand Down
6 changes: 6 additions & 0 deletions osmgeocoder/data/sql/geocoder/004-reverse_geocoding.sql
Original file line number Diff line number Diff line change
Expand Up @@ -33,6 +33,8 @@ BEGIN
h.housenumber as house_number,
c.postcode,
c.city,
NULL as county,
NULL as "state",
location,
gis.ST_Distance(location, point) as distance,
c.license_id
Expand Down Expand Up @@ -69,12 +71,16 @@ BEGIN
h.house_number,
c.postcode,
c.name as city,
NULLIF(a6.name, '')::text as county,
NULLIF(a4.name, '')::text as "state",
h.geometry as location,
gis.ST_Distance(h.geometry, point) as distance,
'00000000-0000-0000-0000-000000000000'::uuid as license_id
FROM public.osm_struct_house h
JOIN public.osm_struct_streets s ON h.street_id = s.id
JOIN public.osm_struct_cities c ON s.city_id = c.id
LEFT JOIN public.osm_admin a4 ON gis.ST_Contains(a4.geometry, h.geometry::gis.geometry(point, 3857)) and a4.admin_level = 4
LEFT JOIN public.osm_admin a6 ON gis.ST_Contains(a6.geometry, h.geometry::gis.geometry(point, 3857)) and a6.admin_level = 6
WHERE
gis.ST_X(h.geometry) >= gis.ST_X(point) - radius
AND gis.ST_X(h.geometry) <= gis.ST_X(point) + radius
Expand Down
2 changes: 2 additions & 0 deletions osmgeocoder/data/sql/prepare/001-custom_types.sql
Original file line number Diff line number Diff line change
Expand Up @@ -12,6 +12,8 @@ BEGIN
house_number text,
postcode text,
city text,
county text,
"state" text,
location gis.geometry(point, 3857),
distance float,
license_id uuid
Expand Down

0 comments on commit d2e5512

Please sign in to comment.