diff --git a/etc/db/upgrades/upgrade01-78adb2be→7917eeeb.sql b/etc/db/upgrades/upgrade01-78adb2be→7917eeeb.sql new file mode 100644 index 0000000..cf240a5 --- /dev/null +++ b/etc/db/upgrades/upgrade01-78adb2be→7917eeeb.sql @@ -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'); diff --git a/etc/db/upgrades/upgrade02-6e7ba82e→53f71f70.sql b/etc/db/upgrades/upgrade02-6e7ba82e→53f71f70.sql new file mode 100644 index 0000000..5bcc2fa --- /dev/null +++ b/etc/db/upgrades/upgrade02-6e7ba82e→53f71f70.sql @@ -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 < '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 +-- +