-
Notifications
You must be signed in to change notification settings - Fork 10
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
- Loading branch information
Showing
3 changed files
with
95 additions
and
134 deletions.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
159 changes: 95 additions & 64 deletions
159
src/main/resources/changelog/changes/v4.0/sql/create-instance-trigger.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -1,91 +1,122 @@ | ||
CREATE FUNCTION coalesce_to_empty(value text) RETURNS text AS | ||
$$ | ||
BEGIN | ||
RETURN coalesce(value, ''); | ||
END | ||
$$ LANGUAGE plpgsql; | ||
|
||
CREATE FUNCTION prepare_for_expected_format(value text, length integer) RETURNS text AS | ||
$$ | ||
BEGIN | ||
RETURN substring(replace(coalesce_to_empty(value), '\', '\\') FROM 1 FOR length); | ||
END | ||
$$ LANGUAGE plpgsql; | ||
CREATE FUNCTION calculate_hash_id(elements text[]) RETURNS text AS | ||
$$ | ||
BEGIN | ||
RETURN encode(digest(array_to_string(elements, '|')::bytea, 'sha1'), 'hex'); | ||
END | ||
$$ LANGUAGE plpgsql; | ||
CREATE OR REPLACE FUNCTION instance_deps_trigger() | ||
RETURNS TRIGGER AS | ||
$$ | ||
DECLARE | ||
i jsonb; | ||
classification_id text; | ||
classification_number text; | ||
subject_id text; | ||
subject_value text; | ||
contributor_id text; | ||
contributor_name text; | ||
entry jsonb; | ||
classification_id text; | ||
classification_number text; | ||
classification_type_id text; | ||
subject_id text; | ||
subject_value text; | ||
subject_authority_id text; | ||
contributor_id text; | ||
contributor_name text; | ||
contributor_authority_id text; | ||
contributor_name_type_id text; | ||
BEGIN | ||
-- extract classifications | ||
-- process classifications | ||
DELETE | ||
FROM instance_classification | ||
WHERE instance_id = NEW.id; | ||
FOR i IN SELECT * FROM jsonb_array_elements(NEW.json -> 'classifications') | ||
LOOP | ||
classification_number := | ||
substring(replace(coalesce(i ->> 'classificationNumber', ''), '\', '\\') from 1 for 50); | ||
classification_id := encode(digest((concat_ws('|', | ||
classification_number, | ||
coalesce(i ->> 'classificationTypeId', '') | ||
))::bytea, 'sha1'), 'hex'); | ||
INSERT | ||
INTO classification(id, number, type_id) | ||
VALUES (classification_id, classification_number, i ->> 'classificationTypeId') | ||
ON CONFLICT (id) DO NOTHING; | ||
INSERT | ||
INTO instance_classification(instance_id, classification_id, tenant_id, shared) | ||
VALUES (NEW.id, classification_id, NEW.tenant_id, NEW.shared); | ||
END LOOP; | ||
-- extract subjects | ||
IF TG_OP <> 'DELETE' THEN | ||
FOR entry IN SELECT * FROM jsonb_array_elements(NEW.json -> 'classifications') | ||
LOOP | ||
classification_number := prepare_for_expected_format(entry ->> 'classificationNumber', 50); | ||
classification_type_id := entry ->> 'classificationTypeId'; | ||
classification_id := calculate_hash_id(ARRAY [classification_number, | ||
coalesce_to_empty(classification_type_id)]); | ||
INSERT | ||
INTO classification(id, number, type_id) | ||
VALUES (classification_id, classification_number, classification_type_id) | ||
ON CONFLICT (id) DO NOTHING; | ||
INSERT | ||
INTO instance_classification(instance_id, classification_id, tenant_id, shared) | ||
VALUES (NEW.id, classification_id, NEW.tenant_id, NEW.shared); | ||
END LOOP; | ||
END IF; | ||
-- process subjects | ||
DELETE | ||
FROM instance_subject | ||
WHERE instance_id = NEW.id; | ||
FOR i IN SELECT * FROM jsonb_array_elements(NEW.json -> 'subjects') | ||
LOOP | ||
subject_value := substring(replace(coalesce(i ->> 'value', ''), '\', '\\') from 1 for 255); | ||
subject_id := encode(digest((concat_ws('|', | ||
subject_value, | ||
coalesce(i ->> 'authorityId', '') | ||
))::bytea, 'sha1'), 'hex'); | ||
RAISE notice 'subject: % | instance: %', subject_value, NEW.id; | ||
INSERT | ||
INTO subject(id, value, authority_id) | ||
VALUES (subject_id, subject_value, i ->> 'authorityId') | ||
ON CONFLICT (id) DO NOTHING; | ||
INSERT | ||
INTO instance_subject(instance_id, subject_id, tenant_id, shared) | ||
VALUES (NEW.id, subject_id, NEW.tenant_id, NEW.shared); | ||
END LOOP; | ||
-- extract contributors | ||
IF TG_OP <> 'DELETE' THEN | ||
FOR entry IN SELECT * FROM jsonb_array_elements(NEW.json -> 'subjects') | ||
LOOP | ||
subject_value := prepare_for_expected_format(entry ->> 'value', 255); | ||
subject_authority_id := entry ->> 'authorityId'; | ||
subject_id := calculate_hash_id(ARRAY [subject_value, | ||
coalesce_to_empty(subject_authority_id)]); | ||
INSERT | ||
INTO subject(id, value, authority_id) | ||
VALUES (subject_id, subject_value, subject_authority_id) | ||
ON CONFLICT (id) DO NOTHING; | ||
INSERT | ||
INTO instance_subject(instance_id, subject_id, tenant_id, shared) | ||
VALUES (NEW.id, subject_id, NEW.tenant_id, NEW.shared); | ||
END LOOP; | ||
END IF; | ||
-- process contributors | ||
DELETE | ||
FROM instance_contributor | ||
WHERE instance_id = NEW.id; | ||
FOR i IN SELECT * FROM jsonb_array_elements(NEW.json -> 'contributors') | ||
LOOP | ||
contributor_name := substring(replace(coalesce(i ->> 'name', ''), '\', '\\') from 1 for 255); | ||
contributor_id := encode(digest((concat_ws('|', | ||
contributor_name, | ||
coalesce(i ->> 'contributorNameTypeId', ''), | ||
coalesce(i ->> 'authorityId', '') | ||
))::bytea, 'sha1'), 'hex'); | ||
INSERT | ||
INTO contributor(id, name, name_type_id, authority_id) | ||
VALUES (contributor_id, contributor_name, i ->> 'contributorNameTypeId', i ->> 'authorityId') | ||
ON CONFLICT (id) DO NOTHING; | ||
INSERT | ||
INTO instance_contributor(instance_id, contributor_id, type_id, tenant_id, shared) | ||
VALUES (NEW.id, contributor_id, coalesce(i ->> 'contributorTypeId', ''), NEW.tenant_id, NEW.shared); | ||
END LOOP; | ||
IF TG_OP <> 'DELETE' THEN | ||
FOR entry IN SELECT * FROM jsonb_array_elements(NEW.json -> 'contributors') | ||
LOOP | ||
contributor_name := prepare_for_expected_format(entry ->> 'name', 255); | ||
contributor_name_type_id := entry ->> 'contributorNameTypeId'; | ||
contributor_authority_id := entry ->> 'authorityId'; | ||
contributor_id := calculate_hash_id(ARRAY [contributor_name, | ||
coalesce_to_empty(contributor_name_type_id), | ||
coalesce_to_empty(contributor_authority_id)]); | ||
INSERT | ||
INTO contributor(id, name, name_type_id, authority_id) | ||
VALUES (contributor_id, contributor_name, contributor_name_type_id, contributor_authority_id) | ||
ON CONFLICT (id) DO NOTHING; | ||
INSERT | ||
INTO instance_contributor(instance_id, contributor_id, type_id, tenant_id, shared) | ||
VALUES (NEW.id, contributor_id, coalesce_to_empty(entry ->> 'contributorTypeId'), | ||
NEW.tenant_id, NEW.shared); | ||
END LOOP; | ||
END IF; | ||
RETURN NEW; | ||
END; | ||
$$ LANGUAGE plpgsql; | ||
DROP TRIGGER IF EXISTS instance_trigger ON instance CASCADE; | ||
CREATE TRIGGER instance_trigger | ||
AFTER INSERT OR UPDATE | ||
AFTER INSERT OR UPDATE OR DELETE | ||
ON instance | ||
FOR EACH ROW | ||
EXECUTE FUNCTION instance_deps_trigger(); |
58 changes: 0 additions & 58 deletions
58
src/main/resources/changelog/changes/v4.0/sql/delete-instance-trigger.sql
This file was deleted.
Oops, something went wrong.