Skip to content

Commit a714f62

Browse files
committed
Updating queries to work with downloads.
1 parent 503917b commit a714f62

23 files changed

+768
-177
lines changed

README.md

Lines changed: 5 additions & 6 deletions
Original file line numberDiff line numberDiff line change
@@ -6,12 +6,11 @@ This is a repository to store the functions used within the Neotoma Database for
66

77
All individuals are welcome to contribute to this repository. Contributions are subject to the [Code of Conduct](https://github.com/neotomadb/Neotoma_SQL/blob/master/code_of_conduct.md) for this repository.
88

9-
* Steve Crawford - [Penn State](http://www.ems.psu.edu/node/147)
10-
* Simon Goring - [University of Wisconsin](http://goring.org)
11-
* Mike Stryker - [Penn State](http://www.ems.psu.edu/node/2892)
12-
* Jonathan Nelson - Penn State
13-
* Adrian George - University of Wisconsin
14-
* Jack Williams - University of Wisconsin
9+
* Steve Crawford - [Penn State](http://www.ems.psu.edu/node/147)
10+
* Simon Goring - [University of Wisconsin](http://goring.org)
11+
* Mike Stryker - [Penn State](http://www.ems.psu.edu/node/2892)
12+
* Anna George - University of Wisconsin
13+
* Jack Williams - University of Wisconsin
1514

1615
## Description
1716

Lines changed: 34 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,34 @@
1+
CREATE OR REPLACE FUNCTION ap.collectionunitobject(_collectionunitid integer)
2+
RETURNS TABLE(collectionunitid integer, collectionunit jsonb)
3+
LANGUAGE sql
4+
AS $function$
5+
SELECT clu.collectionunitid,
6+
jsonb_build_object('site', (SELECT site FROM ap.siteobject(clu.siteid)),
7+
'collectionunit', json_build_array(jsonb_build_object('collectionunitid', clu.collectionunitid,
8+
'depositionalenvironment', dvt.depenvt,
9+
'collectionunit', clu.collunitname,
10+
'handle', clu.handle,
11+
'collunittype', cts.colltype,
12+
'colldate', clu.colldate,
13+
'waterdepth', clu.waterdepth,
14+
'notes', clu.notes,
15+
'collectiondevice', clu.colldevice,
16+
'location', clu.location,
17+
'gpslocation', json_build_object('latitude', clu.gpslatitude,
18+
'longitude', clu.gpslongitude,
19+
'gpsaltitude', clu.gpsaltitude,
20+
'gpserror', clu.gpserror),
21+
'collectors', json_agg(DISTINCT jsonb_build_object('contactid', cnt.contactid,
22+
'contactname', cnt.contactname,
23+
'familyname', cnt.familyname,
24+
'firstname', cnt.givennames,
25+
'initials', cnt.leadinginitials))))) AS collectionunit
26+
FROM
27+
ndb.collectionunits AS clu
28+
LEFT JOIN ndb.depenvttypes AS dvt ON dvt.depenvtid = clu.depenvtid
29+
LEFT JOIN ndb.collectiontypes AS cts ON cts.colltypeid = clu.colltypeid
30+
LEFT OUTER JOIN ndb.collectors AS col ON col.collectionunitid = clu.collectionunitid
31+
LEFT JOIN ndb.contacts AS cnt ON cnt.contactid = col.contactid
32+
WHERE clu.collectionunitid = _collectionunitid
33+
GROUP BY clu.collectionunitid, dvt.depenvt, cts.colltype;
34+
$function$

function/ap/datasetobject.sql

Lines changed: 50 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,50 @@
1+
CREATE OR REPLACE FUNCTION ap.datasetobject(_datasetid integer)
2+
RETURNS TABLE(datasetid integer, dataset jsonb)
3+
LANGUAGE sql
4+
AS $function$
5+
SELECT dts.datasetid,
6+
jsonb_build_object('datasetid', dts.datasetid,
7+
'datasettype', dst.datasettype,
8+
'datasetnotes', dts.notes,
9+
'database', cstdb.databasename,
10+
'doi', json_agg(DISTINCT doi.doi),
11+
'datasetpublications', json_agg(DISTINCT jsonb_build_object('publicationid', pub.publicationid,
12+
'citation', pub.citation)),
13+
'datasetpi', json_agg(DISTINCT jsonb_build_object('contactid', cnt.contactid,
14+
'contactname', cnt.contactname,
15+
'familyname', cnt.familyname,
16+
'firstname', cnt.givennames,
17+
'initials', cnt.leadinginitials)),
18+
'datasetprocessors', json_agg(DISTINCT jsonb_build_object('contactid', cntp.contactid,
19+
'contactname', cntp.contactname,
20+
'familyname', cntp.familyname,
21+
'firstname', cntp.givennames,
22+
'initials', cntp.leadinginitials)),
23+
'agerange', json_agg(DISTINCT jsonb_build_object('ageyoung', agerange.younger,
24+
'ageold', agerange.older,
25+
'units', agetypes.agetype)),
26+
'repository', json_agg(DISTINCT ri.repository))
27+
AS dataset
28+
FROM
29+
ndb.datasets AS dts
30+
LEFT OUTER JOIN ndb.datasettypes AS dst ON dst.datasettypeid = dts.datasettypeid
31+
LEFT OUTER JOIN ndb.datasetdoi AS doi ON dts.datasetid = doi.datasetid
32+
LEFT OUTER JOIN ndb.datasetdatabases AS dsdb ON dsdb.datasetid = dts.datasetid
33+
LEFT OUTER JOIN ndb.datasetpublications AS dtpub ON dtpub.datasetid = dts.datasetid
34+
LEFT OUTER JOIN ndb.publications AS pub ON pub.publicationid = dtpub.publicationid
35+
LEFT OUTER JOIN ndb.datasetpis AS dspi ON dspi.datasetid = dts.datasetid
36+
LEFT OUTER JOIN ndb.dataprocessors AS dspr ON dspr.datasetid = dts.datasetid
37+
LEFT OUTER JOIN ndb.contacts AS cntp ON cntp.contactid = dspi.contactid
38+
LEFT OUTER JOIN ndb.contacts AS cnt ON cnt.contactid = dspi.contactid
39+
LEFT OUTER JOIN ndb.dsageranges AS agerange ON dts.datasetid = agerange.datasetid
40+
LEFT OUTER JOIN ndb.agetypes AS agetypes ON agetypes.agetypeid = agerange.agetypeid
41+
LEFT OUTER JOIN ndb.constituentdatabases AS cstdb ON dsdb.databaseid = cstdb.databaseid
42+
LEFT OUTER JOIN ndb.repositoryspecimens AS rpspec ON rpspec.datasetid = dts.datasetid
43+
LEFT OUTER JOIN ndb.repositoryinstitutions AS ri ON ri.repositoryid = rpspec.repositoryid
44+
WHERE dts.datasetid = _datasetid
45+
GROUP BY
46+
dts.datasetid,
47+
dst.datasettype,
48+
dts.notes,
49+
cstdb.databasename
50+
$function$
Lines changed: 44 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,44 @@
1+
--
2+
DROP FUNCTION IF EXISTS ap.sitelink(_siteid integer);
3+
CREATE OR REPLACE FUNCTION ap.sitelink(_siteid integer)
4+
RETURNS TABLE(siteid integer, sitelink jsonb)
5+
LANGUAGE sql
6+
AS $function$
7+
SELECT sts.siteid,
8+
json_build_object('collectionunitid', clu.collectionunitid,
9+
'collectionunit', clu.collunitname,
10+
'handle', clu.handle,
11+
'collectionunittype', cts.colltype,
12+
'datasets', json_agg(json_build_object('datasetid', dts.datasetid,
13+
'datasettype', dst.datasettype))) AS collectionunit
14+
FROM
15+
ndb.datasets AS dts
16+
LEFT JOIN ndb.collectionunits AS clu ON clu.collectionunitid = dts.collectionunitid
17+
LEFT JOIN ndb.sites AS sts ON sts.siteid = clu.siteid
18+
LEFT JOIN ndb.datasettypes AS dst ON dst.datasettypeid = dts.datasettypeid
19+
LEFT OUTER JOIN ndb.collectiontypes as cts ON clu.colltypeid = cts.colltypeid
20+
WHERE sts.siteid = _siteid
21+
GROUP BY sts.siteid, clu.collectionunitid, cts.colltype
22+
$function$;
23+
24+
DROP FUNCTION IF EXISTS ap.sitelink(_siteid integer[]);
25+
CREATE OR REPLACE FUNCTION ap.sitelink(_siteid integer[])
26+
RETURNS TABLE(siteid integer, sitelink jsonb)
27+
LANGUAGE sql
28+
AS $function$
29+
SELECT sts.siteid,
30+
json_build_object('collectionunitid', clu.collectionunitid,
31+
'collectionunit', clu.collunitname,
32+
'handle', clu.handle,
33+
'collectionunittype', cts.colltype,
34+
'datasets', json_agg(json_build_object('datasetid', dts.datasetid,
35+
'datasettype', dst.datasettype))) AS collectionunit
36+
FROM
37+
ndb.datasets AS dts
38+
LEFT JOIN ndb.collectionunits AS clu ON clu.collectionunitid = dts.collectionunitid
39+
LEFT JOIN ndb.sites AS sts ON sts.siteid = clu.siteid
40+
LEFT JOIN ndb.datasettypes AS dst ON dst.datasettypeid = dts.datasettypeid
41+
LEFT OUTER JOIN ndb.collectiontypes as cts ON clu.colltypeid = cts.colltypeid
42+
WHERE sts.siteid = ANY(_siteid)
43+
GROUP BY sts.siteid, clu.collectionunitid, cts.colltype
44+
$function$;

function/ap/sample.sql

Lines changed: 61 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,61 @@
1+
CREATE OR REPLACE FUNCTION ap.sample(_datasetid integer)
2+
RETURNS TABLE(datasetid integer, sample jsonb)
3+
LANGUAGE sql
4+
AS $function$
5+
SELECT
6+
ds.datasetid,
7+
jsonb_build_object('sampleid', dsd.sampleid,
8+
'keywords', array_agg(DISTINCT ky.keyword),
9+
'depth', anu.depth,
10+
'datum', jsonb_agg(DISTINCT jsonb_build_object('value', dt.value,
11+
'variablename', tx.taxonname,
12+
'taxonid', tx.taxonid,
13+
'taxongroup', txg.taxagroup,
14+
'ecologicalgroup', ecg.ecolgroupid,
15+
'element', ve.variableelement,
16+
'elementtype', vt.elementtype,
17+
'symmetry', vs.symmetry,
18+
'context', vc.variablecontext,
19+
'units', vru.variableunits)),
20+
'sampleanalyst', json_agg(DISTINCT jsonb_build_object('contactid', cnt.contactid,
21+
'contactname', cnt.contactname,
22+
'familyname', cnt.familyname,
23+
'firstname', cnt.givennames,
24+
'initials', cnt.leadinginitials)),
25+
'ages', jsonb_agg(
26+
DISTINCT jsonb_build_object('chronologyid', ch.chronologyid,
27+
'chronologyname', ch.chronologyname,
28+
'agetype', cht.agetype,
29+
'age', sma.age,
30+
'ageyounger', sma.ageyounger,
31+
'ageolder', sma.ageolder))) AS sampledata
32+
FROM
33+
ndb.datasets AS ds
34+
LEFT OUTER JOIN ndb.dsdatasample AS dsd ON dsd.datasetid = ds.datasetid
35+
LEFT OUTER JOIN ndb.data AS dt ON dt.dataid = dsd.dataid
36+
LEFT OUTER JOIN ndb.variables AS var ON var.variableid = dsd.variableid
37+
LEFT OUTER JOIN ndb.taxa AS tx ON tx.taxonid = var.taxonid
38+
LEFT OUTER JOIN ndb.taxagrouptypes AS txg ON txg.taxagroupid = tx.taxagroupid
39+
LEFT OUTER JOIN ndb.ecolgroups AS ecg ON ecg.taxonid = tx.taxonid
40+
LEFT OUTER JOIN ndb.variableunits AS vru ON vru.variableunitsid = var.variableunitsid
41+
LEFT OUTER JOIN ndb.samples AS smp ON smp.sampleid = dsd.sampleid
42+
LEFT OUTER JOIN ndb.sampleanalysts AS san ON san.sampleid = smp.sampleid
43+
LEFT JOIN ndb.contacts AS cnt ON cnt.contactid = san.contactid
44+
LEFT OUTER JOIN ndb.analysisunits AS anu ON anu.analysisunitid = smp.analysisunitid
45+
LEFT JOIN ndb.variableelements AS ve ON ve.variableelementid = var.variableelementid
46+
LEFT OUTER JOIN ndb.elementsymmetries AS vs ON vs.symmetryid = ve.symmetryid
47+
LEFT OUTER JOIN ndb.elementtypes AS vt ON vt.elementtypeid = ve.elementtypeid
48+
LEFT JOIN ndb.variablecontexts AS vc ON vc.variablecontextid = var.variablecontextid
49+
LEFT OUTER JOIN ndb.sampleages AS sma ON sma.sampleid = smp.sampleid
50+
LEFT OUTER JOIN ndb.chronologies AS ch ON sma.chronologyid = ch.chronologyid
51+
LEFT OUTER JOIN ndb.agetypes AS cht ON cht.agetypeid = ch.agetypeid
52+
LEFT OUTER JOIN ndb.samplekeywords AS smpky ON smpky.sampleid = smp.sampleid
53+
LEFT OUTER JOIN ndb.keywords AS ky ON ky.keywordid = smpky.keywordid
54+
WHERE
55+
ds.datasetid = _datasetid
56+
GROUP BY ds.datasetid,
57+
dsd.sampleid,
58+
anu.depth,
59+
anu.thickness
60+
ORDER BY anu.depth ASC;
61+
$function$

function/ap/sitelink.sql

Lines changed: 20 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,20 @@
1+
CREATE OR REPLACE FUNCTION ap.sitelink(_siteid integer)
2+
RETURNS TABLE(siteid integer, sitelink jsonb)
3+
LANGUAGE sql
4+
AS $function$
5+
SELECT sts.siteid,
6+
jsonb_build_object('collectionunitid', clu.collectionunitid,
7+
'collectionunit', clu.collunitname,
8+
'handle', clu.handle,
9+
'collectionunittype', cts.colltype,
10+
'datasets', json_agg(json_build_object('datasetid', dts.datasetid,
11+
'datasettype', dst.datasettype))) AS collectionunit
12+
FROM
13+
ndb.datasets AS dts
14+
LEFT JOIN ndb.collectionunits AS clu ON clu.collectionunitid = dts.collectionunitid
15+
LEFT JOIN ndb.sites AS sts ON sts.siteid = clu.siteid
16+
LEFT JOIN ndb.datasettypes AS dst ON dst.datasettypeid = dts.datasettypeid
17+
LEFT OUTER JOIN ndb.collectiontypes as cts ON clu.colltypeid = cts.colltypeid
18+
WHERE sts.siteid = _siteid
19+
GROUP BY sts.siteid, clu.collectionunitid, cts.colltype
20+
$function$

function/ap/siteobject.sql

Lines changed: 20 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,20 @@
1+
CREATE OR REPLACE FUNCTION ap.siteobject(_siteid integer)
2+
RETURNS TABLE(siteid integer, site jsonb)
3+
LANGUAGE sql
4+
AS $function$
5+
SELECT sts.siteid,
6+
jsonb_build_object( 'siteid', sts.siteid,
7+
'sitename', sts.sitename,
8+
'sitedescription', sts.sitedescription,
9+
'geography', ST_AsGeoJSON(sts.geog,5,2),
10+
'area', sts.area,
11+
'altitude', sts.altitude,
12+
'notes', sts.notes,
13+
'geopolitical', gpn.names) AS site
14+
FROM
15+
ndb.sites AS sts
16+
LEFT JOIN ap.geopolnames AS gpn ON gpn.siteid = sts.siteid
17+
WHERE sts.siteid = _siteid
18+
GROUP BY sts.siteid, sts.sitename, sts.sitedescription, ST_AsGeoJSON(sts.geog,5,2),
19+
sts.area, sts.altitude, sts.notes, gpn.names;
20+
$function$;

function/ap/updatequery.sql

Lines changed: 8 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,8 @@
1+
CREATE OR REPLACE FUNCTION ap.updatequery()
2+
RETURNS trigger
3+
LANGUAGE plpgsql
4+
AS $function$
5+
BEGIN
6+
REFRESH MATERIALIZED VIEW CONCURRENTLY ap.querytable;
7+
RETURN NULL;
8+
END $function$

0 commit comments

Comments
 (0)