Commit f7c86e7f authored by Bjarni Pjetursson's avatar Bjarni Pjetursson
Browse files

Add new file

parent 53dfa439
/*
DB: jupiter-oracle-prod (skal oplyses her i scriptet!)
Titel: Aktive vandforsyningsboringer tilknyttet aktive almene vandværker uden tilladelse
Revision: 0.1 - bpj@geus.dk 2022-05-24
Status: prototype
*/
SELECT
anl.municipalityno2007||' - '||kl.longtext AS kommune,
TO_CHAR(anl.plantid)||' - '||anl.plantname AS anlaeg,
TO_CHAR(anl.participantvatno) AS cvr,
vtno.companytype||' - '||vl.longtext AS virksomhedstype,
anl.vrrpurpose||' - '||ifl.longtext AS indvindingsformaal,
cp.amountperyear AS anl_tilladelse_m3,
anl.dataowner AS anlaeg_dataejer,
CASE WHEN anl.xutm32euref89 IS NOT NULL THEN 'POINT('||TO_CHAR(ROUND(anl.xutm32euref89))||' '||TO_CHAR(ROUND(anl.yutm32euref89))||')' END AS anlaeg_utm32euref89,
TO_CHAR(ia_bo.intakeusage)||' - '||ianv.longtext AS indtagsanvendelse,
ia_bo.startdate AS indtag_startdato,
ia_bo.enddate AS indtag_slutdato,
ia_bo.boreholeno AS dgunr,
CASE WHEN ia_bo.purpose IS NOT NULL THEN bf.longtext||' ['||ia_bo.purpose||']' END AS oprindeligt_boringsformaal,
CASE WHEN ia_bo.use IS NOT NULL THEN ba.shorttext||' ['||ia_bo.use||']' END AS aktuel_boringsanvendelse,
ia_bo.amountperyear AS bor_tilladelse_m3,
CASE WHEN ia_bo.xutm32euref89 IS NOT NULL THEN 'POINT('||TO_CHAR(ROUND(ia_bo.xutm32euref89))||' '||TO_CHAR(ROUND(ia_bo.yutm32euref89))||')' END AS boring_utm32euref89
FROM drwplant anl /* Anlæg https://data.geus.dk/tabellerkoder/index.html?tablename=DRWPLANT */
LEFT JOIN code_808 kl ON anl.municipalityno2007 = kl.code /* Kommune https://data.geus.dk/tabellerkoder/koder.html?codetype=808 */
LEFT JOIN code_807 rl ON anl.region = rl.code /* Region https://data.geus.dk/tabellerkoder/koder.html?codetype=807 */
LEFT JOIN code_741 ifl ON anl.vrrpurpose = ifl.code /* Anlægsformål https://data.geus.dk/tabellerkoder/koder.html?codetype=741 */
LEFT JOIN (
SELECT /* Virksomhedstype https://data.geus.dk/tabellerkoder/index.html?tablename=DRWPLANTCOMPANYTYPE */
vt.plantid, vt.companytype, vt.companytypeno, vt.updatedate, vt.insertdate,
ROW_NUMBER () OVER (PARTITION BY vt.plantid ORDER BY CASE WHEN vt.companytype IN ('V01','V02','M42') THEN 1 ELSE 2 END, COALESCE(vt.updatedate,vt.insertdate) DESC) prio
FROM drwplantcompanytype vt) vtno ON anl.plantid = vtno.plantid AND vtno.prio = 1
LEFT JOIN code_852 vl ON vtno.companytype = vl.code /* Virksomhedstype https://data.geus.dk/tabellerkoder/koder.html?codetype=852 */
LEFT JOIN (
/* Indvindingstilladelse https://data.geus.dk/tabellerkoder/index.html?tablename=CATCHPERM */
SELECT SUM(cp.amountperyear) amountperyear, cp.plantid
FROM catchperm cp
WHERE (cp.startdate <= sysdate OR cp.startdate IS NULL)
AND (cp.enddate >= sysdate OR cp.enddate IS NULL)
AND COALESCE(cp.revoked,'0') = '0'
/* AND cp.companytype IS NOT NULL */ /* TODO: Kriterie bør undersøges nærmere */
AND cp.amountperyear IS NOT NULL
GROUP BY cp.plantid
) cp ON anl.plantid = cp.plantid
LEFT JOIN (
/* Vi laver et sub-select, så både indtagsanvendelse og boringens anvendelse/formål afgør, om boringsoplysninger kommer med */
SELECT bo.boreholeid, ia.plantid, ia.intakeusage, ia.startdate, ia.enddate, bo.boreholeno, bo.purpose, bo.use, bo.xutm32euref89, bo.yutm32euref89, SUM(bcc.amountperyear) AS amountperyear
FROM drwplantintake ia /* Indtag-anlæg-kobling https://data.geus.dk/tabellerkoder/index.html?tablename=DRWPLANTINTAKE */
JOIN borehole bo ON ia.boreholeid = bo.boreholeid
LEFT JOIN borecatchcond bcc /* Boringsindvindingstilladelse https://data.geus.dk/tabellerkoder/index.html?tablename=BORECATCHCOND */
ON bo.boreholeid = bcc.boreholeid AND (bcc.startdate <= sysdate OR bcc.startdate IS NULL) AND (bcc.enddate >= sysdate OR bcc.enddate IS NULL) AND bcc.amountperyear IS NOT NULL
WHERE (ia.startdate <= sysdate OR ia.startdate IS NULL)
AND (ia.enddate >= sysdate OR ia.enddate IS NULL)
AND COALESCE(bo.use,bo.purpose) IN ('V','VV','RE','VR')
AND COALESCE(ia.intakeusage,0) IN (0,1,3) /* 0=ikke oplyst, 1=indvinding, 3=indvinding og monitering. NB: afværge, grundvandssænkning o.lign. er ikke med. */
GROUP BY bo.boreholeid, ia.plantid, ia.intakeusage, ia.startdate, ia.enddate, bo.boreholeno, bo.purpose, bo.use, bo.xutm32euref89, bo.yutm32euref89
) ia_bo ON anl.plantid = ia_bo.plantid
LEFT JOIN code_816 ianv ON ia_bo.intakeusage = ianv.code /* Indtagsanvendelse https://data.geus.dk/tabellerkoder/koder.html?codetype=816 */
LEFT JOIN code_17 bf ON ia_bo.purpose = bf.code /* Boringsformål https://data.geus.dk/tabellerkoder/koder.html?codetype=17 */
LEFT JOIN code_855 ba ON ia_bo.use = ba.code /* Boringsanvendelse https://data.geus.dk/tabellerkoder/koder.html?codetype=855 */
WHERE
vtno.companytype IN ('V01','V02') /* Almene anlæg */
AND (anl.active != 2 OR anl.active IS NULL)
AND anl.region IS NOT NULL /* Udelad grønlandske anlæg */
AND (cp.amountperyear IS NULL OR cp.amountperyear = 0) /* Ingen anlægstilladelse */
AND (ia_bo.amountperyear IS NULL OR ia_bo.amountperyear = 0) /* Ingen boringstilladelser */
ORDER BY region, kommune, anlaeg, dgunr
Supports Markdown
0% or .
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment