From 49c51da1f230103651c308b3b37323baaf81494a Mon Sep 17 00:00:00 2001 From: alaskowski <alaskowski@ethz.ch> Date: Wed, 2 Aug 2023 15:47:18 +0200 Subject: [PATCH] SSDM-55: Fixed database 'column reference "id" is ambiguous' issue when creating sample attached to project --- .../sql/postgresql/193/function-193.sql | 8 ++-- .../migration/migration-192-193.sql | 39 +++++++++++++++++++ 2 files changed, 43 insertions(+), 4 deletions(-) diff --git a/server-application-server/source/sql/postgresql/193/function-193.sql b/server-application-server/source/sql/postgresql/193/function-193.sql index 329fe70b240..95bef6f2b76 100644 --- a/server-application-server/source/sql/postgresql/193/function-193.sql +++ b/server-application-server/source/sql/postgresql/193/function-193.sql @@ -3639,16 +3639,16 @@ DECLARE proj_code VARCHAR; identifier VARCHAR := '/'; BEGIN IF NEW.space_id IS NOT NULL THEN - SELECT code INTO STRICT space_code FROM spaces WHERE id = NEW.space_id; + SELECT code INTO STRICT space_code FROM spaces WHERE spaces.id = NEW.space_id; identifier := identifier || space_code || '/'; END IF; IF NEW.proj_id IS NOT NULL THEN IF NEW.space_id IS NOT NULL THEN - SELECT code INTO STRICT proj_code FROM projects WHERE id = NEW.proj_id; + SELECT code INTO STRICT proj_code FROM projects WHERE projects.id = NEW.proj_id; ELSE SELECT p.code, s.code INTO STRICT proj_code, space_code FROM projects p - INNER JOIN spaces s ON p.space_id = s.id WHERE id = NEW.proj_id; + INNER JOIN spaces s ON p.space_id = s.id WHERE p.id = NEW.proj_id; identifier := identifier || space_code || '/'; END IF; @@ -3656,7 +3656,7 @@ BEGIN END IF; IF NEW.samp_id_part_of IS NOT NULL THEN - SELECT code INTO STRICT container_code FROM samples_all WHERE id = NEW.samp_id_part_of; + SELECT code INTO STRICT container_code FROM samples_all WHERE samples_all.id = NEW.samp_id_part_of; identifier := identifier || container_code || ':' || NEW.code; ELSE identifier := identifier || NEW.code; diff --git a/server-application-server/source/sql/postgresql/migration/migration-192-193.sql b/server-application-server/source/sql/postgresql/migration/migration-192-193.sql index d5aae21f166..bd1f6d5d555 100644 --- a/server-application-server/source/sql/postgresql/migration/migration-192-193.sql +++ b/server-application-server/source/sql/postgresql/migration/migration-192-193.sql @@ -7,3 +7,42 @@ ALTER TABLE DATA_SET_PROPERTIES DROP CONSTRAINT DSPR_BK_UK; ALTER TABLE IF EXISTS PROPERTY_TYPES ADD COLUMN IS_MULTI_VALUE BOOLEAN_CHAR NOT NULL DEFAULT 'F'; + + +CREATE OR REPLACE FUNCTION samples_all_tsvector_document_trigger() RETURNS trigger AS $$ +DECLARE proj_code VARCHAR; + space_code VARCHAR; + container_code VARCHAR; + identifier VARCHAR := '/'; +BEGIN + IF NEW.space_id IS NOT NULL THEN + SELECT code INTO STRICT space_code FROM spaces WHERE spaces.id = NEW.space_id; + identifier := identifier || space_code || '/'; + END IF; + + IF NEW.proj_id IS NOT NULL THEN + IF NEW.space_id IS NOT NULL THEN + SELECT code INTO STRICT proj_code FROM projects WHERE projects.id = NEW.proj_id; + ELSE + SELECT p.code, s.code INTO STRICT proj_code, space_code FROM projects p + INNER JOIN spaces s ON p.space_id = s.id WHERE p.id = NEW.proj_id; + identifier := identifier || space_code || '/'; + END IF; + + identifier := identifier || proj_code || '/'; + END IF; + + IF NEW.samp_id_part_of IS NOT NULL THEN + SELECT code INTO STRICT container_code FROM samples_all WHERE samples_all.id = NEW.samp_id_part_of; + identifier := identifier || container_code || ':' || NEW.code; + ELSE + identifier := identifier || NEW.code; + END IF; + + NEW.sample_identifier := identifier; + NEW.tsvector_document := (escape_tsvector_string(NEW.perm_id) || ':1')::tsvector || + (escape_tsvector_string(NEW.code) || ':1')::tsvector || + (escape_tsvector_string(identifier) || ':1')::tsvector; + RETURN NEW; +END +$$ LANGUAGE plpgsql; \ No newline at end of file -- GitLab