[sql] Make PostgreSQL schema scripts search_path-agnostic

This commit is contained in:
Sergey Konovalov
2025-08-25 14:13:53 +03:00
parent 8ee59496c6
commit 8dff329455
3 changed files with 12 additions and 11 deletions

View File

@ -7,7 +7,7 @@
-- ----------------------------
-- Table structure for doc_changes
-- ----------------------------
CREATE TABLE IF NOT EXISTS "public"."doc_changes" (
CREATE TABLE IF NOT EXISTS "doc_changes" (
"tenant" varchar(255) COLLATE "default" NOT NULL,
"id" varchar(255) COLLATE "default" NOT NULL,
"change_id" int4 NOT NULL,
@ -23,7 +23,7 @@ WITH (OIDS=FALSE);
-- ----------------------------
-- Table structure for task_result
-- ----------------------------
CREATE TABLE IF NOT EXISTS "public"."task_result" (
CREATE TABLE IF NOT EXISTS "task_result" (
"tenant" varchar(255) COLLATE "default" NOT NULL,
"id" varchar(255) COLLATE "default" NOT NULL,
"status" int2 NOT NULL,
@ -43,15 +43,15 @@ WITH (OIDS=FALSE);
CREATE OR REPLACE FUNCTION merge_db(_tenant varchar(255), _id varchar(255), _status int2, _status_info int4, _last_open_date timestamp without time zone, _user_index int4, _change_id int4, _callback text, _baseurl text, OUT isupdate char(5), OUT userindex int4) AS
$$
DECLARE
t_var "public"."task_result"."user_index"%TYPE;
t_var "task_result"."user_index"%TYPE;
BEGIN
LOOP
-- first try to update the key
-- note that "a" must be unique
IF ((_callback <> '') IS TRUE) AND ((_baseurl <> '') IS TRUE) THEN
UPDATE "public"."task_result" SET last_open_date=_last_open_date, user_index=user_index+1,callback=_callback,baseurl=_baseurl WHERE tenant = _tenant AND id = _id RETURNING user_index into userindex;
UPDATE "task_result" SET last_open_date=_last_open_date, user_index=user_index+1,callback=_callback,baseurl=_baseurl WHERE tenant = _tenant AND id = _id RETURNING user_index into userindex;
ELSE
UPDATE "public"."task_result" SET last_open_date=_last_open_date, user_index=user_index+1 WHERE tenant = _tenant AND id = _id RETURNING user_index into userindex;
UPDATE "task_result" SET last_open_date=_last_open_date, user_index=user_index+1 WHERE tenant = _tenant AND id = _id RETURNING user_index into userindex;
END IF;
IF found THEN
isupdate := 'true';
@ -61,7 +61,7 @@ BEGIN
-- if someone else inserts the same key concurrently,
-- we could get a unique-key failure
BEGIN
INSERT INTO "public"."task_result"(tenant, id, status, status_info, last_open_date, user_index, change_id, callback, baseurl) VALUES(_tenant, _id, _status, _status_info, _last_open_date, _user_index, _change_id, _callback, _baseurl) RETURNING user_index into userindex;
INSERT INTO "task_result"(tenant, id, status, status_info, last_open_date, user_index, change_id, callback, baseurl) VALUES(_tenant, _id, _status, _status_info, _last_open_date, _user_index, _change_id, _callback, _baseurl) RETURNING user_index into userindex;
isupdate := 'false';
RETURN;
EXCEPTION WHEN unique_violation THEN

View File

@ -2,9 +2,9 @@ SET client_min_messages = WARNING;
--
-- Drop tables
--
DROP TABLE IF EXISTS "public"."doc_callbacks";
DROP TABLE IF EXISTS "public"."doc_changes";
DROP TABLE IF EXISTS "public"."task_result";
DROP TABLE IF EXISTS "doc_callbacks";
DROP TABLE IF EXISTS "doc_changes";
DROP TABLE IF EXISTS "task_result";
--https://www.postgresql.org/docs/current/static/plpgsql-control-structures.html#PLPGSQL-UPSERT-EXAMPLE
DROP FUNCTION IF EXISTS merge_db(_id varchar(255), _status int2, _status_info int8, _last_open_date timestamp without time zone, _title varchar(255), _user_index int8, _change_id int8, OUT isupdate char(5), OUT userindex int8) CASCADE;