mirror of
https://gitlab.com/wgp/dougal/software.git
synced 2025-12-06 09:07:09 +00:00
148 lines
3.9 KiB
PL/PgSQL
148 lines
3.9 KiB
PL/PgSQL
-- Turn project_summary into a materialised view
|
|
--
|
|
-- New schema version: 0.4.5
|
|
--
|
|
-- 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.
|
|
--
|
|
-- The project_summary view is quite a bottleneck. While it itself is
|
|
-- not the real culprit (rather the underlying views are), this is one
|
|
-- relatively cheap way of improving responsiveness from the client's
|
|
-- point of view.
|
|
-- We leave the details of how / when to refresh the view to the non-
|
|
-- database code.
|
|
--
|
|
-- 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);
|
|
|
|
DROP VIEW project_summary;
|
|
|
|
CREATE MATERIALIZED VIEW project_summary AS
|
|
WITH fls AS (
|
|
SELECT
|
|
avg((final_lines_summary.duration / ((final_lines_summary.num_points - 1))::double precision)) AS shooting_rate,
|
|
avg((final_lines_summary.length / date_part('epoch'::text, final_lines_summary.duration))) AS speed,
|
|
sum(final_lines_summary.duration) AS prod_duration,
|
|
sum(final_lines_summary.length) AS prod_distance
|
|
FROM final_lines_summary
|
|
), project AS (
|
|
SELECT
|
|
p.pid,
|
|
p.name,
|
|
p.schema
|
|
FROM public.projects p
|
|
WHERE (split_part(current_setting('search_path'::text), ','::text, 1) = p.schema)
|
|
)
|
|
SELECT
|
|
project.pid,
|
|
project.name,
|
|
project.schema,
|
|
( SELECT count(*) AS count
|
|
FROM preplot_lines
|
|
WHERE (preplot_lines.class = 'V'::bpchar)) AS lines,
|
|
ps.total,
|
|
ps.virgin,
|
|
ps.prime,
|
|
ps.other,
|
|
ps.ntba,
|
|
ps.remaining,
|
|
( SELECT to_json(fs.*) AS to_json
|
|
FROM final_shots fs
|
|
ORDER BY fs.tstamp
|
|
LIMIT 1) AS fsp,
|
|
( SELECT to_json(fs.*) AS to_json
|
|
FROM final_shots fs
|
|
ORDER BY fs.tstamp DESC
|
|
LIMIT 1) AS lsp,
|
|
( SELECT count(*) AS count
|
|
FROM raw_lines rl) AS seq_raw,
|
|
( SELECT count(*) AS count
|
|
FROM final_lines rl) AS seq_final,
|
|
fls.prod_duration,
|
|
fls.prod_distance,
|
|
fls.speed AS shooting_rate
|
|
FROM preplot_summary ps,
|
|
fls,
|
|
project;
|
|
|
|
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.4.5' THEN
|
|
RAISE EXCEPTION
|
|
USING MESSAGE='Patch already applied';
|
|
END IF;
|
|
|
|
IF current_db_version != '0.4.4' 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.4.5"}')
|
|
ON CONFLICT (key) DO UPDATE
|
|
SET value = public.info.value || '{"db_schema": "0.4.5"}' 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
|
|
--
|