Commit 034758b1 authored by Eliot Blennerhassett's avatar Eliot Blennerhassett

Include parts of address_number in linz_addr

parent bed7973f
......@@ -3,7 +3,42 @@
.trace ON
/*
/*-- ---------------------------------------------------------------------
ATTACH DATABASE "nz_address-osm_raw.sqlite" AS "osm";
DELETE FROM osm_addr;
-- Gathering the OSM addresses as points
INSERT INTO osm_addr
SELECT
1 as is_way,
w.way_id as osm_id,
t1.v as housenumber,
t2.v as street,
ST_Centroid(ST_Collect(n.Geometry)) as geom
FROM osm.osm_ways as w
INNER JOIN osm_way_tags as t1 on (w.way_id = t1.way_id and t1.k = "addr:housenumber")
LEFT JOIN osm.osm_way_tags as t2 on (w.way_id = t2.way_id and t2.k = "addr:street")
INNER JOIN osm.osm_way_refs as r on (r.way_id = w.way_id)
INNER JOIN osm.osm_nodes as n on (r.node_id = n.node_id)
GROUP BY w.way_id
;
INSERT INTO osm_addr
SELECT
0 as is_way,
n.node_id as osm_id,
t1.v as housenumber,
t2.v as street,
Geometry as geom
FROM osm.osm_nodes as n
INNER JOIN osm.osm_node_tags as t1 on (n.node_id = t1.node_id and t1.k = "addr:housenumber")
LEFT JOIN osm.osm_node_tags as t2 on (n.node_id = t2.node_id and t2.k = "addr:street")
;
DETACH osm;
-- ---------------------------------------------------------------------
ATTACH DATABASE "nz-street-address.gpkg" as "linz";
--SELECT AutoGPKGStart();
......@@ -18,6 +53,10 @@ SELECT
address_id as linz_id,
change_id,
address_type as addr_type,
unit_value,
address_number,
address_number_suffix,
address_number_high,
suburb_locality,
town_city,
full_address_number,
......@@ -27,7 +66,9 @@ FROM linz.nz_street_address;
DETACH linz;
drop table places;
-- ---------------------------------------------------------------------
drop table if exists places;
create table places as
select
town_city,
......@@ -36,41 +77,11 @@ select
from linz_addr
where addr_type = 'Road'
group by town_city, suburb_locality
order by town_city, suburb_locality
order by town_city, suburb_locality;
*/
ATTACH DATABASE "nz_address-osm_raw.sqlite" AS "osm";
DELETE FROM osm_addr;
-- Gathering the OSM addresses as points
INSERT INTO osm_addr
SELECT
'way' as type,
w.way_id as osm_id,
t1.v as housenumber,
t2.v as street,
ST_Centroid(ST_Collect(n.Geometry)) as geom
FROM osm.osm_ways as w
INNER JOIN osm_way_tags as t1 on (w.way_id = t1.way_id and t1.k = "addr:housenumber")
LEFT JOIN osm.osm_way_tags as t2 on (w.way_id = t2.way_id and t2.k = "addr:street")
INNER JOIN osm.osm_way_refs as r on (r.way_id = w.way_id)
INNER JOIN osm.osm_nodes as n on (r.node_id = n.node_id)
GROUP BY w.way_id
;
INSERT INTO osm_addr
SELECT
'node' as type,
n.node_id as osm_id,
t1.v as housenumber,
t2.v as street,
Geometry as geom
FROM osm.osm_nodes as n
INNER JOIN osm.osm_node_tags as t1 on (n.node_id = t1.node_id and t1.k = "addr:housenumber")
LEFT JOIN osm.osm_node_tags as t2 on (n.node_id = t2.node_id and t2.k = "addr:street")
;
-- ---------------------------------------------------------------------
DETACH osm;
*/
-- ---------------------------------------------------------------------
-- matching linz vs OSM nodes on housenumber and empirically determined distance
......@@ -81,6 +92,7 @@ DELETE FROM osm_linz;
-- first, exact match on road, number; close proximity
INSERT INTO osm_linz
SELECT
o.is_way as is_way,
o.osm_id as osm_id,
l.linz_id as linz_id,
Distance(o.geom, l.geom) as D
......@@ -93,7 +105,12 @@ JOIN linz_addr as l on
-- remaining OSM entries with streets
-- 6539/46858
create table temp.inexact as
select type, osm_addr.osm_id, housenumber, street, geom
select
is_way,
osm_addr.osm_id,
housenumber,
street,
geom
from osm_addr
left outer join osm_linz as done
on osm_addr.osm_id = done.osm_id
......@@ -103,10 +120,15 @@ order by street, housenumber
-- and without streets
insert into temp.inexact
select type, osm_addr.osm_id, housenumber, street, geom
select
is_way,
osm_addr.osm_id,
housenumber,
street,
geom
from osm_addr
left outer join osm_linz as done
on osm_addr.osm_id = done.osm_id
on osm_addr.osm_id = done.osm_id
where done.osm_id is null and street is null
order by street, housenumber
;
......@@ -114,6 +136,7 @@ order by street, housenumber
-- Inexact matches with LINZ data on housenumber and proximity
CREATE TABLE temp.linz_inexact AS
SELECT
o.is_way as is_way,
o.osm_id as osm_id,
l.linz_id as linz_id,
Distance(o.geom, l.geom) as D
......@@ -128,7 +151,7 @@ INSERT INTO osm_linz
SELECT * from temp.linz_inexact;
-- The LINZ addresses identified as not already in OSM
drop table linz_not_osm;
drop table if exists linz_not_osm;
create table linz_not_osm as
select
......@@ -141,7 +164,7 @@ select
linz_addr.town_city as c
from linz_addr
left outer join osm_linz
on (osm_id = linz_addr.linz_id)
on (osm_linz.linz_id = linz_addr.linz_id)
where
osm_linz.linz_id is NULL
and linz_addr.addr_type != "Water"
......
-- initialise osmlinzaddr.sqlite (as spatialite database)
-- initialise (as spatialite database)
-- Subset of LINZ address data,
CREATE TABLE linz_addr(
linz_id mediumint,
linz_id mediumint primary key,
change_id mediumint,
addr_type text(20),
'unit_value' TEXT(70),
'address_number' MEDIUMINT,
'address_number_suffix' TEXT(10),
'address_number_high' MEDIUMINT,
suburb_locality text(80),
town_city text(80),
full_address_number text(100),
full_road_name text(250)
);
SELECT AddGeometryColumn('linz_addr', "geom", 4326, "POINT", "XY", 1);
-- OSM address data
CREATE TABLE osm_addr(
type TEXT,
is_way BOOLEAN,
osm_id INT,
housenumber TEXT,
street TEXT
street TEXT,
primary key (is_way, osm_id)
);
SELECT AddGeometryColumn('osm_addr', "geom", 4326, "POINT", "XY", 1);
-- Cross reference of items representing the same address
CREATE TABLE osm_linz(
'is_way' boolean,
'osm_id' int,
'linz_id' int,
'D' real -- distance between OSM and LINZ address (? degrees ?)
'D' real, -- distance between OSM and LINZ address (? degrees ?)
foreign key (is_way, osm_id) references osm_addr(is_way, osm_id),
foreign key (linz_id) references linz_addr(linz_id)
);
Markdown is supported
0% or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment