1+ CREATE FUNCTION ap .dailyquerytable(_interval VARCHAR )
2+ RETURNS TABLE (siteid INT ,
3+ sitename VARCHAR ,
4+ datasetid INT ,
5+ chronologyid INT ,
6+ altitude FLOAT,
7+ datasettype VARCHAR ,
8+ databaseid INT ,
9+ collectionunitid INT ,
10+ colltype VARCHAR ,
11+ depenvt VARCHAR ,
12+ geog GEOGRAPHY,
13+ older FLOAT,
14+ younger FLOAT,
15+ agetype VARCHAR ,
16+ publications INT [],
17+ taxa INT [],
18+ keywords INT [],
19+ contacts INT [],
20+ collectionunit JSONB,
21+ geopol INT [])
22+ AS $$
23+ WITH allids AS (
24+ SELECT st .siteid ,
25+ unnest(array_append(gp .geoout , gp .geoin ::int )) AS geopol
26+ FROM ndb .sites AS st
27+ INNER JOIN ndb .sitegeopolitical AS sgp ON st .siteid = sgp .siteid
28+ INNER JOIN ndb .geopoliticalunits AS gpu ON gpu .geopoliticalid = sgp .geopoliticalid
29+ INNER JOIN ndb .geopaths AS gp ON gp .geoin = sgp .geopoliticalid
30+ ),
31+ sgp AS (
32+ SELECT siteid, array_agg(DISTINCT geopol) AS geopol
33+ FROM allids
34+ GROUP BY siteid
35+ )
36+ SELECT st .siteid ,
37+ st .sitename ,
38+ ds .datasetid ,
39+ chron .chronologyid ,
40+ st .altitude ,
41+ dst .datasettype ,
42+ dsdb .databaseid ,
43+ cu .collectionunitid ,
44+ cut .colltype ,
45+ dvt .depenvt ,
46+ st .geog ,
47+ arg .older ,
48+ arg .younger ,
49+ agetypes .agetype ,
50+ array_remove(array_agg(DISTINCT dspb .publicationid ), NULL ) AS publications,
51+ array_remove(array_agg(DISTINCT var .taxonid ), NULL ) AS taxa,
52+ array_remove(array_agg(DISTINCT smpkw .keywordid ), NULL ) AS keywords,
53+ array_remove(array_agg(DISTINCT dpi .contactid ) || array_agg(DISTINCT sma .contactid ), NULL ) AS contacts,
54+ jsonb_build_object(' collectionunitid' , cu .collectionunitid ,
55+ ' collectionunit' , cu .collunitname ,
56+ ' handle' , cu .handle ,
57+ ' collectionunittype' , cut .colltype ,
58+ ' datasets' , json_agg(DISTINCT jsonb_build_object(' datasetid' , ds .datasetid ,
59+ ' datasettype' , dst .datasettype ))) AS collectionunit,
60+ sgp .geopol
61+ FROM ndb .sites AS st
62+ LEFT OUTER JOIN ndb .collectionunits AS cu ON cu .siteid = st .siteid
63+ LEFT OUTER JOIN ndb .collectiontypes AS cut ON cut .colltypeid = cu .colltypeid
64+ LEFT OUTER JOIN ndb .datasets AS ds ON ds .collectionunitid = cu .collectionunitid
65+ LEFT OUTER JOIN ndb .depenvttypes AS dvt ON dvt .depenvtid = cu .depenvtid
66+ LEFT OUTER JOIN ndb .datasetpis AS dpi ON dpi .datasetid = ds .datasetid
67+ LEFT OUTER JOIN ndb .datasettypes AS dst ON dst .datasettypeid = ds .datasettypeid
68+ LEFT OUTER JOIN ndb .datasetdatabases AS dsdb ON ds .datasetid = dsdb .datasetid
69+ LEFT OUTER JOIN ndb .datasetpublications AS dspb ON dspb .datasetid = ds .datasetid
70+ LEFT OUTER JOIN ndb .chronologies AS chron ON chron .collectionunitid = ds .collectionunitid
71+ LEFT OUTER JOIN ndb .dsageranges AS arg ON ds .datasetid = arg .datasetid AND chron .agetypeid = arg .agetypeid
72+ LEFT OUTER JOIN ndb .agetypes AS agetypes ON agetypes .agetypeid = arg .agetypeid
73+ LEFT OUTER JOIN ndb .samples AS smp ON smp .datasetid = ds .datasetid
74+ LEFT OUTER JOIN ndb .sampleanalysts AS sma ON sma .sampleid = smp .sampleid
75+ LEFT OUTER JOIN ndb .samplekeywords AS smpkw ON smpkw .sampleid = smp .sampleid
76+ LEFT OUTER JOIN ndb .data AS dt ON dt .sampleid = smp .sampleid
77+ LEFT OUTER JOIN ndb .variables AS var ON var .variableid = dt .variableid
78+ LEFT OUTER JOIN sgp AS sgp ON st .siteid = sgp .siteid
79+ WHERE ds .recdatemodified > current_date - (_interval || ' day' )::INTERVAL OR
80+ smp .recdatemodified > current_date - (_interval || ' day' )::INTERVAL OR
81+ st .recdatemodified > current_date - (_interval || ' day' )::INTERVAL
82+ GROUP BY st .siteid ,
83+ cu .collectionunitid ,
84+ st .sitename ,
85+ ds .datasetid ,
86+ cut .colltype ,
87+ chron .chronologyid ,
88+ dsdb .databaseid ,
89+ st .altitude ,
90+ dst .datasettype ,
91+ st .geog ,
92+ arg .older ,
93+ arg .younger ,
94+ agetypes .agetype ,
95+ sgp .geopol ,
96+ dvt .depenvt
97+ $$ LANGUAGE sql;
0 commit comments