forked from collectionspace/services
-
Notifications
You must be signed in to change notification settings - Fork 0
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
Merge pull request collectionspace#236 from lkvoong/CC-1492
CC-1492: Add new functions for Repatriation and NAGPRA Compliance report
- Loading branch information
Showing
3 changed files
with
145 additions
and
0 deletions.
There are no files selected for viewing
49 changes: 49 additions & 0 deletions
49
services/common/src/main/resources/db/postgresql/function_pahma_aggRepDateField.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 |
---|---|---|
@@ -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', '|'); | ||
|
40 changes: 40 additions & 0 deletions
40
services/common/src/main/resources/db/postgresql/function_pahma_aggRepField.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 |
---|---|---|
@@ -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', '|'); | ||
|
56 changes: 56 additions & 0 deletions
56
services/common/src/main/resources/db/postgresql/function_pahma_aggRepGroupField.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 |
---|---|---|
@@ -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', '|'); | ||
|