From 5722176b69d8c020b15eb268818ade43ea3bf7fc Mon Sep 17 00:00:00 2001 From: Lam Voong Date: Fri, 11 Dec 2020 11:26:54 -0800 Subject: [PATCH 1/2] New Repatriation/NAGPRA Compliance report --- .../pahma/pahmaRepatriationNAGPRA.jrxml | 207 ++++++++++++++++++ .../payloads/pahmaRepatriationNAGPRA.xml | 17 ++ 2 files changed, 224 insertions(+) create mode 100644 services/report/3rdparty/jasper-cs-report/src/main/resources/tenants/pahma/pahmaRepatriationNAGPRA.jrxml create mode 100644 services/report/3rdparty/jasper-cs-report/src/main/resources/tenants/pahma/payloads/pahmaRepatriationNAGPRA.xml diff --git a/services/report/3rdparty/jasper-cs-report/src/main/resources/tenants/pahma/pahmaRepatriationNAGPRA.jrxml b/services/report/3rdparty/jasper-cs-report/src/main/resources/tenants/pahma/pahmaRepatriationNAGPRA.jrxml new file mode 100644 index 0000000000..6a2a15698c --- /dev/null +++ b/services/report/3rdparty/jasper-cs-report/src/main/resources/tenants/pahma/pahmaRepatriationNAGPRA.jrxml @@ -0,0 +1,207 @@ + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + diff --git a/services/report/3rdparty/jasper-cs-report/src/main/resources/tenants/pahma/payloads/pahmaRepatriationNAGPRA.xml b/services/report/3rdparty/jasper-cs-report/src/main/resources/tenants/pahma/payloads/pahmaRepatriationNAGPRA.xml new file mode 100644 index 0000000000..5a87186290 --- /dev/null +++ b/services/report/3rdparty/jasper-cs-report/src/main/resources/tenants/pahma/payloads/pahmaRepatriationNAGPRA.xml @@ -0,0 +1,17 @@ + + + + Repatriation and NAGPRA Compliance + pahmaRepatriationNAGPRA.jasper + + Group + CollectionObject + + true + true + true + false + false + text/csv + + From 221f6ec42bed14c14df82a3d65ce7c63cc1fcf4a Mon Sep 17 00:00:00 2001 From: Lam Voong Date: Thu, 28 Jan 2021 11:32:58 -0800 Subject: [PATCH 2/2] CC-1492: add new functions for Repatriation and NAGPRA Compliance report --- .../function_pahma_aggRepDateField.sql | 49 ++++++++++++++++ .../postgresql/function_pahma_aggRepField.sql | 40 +++++++++++++ .../function_pahma_aggRepGroupField.sql | 56 +++++++++++++++++++ 3 files changed, 145 insertions(+) create mode 100644 services/common/src/main/resources/db/postgresql/function_pahma_aggRepDateField.sql create mode 100644 services/common/src/main/resources/db/postgresql/function_pahma_aggRepField.sql create mode 100644 services/common/src/main/resources/db/postgresql/function_pahma_aggRepGroupField.sql diff --git a/services/common/src/main/resources/db/postgresql/function_pahma_aggRepDateField.sql b/services/common/src/main/resources/db/postgresql/function_pahma_aggRepDateField.sql new file mode 100644 index 0000000000..90e0d84684 --- /dev/null +++ b/services/common/src/main/resources/db/postgresql/function_pahma_aggRepDateField.sql @@ -0,0 +1,49 @@ +/* utils.aggRepDateField(coid varchar, tname varchar, cname varchar, sepval varchar) + * -- aggregates values of a repeating date field + * -- requires: + * -- coid = collectionobjects_common.id of the parent Collection Object + * -- tname = table name of the repeating group + * -- cname = column name of the date field in structuredDateGroup + * -- sepval = separator/delimiter character + */ + +CREATE SCHEMA IF NOT EXISTS utils AUTHORIZATION nuxeo_pahma; + +-- DROP FUNCTION utils.aggRepDateField(coid varchar, tname varchar, cname varchar, sep varchar); + +CREATE OR REPLACE FUNCTION utils.aggRepDateField( + coid VARCHAR, + tname VARCHAR, + cname VARCHAR, + sepval VARCHAR) +RETURNS VARCHAR +AS $$ +DECLARE + ctype VARCHAR; + cstr VARCHAR := cname::text; + aggstr VARCHAR; +BEGIN + + EXECUTE 'SELECT STRING_AGG(CASE WHEN s.' || cname || ' IS NULL THEN ''%NULLVALUE%''' + || ' ELSE s.' || cstr || ' END, ''' || sepval || ''' ORDER BY h.pos)' + || ' FROM hierarchy h' + || ' JOIN ' || tname || ' n ON (h.id = n.id)' + || ' JOIN hierarchy hn on (n.id = hn.parentid AND hn.primarytype = ''structuredDateGroup'')' + || ' JOIN structureddategroup s ON (hn.id = s.id)' + || ' WHERE h.parentid = $2' + || ' GROUP BY h.parentid' + INTO aggstr + USING tname, coid; + + RETURN aggstr; + +END; +$$ +LANGUAGE plpgsql; + +GRANT EXECUTE ON FUNCTION utils.aggRepDateField(coid varchar, tname varchar, cname varchar, sepval varchar) to reporters_pahma; + +-- SELECT proacl FROM pg_proc WHERE proname = 'aggrepdatefield'; + +-- SELECT utils.aggRepDateField('2dbcbf18-4966-4178-9880-e81258568921', 'nagprareportfiledgroup', 'datedisplaydate', '|'); + diff --git a/services/common/src/main/resources/db/postgresql/function_pahma_aggRepField.sql b/services/common/src/main/resources/db/postgresql/function_pahma_aggRepField.sql new file mode 100644 index 0000000000..b8ef6fe0ec --- /dev/null +++ b/services/common/src/main/resources/db/postgresql/function_pahma_aggRepField.sql @@ -0,0 +1,40 @@ +/* aggRepField(coid varchar, tname varchar, sepval varchar) + * -- aggregates values of a repeating field + * -- requires: + * -- coid = collectionobjects_common.id of the parent Collection Object + * -- tname = table name of the repeating field + * -- sepval = separator/delimiter character + */ + +CREATE SCHEMA IF NOT EXISTS utils AUTHORIZATION nuxeo_pahma; + +-- DROP FUNCTION utils.aggRepField(coid varchar, tname varchar, sepval varchar); + +CREATE OR REPLACE FUNCTION utils.aggRepField( + coid VARCHAR, + tname VARCHAR, + sepval VARCHAR) +RETURNS VARCHAR +AS $$ +DECLARE + aggstr VARCHAr; +BEGIN + EXECUTE 'SELECT STRING_AGG(CASE WHEN item IS NULL THEN ''%NULLVALUE%''' + || ' ELSE regexp_replace(item, E''[\\n\\r]+'', ''\n'', ''g'') END, ''' || sepval || ''' ORDER BY pos)' + || ' FROM ' || tname + || ' WHERE id = $1' + || ' GROUP BY id' + INTO aggstr + USING coid; + + RETURN aggstr; +END; +$$ +LANGUAGE plpgsql; + +GRANT EXECUTE ON FUNCTION utils.aggRepField(coid varchar, tname varchar, sepval varchar) to reporters_pahma; + +-- SELECT proacl FROM pg_proc WHERE proname = 'aggrepfield'; + +-- SELECT aggRepField('2dbcbf18-4966-4178-9880-e81258568921', 'collectionobjects_nagpra_nagpracategories', '|'); + diff --git a/services/common/src/main/resources/db/postgresql/function_pahma_aggRepGroupField.sql b/services/common/src/main/resources/db/postgresql/function_pahma_aggRepGroupField.sql new file mode 100644 index 0000000000..c6cf4b3cff --- /dev/null +++ b/services/common/src/main/resources/db/postgresql/function_pahma_aggRepGroupField.sql @@ -0,0 +1,56 @@ +/* utils.aggRepGroupField(coid varchar, tname varchar, cname varchar, sepval varchar) + * -- aggregates values of a repeating group of fields + * -- requires: + * -- coid = collectionobjects_common.id of the parent Collection Object + * -- tname = table name of the repeating group + * -- cname = column name of the repeating group field + * -- sepval = separator/delimiter character + */ + +CREATE SCHEMA IF NOT EXISTS utils AUTHORIZATION nuxeo_pahma; + +-- DROP FUNCTION utils.aggRepGroupField(coid varchar, tname varchar, cname varchar, sepval varchar); + +CREATE OR REPLACE FUNCTION utils.aggRepGroupField( + coid VARCHAR, + tname VARCHAR, + cname VARCHAR, + sepval VARCHAR) +RETURNS VARCHAR +AS $$ +DECLARE + ctype VARCHAR; + cstr VARCHAR; + aggstr VARCHAR; +BEGIN + SELECT data_type INTO ctype FROM information_schema.columns WHERE table_name = tname AND column_name = cname; + + IF ctype IN ('text', 'character varying') THEN + cstr := cname; + ELSE + cstr := cname || '::text'; + END IF; + + EXECUTE 'SELECT STRING_AGG(CASE WHEN n.' || cname || ' IS NULL THEN ''%NULLVALUE%''' + || ' ELSE regexp_replace(n.' || cstr || ', E''[\\n\\r]+'', ''\n'', ''g'') END, ''' || sepval || ''' ORDER BY h.pos)' + || ' FROM hierarchy h' + || ' JOIN ' || tname || ' n ON (h.id = n.id AND lower(h.primarytype) = $1)' + || ' WHERE h.parentid = $2' + || ' GROUP BY h.parentid' + INTO aggstr + USING tname, coid; + + RETURN aggstr; + +END; +$$ +LANGUAGE plpgsql; + +GRANT EXECUTE ON FUNCTION utils.aggRepGroupField(coid varchar, tname varchar, cname varchar, sepval varchar) to reporters_pahma; + +-- SELECT proacl FROM pg_proc WHERE proname = 'aggrepgroupfield'; + +-- SELECT utils.aggRepGroupField('2dbcbf18-4966-4178-9880-e81258568921', 'referencegroup', 'reference', '|'); + +-- SELECT utils.aggRepGroupField('2dbcbf18-4966-4178-9880-e81258568921', 'nagprareportfiledgroup', 'nagprareportfiled', '|'); +