From d3446d03bdbd973c721b12d2622ccaddb4c20831 Mon Sep 17 00:00:00 2001 From: "D. Berge" Date: Fri, 22 Aug 2025 00:01:02 +0200 Subject: [PATCH] Add database upgrade file 44 --- ...0.6.6-add-last_project_update-function.sql | 157 ++++++++++++++++++ 1 file changed, 157 insertions(+) create mode 100644 etc/db/upgrades/upgrade44-v0.6.6-add-last_project_update-function.sql diff --git a/etc/db/upgrades/upgrade44-v0.6.6-add-last_project_update-function.sql b/etc/db/upgrades/upgrade44-v0.6.6-add-last_project_update-function.sql new file mode 100644 index 0000000..863088f --- /dev/null +++ b/etc/db/upgrades/upgrade44-v0.6.6-add-last_project_update-function.sql @@ -0,0 +1,157 @@ +-- Add procedure to decimate old nav data +-- +-- New schema version: 0.6.6 +-- +-- ATTENTION: +-- +-- ENSURE YOU HAVE BACKED UP THE DATABASE BEFORE RUNNING THIS SCRIPT. +-- +-- +-- NOTE: This upgrade affects the public schema only. +-- NOTE: Each application starts a transaction, which must be committed +-- or rolled back. +-- +-- This adds a last_project_update(pid) function. It takes a project ID +-- and returns the last known timestamp from that project. Timestamps +-- are derived from multiple sources: +-- +-- - raw_shots table +-- - final_shots table +-- - events_log_full table +-- - info table where key = 'qc' +-- - files table, from the hashes (which contain the file's mtime) +-- - project configuration, looking for an _updatedOn property +-- +-- To apply, run as the dougal user: +-- +-- psql < v_last_ts OR v_last_ts IS NULL THEN + v_last_ts := v_current_ts; + END IF; + + -- From final_shots + EXECUTE 'SELECT max(tstamp) FROM ' || v_sid_rec.schema || '.final_shots' INTO v_current_ts; + IF v_current_ts > v_last_ts OR v_last_ts IS NULL THEN + v_last_ts := v_current_ts; + END IF; + + -- From info where key = 'qc' + EXECUTE 'SELECT value->>''updatedOn'' FROM ' || v_sid_rec.schema || '.info WHERE key = ''qc''' INTO v_current_str; + IF v_current_str IS NOT NULL THEN + v_current_ts := v_current_str::timestamptz; + IF v_current_ts > v_last_ts OR v_last_ts IS NULL THEN + v_last_ts := v_current_ts; + END IF; + END IF; + + -- From files hash second part, only for valid colon-separated hashes + EXECUTE 'SELECT max( split_part(hash, '':'', 2)::numeric ) FROM ' || v_sid_rec.schema || '.files WHERE hash ~ ''^[0-9]+:[0-9]+\\.[0-9]+:[0-9]+\\.[0-9]+:[0-9a-f]+$''' INTO v_current_unix; + IF v_current_unix IS NOT NULL THEN + v_current_ts := to_timestamp(v_current_unix); + IF v_current_ts > v_last_ts OR v_last_ts IS NULL THEN + v_last_ts := v_current_ts; + END IF; + END IF; + + -- From event_log_full + EXECUTE 'SELECT max(tstamp) FROM ' || v_sid_rec.schema || '.event_log_full' INTO v_current_ts; + IF v_current_ts > v_last_ts OR v_last_ts IS NULL THEN + v_last_ts := v_current_ts; + END IF; + END LOOP; + + -- From projects.meta->_updatedOn + SELECT (meta->>'_updatedOn')::timestamptz FROM public.projects WHERE pid = p_pid INTO v_current_ts; + IF v_current_ts > v_last_ts OR v_last_ts IS NULL THEN + v_last_ts := v_current_ts; + END IF; + + RETURN v_last_ts; + END; + $function$; + + -- END + +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.6.6' THEN + RAISE EXCEPTION + USING MESSAGE='Patch already applied'; + END IF; + + IF current_db_version != '0.6.5' THEN + RAISE EXCEPTION + USING MESSAGE='Invalid database version: ' || current_db_version, + HINT='Ensure all previous patches have been applied.'; + END IF; + + CALL pg_temp.upgrade_database(); +END; +$outer$ LANGUAGE plpgsql; + +CALL pg_temp.upgrade(); + +CALL pg_temp.show_notice('Cleaning up'); +DROP PROCEDURE pg_temp.upgrade_database (); +DROP PROCEDURE pg_temp.upgrade (); + +CALL pg_temp.show_notice('Updating db_schema version'); +INSERT INTO public.info VALUES ('version', '{"db_schema": "0.6.6"}') +ON CONFLICT (key) DO UPDATE + SET value = public.info.value || '{"db_schema": "0.6.6"}' 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 +--