|
| 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$ |
0 commit comments