mirror of
https://gitlab.com/wgp/dougal/software.git
synced 2025-12-06 08:07:08 +00:00
163 lines
4.7 KiB
PL/PgSQL
163 lines
4.7 KiB
PL/PgSQL
-- Fix wrong number of missing shots in summary views
|
|
--
|
|
-- New schema version: 0.3.13
|
|
--
|
|
-- ATTENTION:
|
|
--
|
|
-- ENSURE YOU HAVE BACKED UP THE DATABASE BEFORE RUNNING THIS SCRIPT.
|
|
--
|
|
--
|
|
-- NOTE: This upgrade affects all schemas in the database.
|
|
-- NOTE: Each application starts a transaction, which must be committed
|
|
-- or rolled back.
|
|
--
|
|
-- Fixes a bug in the `final_lines_summary` and `raw_lines_summary` views
|
|
-- which results in the number of missing shots being miscounted on jobs
|
|
-- using three sources.
|
|
--
|
|
-- To apply, run as the dougal user:
|
|
--
|
|
-- psql <<EOF
|
|
-- \i $THIS_FILE
|
|
-- COMMIT;
|
|
-- EOF
|
|
--
|
|
-- NOTE: It can be applied multiple times without ill effect.
|
|
--
|
|
|
|
BEGIN;
|
|
|
|
CREATE OR REPLACE PROCEDURE pg_temp.show_notice (notice text) AS $$
|
|
BEGIN
|
|
RAISE NOTICE '%', notice;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
CREATE OR REPLACE PROCEDURE pg_temp.upgrade_survey_schema (schema_name text) AS $outer$
|
|
BEGIN
|
|
|
|
RAISE NOTICE 'Updating schema %', schema_name;
|
|
-- We need to set the search path because some of the trigger
|
|
-- functions reference other tables in survey schemas assuming
|
|
-- they are in the search path.
|
|
EXECUTE format('SET search_path TO %I,public', schema_name);
|
|
|
|
|
|
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 missing_sequence_raw_points
|
|
WHERE missing_sequence_raw_points.sequence = s.sequence) AS missing_shots,
|
|
s.length,
|
|
s.azimuth,
|
|
rl.remarks,
|
|
rl.ntbp,
|
|
rl.meta
|
|
FROM (summary s
|
|
JOIN raw_lines rl USING (sequence));
|
|
|
|
|
|
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 missing_sequence_final_points
|
|
WHERE missing_sequence_final_points.sequence = s.sequence) AS missing_shots,
|
|
s.length,
|
|
s.azimuth,
|
|
fl.remarks,
|
|
fl.meta
|
|
FROM (summary s
|
|
JOIN final_lines fl USING (sequence));
|
|
|
|
END;
|
|
$outer$ LANGUAGE plpgsql;
|
|
|
|
CREATE OR REPLACE PROCEDURE pg_temp.upgrade () AS $outer$
|
|
DECLARE
|
|
row RECORD;
|
|
current_db_version TEXT;
|
|
BEGIN
|
|
|
|
SELECT value->>'db_schema' INTO current_db_version FROM public.info WHERE key = 'version';
|
|
|
|
IF current_db_version >= '0.3.13' THEN
|
|
RAISE EXCEPTION
|
|
USING MESSAGE='Patch already applied';
|
|
END IF;
|
|
|
|
IF current_db_version != '0.3.12' THEN
|
|
RAISE EXCEPTION
|
|
USING MESSAGE='Invalid database version: ' || current_db_version,
|
|
HINT='Ensure all previous patches have been applied.';
|
|
END IF;
|
|
|
|
FOR row IN
|
|
SELECT schema_name FROM information_schema.schemata
|
|
WHERE schema_name LIKE 'survey_%'
|
|
ORDER BY schema_name
|
|
LOOP
|
|
CALL pg_temp.upgrade_survey_schema(row.schema_name);
|
|
END LOOP;
|
|
END;
|
|
$outer$ LANGUAGE plpgsql;
|
|
|
|
CALL pg_temp.upgrade();
|
|
|
|
CALL pg_temp.show_notice('Cleaning up');
|
|
DROP PROCEDURE pg_temp.upgrade_survey_schema (schema_name text);
|
|
DROP PROCEDURE pg_temp.upgrade ();
|
|
|
|
CALL pg_temp.show_notice('Updating db_schema version');
|
|
INSERT INTO public.info VALUES ('version', '{"db_schema": "0.3.13"}')
|
|
ON CONFLICT (key) DO UPDATE
|
|
SET value = public.info.value || '{"db_schema": "0.3.13"}' WHERE public.info.key = 'version';
|
|
|
|
|
|
CALL pg_temp.show_notice('All done. You may now run "COMMIT;" to persist the changes');
|
|
DROP PROCEDURE pg_temp.show_notice (notice text);
|
|
|
|
--
|
|
--NOTE Run `COMMIT;` now if all went well
|
|
--
|