Add building_properties table, buildings.revision_id

This commit is contained in:
Tom Russell 2018-09-30 16:17:11 +01:00
parent fb43998f86
commit 8fdcb8defa
4 changed files with 36 additions and 9 deletions

View File

@ -1,8 +1,10 @@
-- Drop all tables
ALTER TABLE buildings DROP COLUMN IF EXISTS revision_id;
DROP TABLE IF EXISTS logs;
DROP TABLE IF EXISTS users;
DROP TABLE IF EXISTS user_sessions;
DROP TABLE IF EXISTS user_categories;
DROP TABLE IF EXISTS user_access_levels;
DROP TABLE IF EXISTS building_properties;
DROP TABLE IF EXISTS buildings;
DROP TABLE IF EXISTS geometries;

View File

@ -20,19 +20,33 @@ CREATE TABLE IF NOT EXISTS geometries (
CREATE TABLE IF NOT EXISTS buildings (
-- internal unique id
building_id serial PRIMARY KEY,
-- unique property reference number
ref_uprn bigint,
-- OS MasterMap topo id
ref_toid varchar,
-- OSM reference id
ref_osm_id bigint,
-- jsonb document for all data, attributes to be specified in application
building_doc jsonb,
-- reference to geometry, aiming to decouple from geometry provider
geometry_id integer REFERENCES geometries
);
ALTER TABLE buildings ADD CONSTRAINT buildings_ref_toid_len CHECK (length(ref_toid) < 90);
--
-- Properties table
--
-- To store UPRN information normalised - building<->property relationship is typically
-- one-to-many, may be many-to-many.
CREATE TABLE IF NOT EXISTS building_properties (
-- internal primary key
building_property_id serial PRIMARY KEY,
-- UPRN
uprn bigint,
-- Parent should reference UPRN, but assume dataset may be (initially) incomplete
parent_uprn bigint,
-- Building ID may be null for failed matches
building_id integer REFERENCES buildings,
-- TOID match provided by AddressBase
toid varchar
);
--
-- User categories
--
@ -104,9 +118,9 @@ CREATE TABLE IF NOT EXISTS logs (
-- default timestamp to time now
log_timestamp TIMESTAMP default NOW(),
-- log document to be extended in application
-- log from..to; only changed values (aim to be reversible)
log_from jsonb,
log_to jsonb,
-- log from..to; only changed values (must be reversible)
forward_patch jsonb,
reverse_patch jsonb,
-- log user id
user_id uuid REFERENCES users,
-- log building id
@ -116,3 +130,5 @@ CREATE TABLE IF NOT EXISTS logs (
CREATE INDEX IF NOT EXISTS log_timestamp_idx ON logs ( log_timestamp );
CREATE INDEX IF NOT EXISTS log_user_idx ON logs ( user_id );
CREATE INDEX IF NOT EXISTS log_building_idx ON logs ( building_id );
ALTER TABLE buildings ADD COLUMN revision_id bigint REFERENCES logs ( log_id );

View File

@ -1,3 +1,6 @@
-- Drop building indexes
DROP INDEX IF EXISTS building_uprn_idx;
DROP INDEX IF EXISTS uprn_building_idx;
DROP INDEX IF EXISTS uprn_uprn_idx;
DROP INDEX IF EXISTS uprn_parent_idx;
DROP INDEX IF EXISTS building_toid_idx;

View File

@ -1,7 +1,13 @@
-- Create building indexes after bulk loading
-- UPRN index over buildings
CREATE INDEX building_uprn_idx ON buildings ( ref_uprn );
-- Building index over UPRNs (given a building, find UPRNs)
CREATE INDEX uprn_building_idx ON building_properties ( building_id );
-- UPRN index (given a UPRN, find buildings or parents)
CREATE INDEX uprn_uprn_idx ON building_properties ( uprn );
-- Parent index over UPRNs (given a UPRN, find children)
CREATE INDEX uprn_parent_idx ON building_properties ( parent_uprn );
-- TOID index over buildings
CREATE INDEX building_toid_idx ON buildings ( ref_toid );