mirror of
https://gitlab.com/wgp/dougal/software.git
synced 2025-12-06 13:27:08 +00:00
137 lines
3.7 KiB
MySQL
137 lines
3.7 KiB
MySQL
|
|
-- Fix project_summary view.
|
||
|
|
--
|
||
|
|
-- New schema version: 0.3.2
|
||
|
|
--
|
||
|
|
-- 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.
|
||
|
|
--
|
||
|
|
-- This fixes a problem with the project_summary view. In its common table
|
||
|
|
-- expression, the view definition tried to search public.projects based on
|
||
|
|
-- the search path value with the following expression:
|
||
|
|
--
|
||
|
|
-- (current_setting('search_path'::text) ~~ (p.schema || '%'::text))
|
||
|
|
--
|
||
|
|
-- That is of course bound to fail as soon as the schema goes above `survey_9`
|
||
|
|
-- because `survey_10 LIKE ('survey_1' || '%')` is TRUE.
|
||
|
|
--
|
||
|
|
-- The new mechanism relies on splitting the search_path.
|
||
|
|
--
|
||
|
|
-- NOTE: The survey schema needs to be the leftmost element in search_path.
|
||
|
|
--
|
||
|
|
-- 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 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 $$
|
||
|
|
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 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;
|
||
|
|
|
||
|
|
|
||
|
|
ALTER TABLE project_summary OWNER TO postgres;
|
||
|
|
|
||
|
|
END;
|
||
|
|
$$ LANGUAGE plpgsql;
|
||
|
|
|
||
|
|
CREATE OR REPLACE PROCEDURE pg_temp.upgrade_15 () AS $$
|
||
|
|
DECLARE
|
||
|
|
row RECORD;
|
||
|
|
BEGIN
|
||
|
|
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;
|
||
|
|
$$ LANGUAGE plpgsql;
|
||
|
|
|
||
|
|
CALL pg_temp.upgrade_15();
|
||
|
|
|
||
|
|
CALL show_notice('Cleaning up');
|
||
|
|
DROP PROCEDURE pg_temp.upgrade_survey_schema (schema_name text);
|
||
|
|
DROP PROCEDURE pg_temp.upgrade_15 ();
|
||
|
|
|
||
|
|
CALL show_notice('Updating db_schema version');
|
||
|
|
INSERT INTO public.info VALUES ('version', '{"db_schema": "0.3.2"}')
|
||
|
|
ON CONFLICT (key) DO UPDATE
|
||
|
|
SET value = public.info.value || '{"db_schema": "0.3.2"}' WHERE public.info.key = 'version';
|
||
|
|
|
||
|
|
|
||
|
|
CALL show_notice('All done. You may now run "COMMIT;" to persist the changes');
|
||
|
|
DROP PROCEDURE show_notice (notice text);
|
||
|
|
|
||
|
|
--
|
||
|
|
--NOTE Run `COMMIT;` now if all went well
|
||
|
|
--
|