mirror of
https://gitlab.com/wgp/dougal/software.git
synced 2025-12-06 12:47:08 +00:00
Add database upgrade file
This commit is contained in:
94
etc/db/upgrades/upgrade04-4d977848→3d70a460.sql
Normal file
94
etc/db/upgrades/upgrade04-4d977848→3d70a460.sql
Normal file
@@ -0,0 +1,94 @@
|
||||
-- Upgrade the database from commit 4d977848 to 3d70a460.
|
||||
--
|
||||
-- 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 adds the `meta` column to the output of the following views:
|
||||
--
|
||||
-- * raw_lines_summary; and
|
||||
-- * sequences_summary
|
||||
--
|
||||
-- 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 can be applied multiple times without ill effect.
|
||||
|
||||
|
||||
BEGIN;
|
||||
|
||||
CREATE OR REPLACE VIEW raw_lines_summary AS
|
||||
WITH summary AS (
|
||||
SELECT DISTINCT rs.sequence,
|
||||
first_value(rs.point) OVER w AS fsp,
|
||||
last_value(rs.point) OVER w AS lsp,
|
||||
first_value(rs.tstamp) OVER w AS ts0,
|
||||
last_value(rs.tstamp) OVER w AS ts1,
|
||||
count(rs.point) OVER w AS num_points,
|
||||
count(pp.point) OVER w AS num_preplots,
|
||||
public.st_distance(first_value(rs.geometry) OVER w, last_value(rs.geometry) OVER w) AS length,
|
||||
((public.st_azimuth(first_value(rs.geometry) OVER w, last_value(rs.geometry) OVER w) * (180)::double precision) / pi()) AS azimuth
|
||||
FROM (raw_shots rs
|
||||
LEFT JOIN preplot_points pp USING (line, point))
|
||||
WINDOW w AS (PARTITION BY rs.sequence ORDER BY rs.tstamp ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING)
|
||||
)
|
||||
SELECT rl.sequence,
|
||||
rl.line,
|
||||
s.fsp,
|
||||
s.lsp,
|
||||
s.ts0,
|
||||
s.ts1,
|
||||
(s.ts1 - s.ts0) AS duration,
|
||||
s.num_points,
|
||||
s.num_preplots,
|
||||
(( SELECT count(*) AS count
|
||||
FROM preplot_points
|
||||
WHERE ((preplot_points.line = rl.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_preplots) AS missing_shots,
|
||||
s.length,
|
||||
s.azimuth,
|
||||
rl.remarks,
|
||||
rl.ntbp,
|
||||
rl.meta
|
||||
FROM (summary s
|
||||
JOIN raw_lines rl USING (sequence));
|
||||
|
||||
DROP VIEW sequences_summary;
|
||||
CREATE OR REPLACE VIEW sequences_summary AS
|
||||
SELECT rls.sequence,
|
||||
rls.line,
|
||||
rls.fsp,
|
||||
rls.lsp,
|
||||
fls.fsp AS fsp_final,
|
||||
fls.lsp AS lsp_final,
|
||||
rls.ts0,
|
||||
rls.ts1,
|
||||
fls.ts0 AS ts0_final,
|
||||
fls.ts1 AS ts1_final,
|
||||
rls.duration,
|
||||
fls.duration AS duration_final,
|
||||
rls.num_preplots,
|
||||
COALESCE(fls.num_points, rls.num_points) AS num_points,
|
||||
COALESCE(fls.missing_shots, rls.missing_shots) AS missing_shots,
|
||||
COALESCE(fls.length, rls.length) AS length,
|
||||
COALESCE(fls.azimuth, rls.azimuth) AS azimuth,
|
||||
rls.remarks,
|
||||
fls.remarks AS remarks_final,
|
||||
rls.meta,
|
||||
fls.meta AS meta_final,
|
||||
CASE
|
||||
WHEN (rls.ntbp IS TRUE) THEN 'ntbp'::text
|
||||
WHEN (fls.sequence IS NULL) THEN 'raw'::text
|
||||
ELSE 'final'::text
|
||||
END AS status
|
||||
FROM (raw_lines_summary rls
|
||||
LEFT JOIN final_lines_summary fls USING (sequence));
|
||||
|
||||
--
|
||||
--NOTE Run `COMMIT;` now if all went well
|
||||
--
|
||||
|
||||
Reference in New Issue
Block a user