Create/drop database elements conditionally
This commit is contained in:
parent
f8e329ce77
commit
36ee3e8c23
@ -3,7 +3,7 @@
|
|||||||
--
|
--
|
||||||
-- To store building outlines.
|
-- To store building outlines.
|
||||||
-- Geometries form the backbone, expected to be provided from other sources.
|
-- Geometries form the backbone, expected to be provided from other sources.
|
||||||
CREATE TABLE geometries (
|
CREATE TABLE IF NOT EXISTS geometries (
|
||||||
-- internal unique id
|
-- internal unique id
|
||||||
geometry_id serial PRIMARY KEY,
|
geometry_id serial PRIMARY KEY,
|
||||||
-- cross-reference to data source id
|
-- cross-reference to data source id
|
||||||
@ -17,25 +17,30 @@ CREATE TABLE geometries (
|
|||||||
--
|
--
|
||||||
-- To store collected data.
|
-- To store collected data.
|
||||||
-- This is the core dataset to be collected by the application.
|
-- This is the core dataset to be collected by the application.
|
||||||
CREATE TABLE buildings (
|
CREATE TABLE IF NOT EXISTS buildings (
|
||||||
-- internal unique id
|
-- internal unique id
|
||||||
building_id serial PRIMARY KEY,
|
building_id serial PRIMARY KEY,
|
||||||
-- unique property reference number
|
-- unique property reference number
|
||||||
uprn bigint,
|
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
|
-- jsonb document for all data, attributes to be specified in application
|
||||||
building_doc jsonb,
|
building_doc jsonb,
|
||||||
-- reference to geometry, aiming to decouple from geometry provider
|
-- reference to geometry, aiming to decouple from geometry provider
|
||||||
geometry_id integer REFERENCES geometries
|
geometry_id integer REFERENCES geometries
|
||||||
);
|
);
|
||||||
|
ALTER TABLE buildings ADD CONSTRAINT buildings_ref_toid_len CHECK (length(ref_toid) < 90);
|
||||||
|
|
||||||
--
|
--
|
||||||
-- User categories
|
-- User categories
|
||||||
--
|
--
|
||||||
-- Self-selected, optional categories
|
-- Self-selected, optional categories
|
||||||
CREATE TABLE user_categories (
|
CREATE TABLE IF NOT EXISTS user_categories (
|
||||||
category_id serial PRIMARY KEY,
|
category_id serial PRIMARY KEY,
|
||||||
-- category name/short description
|
-- category name/short description
|
||||||
category varchar(60)
|
category varchar
|
||||||
);
|
);
|
||||||
INSERT INTO user_categories ( category_id, category ) VALUES ( 1, 'Not provided');
|
INSERT INTO user_categories ( category_id, category ) VALUES ( 1, 'Not provided');
|
||||||
|
|
||||||
@ -43,10 +48,10 @@ INSERT INTO user_categories ( category_id, category ) VALUES ( 1, 'Not provided'
|
|||||||
-- User access levels
|
-- User access levels
|
||||||
--
|
--
|
||||||
-- If necessary for moderation
|
-- If necessary for moderation
|
||||||
CREATE TABLE user_access_levels (
|
CREATE TABLE IF NOT EXISTS user_access_levels (
|
||||||
access_level_id serial PRIMARY KEY,
|
access_level_id serial PRIMARY KEY,
|
||||||
-- name/short description
|
-- name/short description
|
||||||
access_level varchar(60)
|
access_level varchar
|
||||||
);
|
);
|
||||||
INSERT INTO user_access_levels ( access_level_id, access_level ) VALUES ( 1, 'untrusted');
|
INSERT INTO user_access_levels ( access_level_id, access_level ) VALUES ( 1, 'untrusted');
|
||||||
|
|
||||||
@ -54,15 +59,15 @@ INSERT INTO user_access_levels ( access_level_id, access_level ) VALUES ( 1, 'un
|
|||||||
-- Users table
|
-- Users table
|
||||||
--
|
--
|
||||||
-- Minimal user data to support login and edit history
|
-- Minimal user data to support login and edit history
|
||||||
CREATE TABLE users (
|
CREATE TABLE IF NOT EXISTS users (
|
||||||
-- internal unique id
|
-- internal unique id
|
||||||
user_id uuid PRIMARY KEY DEFAULT gen_random_uuid(),
|
user_id uuid PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||||
-- username for login (required)
|
-- username for login (required)
|
||||||
username varchar(30) UNIQUE NOT NULL,
|
username varchar UNIQUE NOT NULL,
|
||||||
-- email address for password reset (optional)
|
-- email address for password reset (optional)
|
||||||
email varchar(50) UNIQUE,
|
email varchar UNIQUE,
|
||||||
-- password - as generated from hash(salt+password) via pgcrypto
|
-- password - as generated from hash(salt+password) via pgcrypto
|
||||||
pass varchar(60),
|
pass varchar,
|
||||||
-- date registered
|
-- date registered
|
||||||
registered timestamp default NOW(),
|
registered timestamp default NOW(),
|
||||||
-- user category (optional, self-selected)
|
-- user category (optional, self-selected)
|
||||||
@ -70,28 +75,30 @@ CREATE TABLE users (
|
|||||||
-- user access level (essential, default untrusted)
|
-- user access level (essential, default untrusted)
|
||||||
access_level integer REFERENCES user_access_levels NOT NULL DEFAULT 1
|
access_level integer REFERENCES user_access_levels NOT NULL DEFAULT 1
|
||||||
);
|
);
|
||||||
|
ALTER TABLE users ADD CONSTRAINT users_username_len CHECK (length(username) < 30);
|
||||||
|
ALTER TABLE users ADD CONSTRAINT users_email_len CHECK (length(email) < 50);
|
||||||
|
ALTER TABLE users ADD CONSTRAINT users_pass_len CHECK (length(pass) < 60);
|
||||||
|
|
||||||
CREATE INDEX user_username_idx ON users ( username );
|
CREATE INDEX IF NOT EXISTS user_username_idx ON users ( username );
|
||||||
CREATE INDEX user_email_idx ON users ( email );
|
CREATE INDEX IF NOT EXISTS user_email_idx ON users ( email );
|
||||||
|
|
||||||
--
|
--
|
||||||
-- User session table
|
-- User session table
|
||||||
--
|
--
|
||||||
--
|
CREATE TABLE IF NOT EXISTS user_sessions (
|
||||||
CREATE TABLE user_sessions (
|
|
||||||
sid varchar PRIMARY KEY,
|
sid varchar PRIMARY KEY,
|
||||||
sess json NOT NULL,
|
sess json NOT NULL,
|
||||||
expire timestamp(6) NOT NULL
|
expire timestamp(6) NOT NULL
|
||||||
);
|
);
|
||||||
|
|
||||||
CREATE INDEX user_sessions_expire_idx on user_sessions ( expire );
|
CREATE INDEX IF NOT EXISTS user_sessions_expire_idx on user_sessions ( expire );
|
||||||
|
|
||||||
--
|
--
|
||||||
-- Logs table
|
-- Logs table
|
||||||
--
|
--
|
||||||
-- To store all changes to building data, recording users and change in data
|
-- To store all changes to building data, recording users and change in data
|
||||||
-- over time.
|
-- over time.
|
||||||
CREATE TABLE logs (
|
CREATE TABLE IF NOT EXISTS logs (
|
||||||
-- integer for internal unique id
|
-- integer for internal unique id
|
||||||
log_id bigserial PRIMARY KEY,
|
log_id bigserial PRIMARY KEY,
|
||||||
-- default timestamp to time now
|
-- default timestamp to time now
|
||||||
@ -106,6 +113,6 @@ CREATE TABLE logs (
|
|||||||
building_id integer REFERENCES buildings
|
building_id integer REFERENCES buildings
|
||||||
);
|
);
|
||||||
|
|
||||||
CREATE INDEX log_timestamp_idx ON logs ( log_timestamp );
|
CREATE INDEX IF NOT EXISTS log_timestamp_idx ON logs ( log_timestamp );
|
||||||
CREATE INDEX log_user_idx ON logs ( user_id );
|
CREATE INDEX IF NOT EXISTS log_user_idx ON logs ( user_id );
|
||||||
CREATE INDEX log_building_idx ON logs ( building_id );
|
CREATE INDEX IF NOT EXISTS log_building_idx ON logs ( building_id );
|
||||||
|
@ -1,10 +1,10 @@
|
|||||||
-- Create indexes after bulk loading geometries and building records
|
-- Create indexes after bulk loading geometries and building records
|
||||||
|
|
||||||
-- Spatial index over geometries
|
-- Spatial index over geometries
|
||||||
CREATE INDEX geometries_idx ON geometries USING GIST ( geometry_geom );
|
CREATE INDEX IF NOT EXISTS geometries_idx ON geometries USING GIST ( geometry_geom );
|
||||||
|
|
||||||
-- Source ID index over geometries
|
-- Source ID index over geometries
|
||||||
CREATE INDEX geometries_source_idx ON geometries ( source_id );
|
CREATE INDEX IF NOT EXISTS geometries_source_idx ON geometries ( source_id );
|
||||||
|
|
||||||
-- Index over building geometry_id (expect to look up building by geometry_id for map tiles)
|
-- Index over building geometry_id (expect to look up building by geometry_id for map tiles)
|
||||||
CREATE INDEX building_geometry_idx ON buildings ( geometry_id );
|
CREATE INDEX IF NOT EXISTS building_geometry_idx ON buildings ( geometry_id );
|
||||||
|
@ -1,4 +1,3 @@
|
|||||||
-- Drop building indexes
|
-- Drop building indexes
|
||||||
|
|
||||||
-- UPRN index over buildings
|
|
||||||
DROP INDEX IF EXISTS building_uprn_idx;
|
DROP INDEX IF EXISTS building_uprn_idx;
|
||||||
|
DROP INDEX IF EXISTS building_toid_idx;
|
||||||
|
@ -1,4 +1,7 @@
|
|||||||
-- Create building indexes after bulk loading
|
-- Create building indexes after bulk loading
|
||||||
|
|
||||||
-- UPRN index over buildings
|
-- UPRN index over buildings
|
||||||
CREATE INDEX building_uprn_idx ON buildings ( uprn );
|
CREATE INDEX building_uprn_idx ON buildings ( ref_uprn );
|
||||||
|
|
||||||
|
-- TOID index over buildings
|
||||||
|
CREATE INDEX building_toid_idx ON buildings ( ref_toid );
|
||||||
|
Loading…
Reference in New Issue
Block a user