From da578d2e506e15cc31a516ba2f52b4676b3f0e7e Mon Sep 17 00:00:00 2001 From: "D. Berge" Date: Wed, 27 Apr 2022 10:49:46 +0200 Subject: [PATCH] Fix project_summary view returning unwanted rows. Fixes #197. --- etc/db/database-version.sql | 4 +- etc/db/schema-template.sql | 2 +- .../upgrade15-v0.3.2-fix-project-summary.sql | 136 ++++++++++++++++++ 3 files changed, 139 insertions(+), 3 deletions(-) create mode 100644 etc/db/upgrades/upgrade15-v0.3.2-fix-project-summary.sql diff --git a/etc/db/database-version.sql b/etc/db/database-version.sql index d22e56f..43648c0 100644 --- a/etc/db/database-version.sql +++ b/etc/db/database-version.sql @@ -1,3 +1,3 @@ -INSERT INTO public.info VALUES ('version', '{"db_schema": "0.3.1"}') +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.1"}' WHERE public.info.key = 'version'; + SET value = public.info.value || '{"db_schema": "0.3.2"}' WHERE public.info.key = 'version'; diff --git a/etc/db/schema-template.sql b/etc/db/schema-template.sql index 33675c9..269560b 100644 --- a/etc/db/schema-template.sql +++ b/etc/db/schema-template.sql @@ -1531,7 +1531,7 @@ CREATE VIEW _SURVEY__TEMPLATE_.project_summary AS p.name, p.schema FROM public.projects p - WHERE (current_setting('search_path'::text) ~~ (p.schema || '%'::text)) + WHERE (split_part(current_setting('search_path'::text), ','::text, 1) = p.schema) ) SELECT project.pid, project.name, diff --git a/etc/db/upgrades/upgrade15-v0.3.2-fix-project-summary.sql b/etc/db/upgrades/upgrade15-v0.3.2-fix-project-summary.sql new file mode 100644 index 0000000..af633dd --- /dev/null +++ b/etc/db/upgrades/upgrade15-v0.3.2-fix-project-summary.sql @@ -0,0 +1,136 @@ +-- 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 <