fix 2.8 migration issue (#18389)

The sql must be idempotent

Signed-off-by: Wang Yan <wangyan@vmware.com>
This commit is contained in:
Wang Yan 2023-03-22 16:12:36 +08:00 committed by GitHub
parent 6590fe8eef
commit c1d297b015
No known key found for this signature in database
GPG Key ID: 4AEE18F83AFDEB23

View File

@ -2,7 +2,7 @@
delete from artifact_blob afb where not exists (select digest from blob b where b.digest = afb.digest_af); delete from artifact_blob afb where not exists (select digest from blob b where b.digest = afb.digest_af);
/* add subject_artifact_digest*/ /* add subject_artifact_digest*/
alter table artifact_accessory add column subject_artifact_digest varchar(1024); alter table artifact_accessory add column IF NOT EXISTS subject_artifact_digest varchar(1024);
DO $$ DO $$
DECLARE DECLARE
@ -16,9 +16,19 @@ BEGIN
END LOOP; END LOOP;
END $$; END $$;
alter table artifact_accessory drop CONSTRAINT artifact_accessory_subject_artifact_id_fkey; alter table artifact_accessory drop CONSTRAINT IF EXISTS artifact_accessory_subject_artifact_id_fkey;
alter table artifact_accessory drop CONSTRAINT unique_artifact_accessory; alter table artifact_accessory drop CONSTRAINT IF EXISTS unique_artifact_accessory;
alter table artifact_accessory add CONSTRAINT unique_artifact_accessory UNIQUE (artifact_id, subject_artifact_digest);
DO $$
BEGIN
IF NOT EXISTS (SELECT 1
FROM pg_constraint
WHERE conname = 'unique_artifact_accessory')
THEN
ALTER TABLE artifact_accessory
ADD CONSTRAINT unique_artifact_accessory UNIQUE (artifact_id, subject_artifact_digest);
END IF;
END $$;
/* Update the registry and replication policy associated with the chartmuseum */ /* Update the registry and replication policy associated with the chartmuseum */
UPDATE registry UPDATE registry
@ -90,42 +100,45 @@ DECLARE
status_code integer; status_code integer;
exec_id integer; exec_id integer;
extra_attrs json; extra_attrs json;
BEGIN BEGIN
FOR job_group IN SELECT DISTINCT policy_id,event_type FROM notification_job WHERE event_type NOT IN ('UPLOAD_CHART', 'DOWNLOAD_CHART', 'DELETE_CHART') if exists (select 1 from information_schema.tables where table_name = 'notification_job') then
LOOP FOR job_group IN SELECT DISTINCT policy_id,event_type FROM notification_job WHERE event_type NOT IN ('UPLOAD_CHART', 'DOWNLOAD_CHART', 'DELETE_CHART')
SELECT * INTO job FROM notification_job WHERE LOOP
policy_id=job_group.policy_id SELECT * INTO job FROM notification_job WHERE
AND event_type=job_group.event_type policy_id=job_group.policy_id
AND status IN ('stopped', 'finished', 'error') AND event_type=job_group.event_type
ORDER BY creation_time DESC LIMIT 1; AND status IN ('stopped', 'finished', 'error')
/* convert vendor type */ ORDER BY creation_time DESC LIMIT 1;
IF job.notify_type = 'http' THEN /* convert vendor type */
vendor_type = 'WEBHOOK'; IF job.notify_type = 'http' THEN
ELSIF job.notify_type = 'slack' THEN vendor_type = 'WEBHOOK';
vendor_type = 'SLACK'; ELSIF job.notify_type = 'slack' THEN
ELSE vendor_type = 'SLACK';
vendor_type = 'WEBHOOK'; ELSE
END IF; vendor_type = 'WEBHOOK';
/* convert status */ END IF;
IF job.status = 'stopped' THEN /* convert status */
new_status = 'Stopped'; IF job.status = 'stopped' THEN
status_code = 3; new_status = 'Stopped';
ELSIF job.status = 'error' THEN status_code = 3;
new_status = 'Error'; ELSIF job.status = 'error' THEN
status_code = 3; new_status = 'Error';
ELSIF job.status = 'finished' THEN status_code = 3;
new_status = 'Success'; ELSIF job.status = 'finished' THEN
status_code = 3; new_status = 'Success';
ELSE status_code = 3;
new_status = ''; ELSE
status_code = 0; new_status = '';
END IF; status_code = 0;
END IF;
SELECT format('{"event_type": "%s", "payload": %s}', job.event_type, to_json(job.job_detail)::TEXT)::JSON INTO extra_attrs; SELECT format('{"event_type": "%s", "payload": %s}', job.event_type, to_json(job.job_detail)::TEXT)::JSON INTO extra_attrs;
INSERT INTO execution (vendor_type,vendor_id,status,trigger,extra_attrs,start_time,end_time,update_time) VALUES (vendor_type,job.policy_id,new_status,'EVENT',extra_attrs,job.creation_time,job.update_time,job.update_time) RETURNING id INTO exec_id; INSERT INTO execution (vendor_type,vendor_id,status,trigger,extra_attrs,start_time,end_time,update_time) VALUES (vendor_type,job.policy_id,new_status,'EVENT',extra_attrs,job.creation_time,job.update_time,job.update_time) RETURNING id INTO exec_id;
INSERT INTO task (execution_id,job_id,status,status_code,run_count,creation_time,start_time,update_time,end_time,vendor_type) VALUES (exec_id,job.job_uuid,new_status,status_code,1,job.creation_time,job.update_time,job.update_time,job.update_time,vendor_type); INSERT INTO task (execution_id,job_id,status,status_code,run_count,creation_time,start_time,update_time,end_time,vendor_type) VALUES (exec_id,job.job_uuid,new_status,status_code,1,job.creation_time,job.update_time,job.update_time,job.update_time,vendor_type);
END LOOP; END LOOP;
END IF;
END $$; END $$;
/* drop the old notification_job table */ /* drop the old notification_job table */
DROP TABLE IF EXISTS notification_job; DROP TABLE IF EXISTS notification_job;