diff --git a/database/migrations/sqls/20240606151842-pgwar-project-entity-labels-up.sql b/database/migrations/sqls/20240606151842-pgwar-project-entity-labels-up.sql index a196cc601..811160183 100644 --- a/database/migrations/sqls/20240606151842-pgwar-project-entity-labels-up.sql +++ b/database/migrations/sqls/20240606151842-pgwar-project-entity-labels-up.sql @@ -182,6 +182,7 @@ BEGIN SET entity_label = new_label WHERE pk_entity = entity_id AND fk_project = project_id + AND fk_project != 0 AND entity_label IS DISTINCT FROM new_label; END; $$ LANGUAGE plpgsql; diff --git a/database/migrations/sqls/20240617151644-pgwar-community-entity-labels-up.sql b/database/migrations/sqls/20240617151644-pgwar-community-entity-labels-up.sql index 75696f7f3..c86b935ed 100644 --- a/database/migrations/sqls/20240617151644-pgwar-community-entity-labels-up.sql +++ b/database/migrations/sqls/20240617151644-pgwar-community-entity-labels-up.sql @@ -19,18 +19,129 @@ BEGIN END; $$ LANGUAGE plpgsql; +-- Function to upsert on pgwar.entity_preview +----------------------------------------------------------------------------- +CREATE OR REPLACE FUNCTION pgwar.upsert_community_entity_preview(ep pgwar.entity_preview) + RETURNS VOID +AS $$ +BEGIN + INSERT INTO pgwar.entity_preview( + pk_entity, + fk_project, + fk_class, + entity_type, + class_label, + entity_label, + full_text, + ts_vector, + type_label, + fk_type, + time_span, + first_second, + last_second + ) + VALUES( + ep.pk_entity, + 0, + ep.fk_class, + ep.entity_type, + ep.class_label, + ep.entity_label, + ep.full_text, + ep.ts_vector, + ep.type_label, + ep.fk_type, + ep.time_span, + ep.first_second, + ep.last_second + ) + ON CONFLICT(pk_entity, fk_project) + DO UPDATE SET + -- ... or update the pgwar.entity_preview + fk_class = EXCLUDED.fk_class, + entity_type = EXCLUDED.entity_type, + class_label = EXCLUDED.class_label, + entity_label = EXCLUDED.entity_label, + full_text = EXCLUDED.full_text, + ts_vector = EXCLUDED.ts_vector, + type_label = EXCLUDED.type_label, + fk_type = EXCLUDED.fk_type, + time_span = EXCLUDED.time_span, + first_second = EXCLUDED.first_second, + last_second = EXCLUDED.last_second + WHERE + -- ... where it is distinct from previous value + entity_preview.fk_class IS DISTINCT FROM EXCLUDED.fk_class OR + entity_preview.entity_type IS DISTINCT FROM EXCLUDED.entity_type OR + entity_preview.class_label IS DISTINCT FROM EXCLUDED.class_label OR + entity_preview.entity_label IS DISTINCT FROM EXCLUDED.entity_label OR + entity_preview.full_text IS DISTINCT FROM EXCLUDED.full_text OR + entity_preview.ts_vector IS DISTINCT FROM EXCLUDED.ts_vector OR + entity_preview.type_label IS DISTINCT FROM EXCLUDED.type_label OR + entity_preview.fk_type IS DISTINCT FROM EXCLUDED.fk_type OR + entity_preview.time_span IS DISTINCT FROM EXCLUDED.time_span OR + entity_preview.first_second IS DISTINCT FROM EXCLUDED.first_second OR + entity_preview.last_second IS DISTINCT FROM EXCLUDED.last_second; +END; +$$ +LANGUAGE plpgsql; -- Update community entity labels on change on projects entity labels --- CREATE OR REPLACE FUNCTION pgwar.update_community_entity_label_on_project_entity_label_change() --- RETURNS TRIGGER AS $$ --- BEGIN --- --- --- RETURN NULL; --- END; --- $$ LANGUAGE plpgsql; --- --- CREATE TRIGGER on_modify_project_entity_preview --- AFTER INSERT OR UPDATE ON pgwar.entity_preview --- FOR EACH ROW --- EXECUTE FUNCTION pgwar.update_community_entity_label_on_project_entity_label_change(); \ No newline at end of file +CREATE OR REPLACE FUNCTION pgwar.update_community_entity_label_on_project_entity_label_change() + RETURNS TRIGGER AS $$ +DECLARE + label text; +BEGIN + IF NEW.fk_project != 0 THEN + SELECT pgwar.get_most_frequent_entity_label(NEW.pk_entity) INTO label; + IF tg_op = 'UPDATE' AND OLD.entity_label != NEW.entity_label THEN + PERFORM + pgwar.upsert_community_entity_preview(( + NEW.pk_entity, + 0, + NEW.fk_class, + NEW.entity_type, + NEW.class_label, + label, + NEW.full_text, + NEW.ts_vector, + NEW.type_label, + NEW.fk_type, + NEW.time_span, + NEW.first_second, + NEW.last_second, + NEW.tmsp_last_modification)::pgwar.entity_preview + ); + ELSEIF tg_op = 'INSERT' THEN + PERFORM + pgwar.upsert_community_entity_preview(( + NEW.pk_entity, + 0, + NEW.fk_class, + NEW.entity_type, + NEW.class_label, + label, + NEW.full_text, + NEW.ts_vector, + NEW.type_label, + NEW.fk_type, + NEW.time_span, + NEW.first_second, + NEW.last_second, + NEW.tmsp_last_modification)::pgwar.entity_preview + ); + ELSE + UPDATE pgwar.entity_preview + SET entity_label = label + WHERE fk_project = 0 AND pk_entity = OLD.pk_entity; + END IF; + END IF; + + RETURN NULL; +END; +$$ LANGUAGE plpgsql; + +CREATE TRIGGER on_modify_project_entity_preview + AFTER INSERT OR UPDATE OR DELETE ON pgwar.entity_preview + FOR EACH ROW +EXECUTE FUNCTION pgwar.update_community_entity_label_on_project_entity_label_change(); \ No newline at end of file diff --git a/database/test/integration/pgwar-community-entity-label/test-pgwar-community-entity-label.sql b/database/test/integration/pgwar-community-entity-label/test-pgwar-community-entity-label.sql new file mode 100644 index 000000000..dcd40ad93 --- /dev/null +++ b/database/test/integration/pgwar-community-entity-label/test-pgwar-community-entity-label.sql @@ -0,0 +1,370 @@ +-- Test the creation of project entity label +-- Start transaction and plan the tests. +BEGIN; + +SELECT plan(3); + +-- Create and switch to a sink table for entity previews +SELECT war.create_sink_table_entity_preview('war.e'); + +SELECT war.switch_entity_preview_table('war.e'); + +INSERT INTO projects.project (pk_entity) +VALUES (1), + (2), + (3), + (4), + (5), + (6), + (7); + +INSERT INTO projects.entity_label_config (fk_project, fk_class, config) +VALUES ( + 1, + 77, + '{ + "labelParts": [ + { + "field": {"isOutgoing": false, "fkProperty": 22, "nrOfStatementsInLabel": 5} + }, + { + "field": {"isOutgoing": true, "fkProperty": 55, "nrOfStatementsInLabel": 5} + } + ] + }'::jsonb + ); + +INSERT INTO projects.entity_label_config (fk_project, fk_class, config) +VALUES ( + 2, + 77, + '{ + "labelParts": [ + { + "field": {"isOutgoing": false, "fkProperty": 22, "nrOfStatementsInLabel": 5} + }, + { + "field": {"isOutgoing": true, "fkProperty": 55, "nrOfStatementsInLabel": 5} + } + ] + }'::jsonb + ); + +INSERT INTO projects.entity_label_config (fk_project, fk_class, config) +VALUES ( + 3, + 77, + '{ + "labelParts": [ + { + "field": {"isOutgoing": false, "fkProperty": 22, "nrOfStatementsInLabel": 5} + }, + { + "field": {"isOutgoing": true, "fkProperty": 55, "nrOfStatementsInLabel": 5} + } + ] + }'::jsonb + ); + +INSERT INTO projects.entity_label_config (fk_project, fk_class, config) +VALUES ( + 4, + 77, + '{ + "labelParts": [ + { + "field": {"isOutgoing": false, "fkProperty": 22, "nrOfStatementsInLabel": 5} + }, + { + "field": {"isOutgoing": true, "fkProperty": 55, "nrOfStatementsInLabel": 5} + } + ] + }'::jsonb + ); + +INSERT INTO projects.entity_label_config (fk_project, fk_class, config) +VALUES ( + 5, + 77, + '{ + "labelParts": [ + { + "field": {"isOutgoing": false, "fkProperty": 22, "nrOfStatementsInLabel": 5} + }, + { + "field": {"isOutgoing": true, "fkProperty": 55, "nrOfStatementsInLabel": 5} + } + ] + }'::jsonb + ); + +INSERT INTO projects.entity_label_config (fk_project, fk_class, config) +VALUES ( + 6, + 77, + '{ + "labelParts": [ + { + "field": {"isOutgoing": false, "fkProperty": 22, "nrOfStatementsInLabel": 5} + }, + { + "field": {"isOutgoing": true, "fkProperty": 55, "nrOfStatementsInLabel": 5} + } + ] + }'::jsonb + ); + +INSERT INTO projects.entity_label_config (fk_project, fk_class, config) +VALUES ( + 7, + 77, + '{ + "labelParts": [ + { + "field": {"isOutgoing": false, "fkProperty": 22, "nrOfStatementsInLabel": 5} + }, + { + "field": {"isOutgoing": true, "fkProperty": 55, "nrOfStatementsInLabel": 5} + } + ] + }'::jsonb + ); + +-- Add entity 1 +INSERT INTO information.resource (fk_class, notes) +VALUES (77, '_1') RETURNING pk_entity; + +INSERT INTO projects.info_proj_rel (fk_entity, fk_project, is_in_project) +SELECT pk_entity, + 1, + true +FROM information.resource +WHERE notes = '_1'; + +INSERT INTO projects.info_proj_rel (fk_entity, fk_project, is_in_project) +SELECT pk_entity, + 2, + true +FROM information.resource +WHERE notes = '_1'; + +INSERT INTO projects.info_proj_rel (fk_entity, fk_project, is_in_project) +SELECT pk_entity, + 3, + true +FROM information.resource +WHERE notes = '_1'; + +INSERT INTO projects.info_proj_rel (fk_entity, fk_project, is_in_project) +SELECT pk_entity, + 4, + true +FROM information.resource +WHERE notes = '_1'; + +INSERT INTO projects.info_proj_rel (fk_entity, fk_project, is_in_project) +SELECT pk_entity, + 5, + true +FROM information.resource +WHERE notes = '_1'; + +INSERT INTO projects.info_proj_rel (fk_entity, fk_project, is_in_project) +SELECT pk_entity, + 6, + true +FROM information.resource +WHERE notes = '_1'; + +-- Add entity 1 to other projects +INSERT INTO projects.info_proj_rel (fk_entity, fk_project, is_in_project) +SELECT pk_entity, + 7, + true +FROM information.resource +WHERE notes = '_1'; + + +-- Insert project statement with entity one as subject and a literal object_label +INSERT INTO pgwar.project_statements +( + pk_entity, + fk_project, + fk_subject_info, + fk_property, + fk_object_info, + object_label +) +SELECT 1, + 1, + pk_entity, + 55, + 66, + 'Label 1' +FROM information.resource +WHERE notes = '_1'; + +-- Insert project statement with entity one as subject and a literal object_label +INSERT INTO pgwar.project_statements +( + pk_entity, + fk_project, + fk_subject_info, + fk_property, + fk_object_info, + object_label +) +SELECT 1, + 2, + pk_entity, + 55, + 66, + 'Label 1bis' +FROM information.resource +WHERE notes = '_1'; + +-- Insert project statement with entity one as subject and a literal object_label +INSERT INTO pgwar.project_statements +( + pk_entity, + fk_project, + fk_subject_info, + fk_property, + fk_object_info, + object_label +) +SELECT 1, + 3, + pk_entity, + 55, + 66, + 'Label 1' +FROM information.resource +WHERE notes = '_1'; + +-- Insert project statement with entity one as subject and a literal object_label +INSERT INTO pgwar.project_statements +( + pk_entity, + fk_project, + fk_subject_info, + fk_property, + fk_object_info, + object_label +) +SELECT 1, + 4, + pk_entity, + 55, + 66, + 'Label 1bis' +FROM information.resource +WHERE notes = '_1'; + +-- Insert project statement with entity one as subject and a literal object_label +INSERT INTO pgwar.project_statements +( + pk_entity, + fk_project, + fk_subject_info, + fk_property, + fk_object_info, + object_label +) +SELECT 1, + 5, + pk_entity, + 55, + 66, + 'Label 1' +FROM information.resource +WHERE notes = '_1'; + +-- Insert project statement with entity one as subject and a literal object_label +INSERT INTO pgwar.project_statements +( + pk_entity, + fk_project, + fk_subject_info, + fk_property, + fk_object_info, + object_label +) +SELECT 1, + 6, + pk_entity, + 55, + 66, + 'Label 1bis' +FROM information.resource +WHERE notes = '_1'; + +-- Insert project statement with entity one as subject and a literal object_label +INSERT INTO pgwar.project_statements +( + pk_entity, + fk_project, + fk_subject_info, + fk_property, + fk_object_info, + object_label +) +SELECT 1, + 7, + pk_entity, + 55, + 66, + 'Label 1bis' +FROM information.resource +WHERE notes = '_1'; + +-- Test 1: assert that entity 1 has "Label 1bis" as community entity label +SELECT is( + ep.entity_label, + 'Label 1bis', + 'Assert community entity preview has Label 1bis' +) +FROM pgwar.entity_preview ep, + information.resource r +WHERE ep.pk_entity = r.pk_entity + AND r.notes = '_1' + AND ep.fk_project = 0; + +-- Update 4 entity labels +UPDATE pgwar.entity_preview +SET entity_label = 'Label 1ter' +WHERE fk_project > 3; + +-- Test 2: assert that entity 1 has "Label 1ter" as community entity label +SELECT is( + ep.entity_label, + 'Label 1ter', + 'Assert community entity preview has Label 1ter' +) +FROM pgwar.entity_preview ep, + information.resource r +WHERE ep.pk_entity = r.pk_entity + AND r.notes = '_1' + AND ep.fk_project = 0; + +-- Delete 6 entity previews +DELETE FROM pgwar.entity_preview +WHERE fk_project > 1; + +-- Test 3: assert that entity 1 has "Label 1" as community entity label +SELECT is( + ep.entity_label, + 'Label 1', + 'Assert community entity preview has Label 1' +) +FROM pgwar.entity_preview ep, + information.resource r +WHERE ep.pk_entity = r.pk_entity + AND r.notes = '_1' + AND ep.fk_project = 0; + +-- Finish the tests and clean up. +SELECT * +FROM finish(); + +ROLLBACK; \ No newline at end of file