mirror of
https://gitlab.com/wgp/dougal/software.git
synced 2025-12-06 10:47:07 +00:00
Add database upgrade files.
These files contain the sequence of SQL commands needed to bring a database or project schema up to date with the latest template database or project schema. These files must be applied manually. Check the comments at the top of the file for instructions.
This commit is contained in:
22
etc/db/upgrades/upgrade01-78adb2be→7917eeeb.sql
Normal file
22
etc/db/upgrades/upgrade01-78adb2be→7917eeeb.sql
Normal file
@@ -0,0 +1,22 @@
|
||||
-- Upgrade the database from commit 78adb2be to 7917eeeb.
|
||||
--
|
||||
-- This upgrade affects the `public` schema only.
|
||||
--
|
||||
-- It creates a new table, `info`, for storing arbitrary JSON
|
||||
-- data not belonging to a specific project. Currently used
|
||||
-- for the equipment list, it could also serve to store user
|
||||
-- details, configuration settings, system state, etc.
|
||||
--
|
||||
-- To apply, run as the dougal user:
|
||||
--
|
||||
-- psql < $THIS_FILE
|
||||
--
|
||||
-- NOTE: It will fail harmlessly if applied twice.
|
||||
|
||||
|
||||
CREATE TABLE IF NOT EXISTS public.info (
|
||||
key text NOT NULL primary key,
|
||||
value jsonb
|
||||
);
|
||||
|
||||
CREATE TRIGGER info_tg AFTER INSERT OR DELETE OR UPDATE ON public.info FOR EACH ROW EXECUTE FUNCTION public.notify('info');
|
||||
160
etc/db/upgrades/upgrade02-6e7ba82e→53f71f70.sql
Normal file
160
etc/db/upgrades/upgrade02-6e7ba82e→53f71f70.sql
Normal file
@@ -0,0 +1,160 @@
|
||||
-- Upgrade the database from commit 6e7ba82e to 53f71f70.
|
||||
--
|
||||
-- NOTE: This upgrade must be applied to every schema in the database.
|
||||
-- NOTE: Each application starts a transaction, which must be committed
|
||||
-- or rolled back.
|
||||
--
|
||||
-- This merges two changes to the database.
|
||||
-- The first one (commit 5de64e6b) modifies the `event` view to return
|
||||
-- the `meta` column of timed and sequence events.
|
||||
-- The second one (commit 53f71f70) adds a primary key constraint to
|
||||
-- events_seq_labels (there is already an equivalent constraint on
|
||||
-- events_seq_timed).
|
||||
--
|
||||
-- To apply, run as the dougal user, for every schema in the database:
|
||||
--
|
||||
-- psql <<EOF
|
||||
-- SET search_path TO survey_*,public;
|
||||
-- \i $THIS_FILE
|
||||
-- COMMIT;
|
||||
-- EOF
|
||||
--
|
||||
-- NOTE: It will fail harmlessly if applied twice.
|
||||
|
||||
|
||||
BEGIN;
|
||||
|
||||
DROP VIEW events_seq_timed CASCADE; -- Brings down events too
|
||||
ALTER TABLE ONLY events_seq_labels
|
||||
ADD CONSTRAINT events_seq_labels_pkey PRIMARY KEY (id, label);
|
||||
|
||||
|
||||
CREATE OR REPLACE VIEW events_seq_timed AS
|
||||
SELECT s.sequence,
|
||||
s.point,
|
||||
s.id,
|
||||
s.remarks,
|
||||
rs.line,
|
||||
rs.objref,
|
||||
rs.tstamp,
|
||||
rs.hash,
|
||||
s.meta,
|
||||
rs.geometry
|
||||
FROM (events_seq s
|
||||
LEFT JOIN raw_shots rs USING (sequence, point));
|
||||
|
||||
|
||||
|
||||
CREATE OR REPLACE VIEW events AS
|
||||
WITH qc AS (
|
||||
SELECT rs.sequence,
|
||||
rs.point,
|
||||
ARRAY[jsonb_array_elements_text(q.labels)] AS labels
|
||||
FROM raw_shots rs,
|
||||
LATERAL jsonb_path_query(rs.meta, '$."qc".*."labels"'::jsonpath) q(labels)
|
||||
)
|
||||
SELECT 'sequence'::text AS type,
|
||||
false AS virtual,
|
||||
s.sequence,
|
||||
s.point,
|
||||
s.id,
|
||||
s.remarks,
|
||||
s.line,
|
||||
s.objref,
|
||||
s.tstamp,
|
||||
s.hash,
|
||||
s.meta,
|
||||
(public.st_asgeojson(public.st_transform(s.geometry, 4326)))::jsonb AS geometry,
|
||||
ARRAY( SELECT esl.label
|
||||
FROM events_seq_labels esl
|
||||
WHERE (esl.id = s.id)) AS labels
|
||||
FROM events_seq_timed s
|
||||
UNION
|
||||
SELECT 'timed'::text AS type,
|
||||
false AS virtual,
|
||||
rs.sequence,
|
||||
rs.point,
|
||||
t.id,
|
||||
t.remarks,
|
||||
rs.line,
|
||||
rs.objref,
|
||||
t.tstamp,
|
||||
rs.hash,
|
||||
t.meta,
|
||||
(t.meta -> 'geometry'::text) AS geometry,
|
||||
ARRAY( SELECT etl.label
|
||||
FROM events_timed_labels etl
|
||||
WHERE (etl.id = t.id)) AS labels
|
||||
FROM ((events_timed t
|
||||
LEFT JOIN events_timed_seq ts USING (id))
|
||||
LEFT JOIN raw_shots rs USING (sequence, point))
|
||||
UNION
|
||||
SELECT 'midnight shot'::text AS type,
|
||||
true AS virtual,
|
||||
v1.sequence,
|
||||
v1.point,
|
||||
((v1.sequence * 100000) + v1.point) AS id,
|
||||
''::text AS remarks,
|
||||
v1.line,
|
||||
v1.objref,
|
||||
v1.tstamp,
|
||||
v1.hash,
|
||||
'{}'::jsonb meta,
|
||||
(public.st_asgeojson(public.st_transform(v1.geometry, 4326)))::jsonb AS geometry,
|
||||
ARRAY[v1.label] AS labels
|
||||
FROM events_midnight_shot v1
|
||||
UNION
|
||||
SELECT 'qc'::text AS type,
|
||||
true AS virtual,
|
||||
rs.sequence,
|
||||
rs.point,
|
||||
((10000000 + (rs.sequence * 100000)) + rs.point) AS id,
|
||||
(q.remarks)::text AS remarks,
|
||||
rs.line,
|
||||
rs.objref,
|
||||
rs.tstamp,
|
||||
rs.hash,
|
||||
'{}'::jsonb meta,
|
||||
(public.st_asgeojson(public.st_transform(rs.geometry, 4326)))::jsonb AS geometry,
|
||||
('{QC}'::text[] || qc.labels) AS labels
|
||||
FROM (raw_shots rs
|
||||
LEFT JOIN qc USING (sequence, point)),
|
||||
LATERAL jsonb_path_query(rs.meta, '$."qc".*."results"'::jsonpath) q(remarks)
|
||||
WHERE (rs.meta ? 'qc'::text);
|
||||
|
||||
|
||||
CREATE OR REPLACE VIEW final_lines_summary AS
|
||||
WITH summary AS (
|
||||
SELECT DISTINCT fs.sequence,
|
||||
first_value(fs.point) OVER w AS fsp,
|
||||
last_value(fs.point) OVER w AS lsp,
|
||||
first_value(fs.tstamp) OVER w AS ts0,
|
||||
last_value(fs.tstamp) OVER w AS ts1,
|
||||
count(fs.point) OVER w AS num_points,
|
||||
public.st_distance(first_value(fs.geometry) OVER w, last_value(fs.geometry) OVER w) AS length,
|
||||
((public.st_azimuth(first_value(fs.geometry) OVER w, last_value(fs.geometry) OVER w) * (180)::double precision) / pi()) AS azimuth
|
||||
FROM final_shots fs
|
||||
WINDOW w AS (PARTITION BY fs.sequence ORDER BY fs.tstamp ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING)
|
||||
)
|
||||
SELECT fl.sequence,
|
||||
fl.line,
|
||||
s.fsp,
|
||||
s.lsp,
|
||||
s.ts0,
|
||||
s.ts1,
|
||||
(s.ts1 - s.ts0) AS duration,
|
||||
s.num_points,
|
||||
(( SELECT count(*) AS count
|
||||
FROM preplot_points
|
||||
WHERE ((preplot_points.line = fl.line) AND (((preplot_points.point >= s.fsp) AND (preplot_points.point <= s.lsp)) OR ((preplot_points.point >= s.lsp) AND (preplot_points.point <= s.fsp))))) - s.num_points) AS missing_shots,
|
||||
s.length,
|
||||
s.azimuth,
|
||||
fl.remarks,
|
||||
fl.meta
|
||||
FROM (summary s
|
||||
JOIN final_lines fl USING (sequence));
|
||||
|
||||
--
|
||||
--NOTE Run `COMMIT;` now if all went well
|
||||
--
|
||||
|
||||
Reference in New Issue
Block a user