annotate schema/updates/1470/01.update_report.sql @ 5640:47ee6ecf94de DQR adjustments

update reports.sql. Migration of materialized view
author Thomas Junk <thomas.junk@intevation.de>
date Thu, 01 Jun 2023 12:24:18 +0200
parents
children 6fe970d800ec
Ignore whitespace changes - Everywhere: Within whitespace: At end of lines:
rev   line source
5640
47ee6ecf94de update reports.sql. Migration of materialized view
Thomas Junk <thomas.junk@intevation.de>
parents:
diff changeset
1 DROP MATERIALIZED VIEW waterway.dqr_bottleneck_stats;
47ee6ecf94de update reports.sql. Migration of materialized view
Thomas Junk <thomas.junk@intevation.de>
parents:
diff changeset
2
47ee6ecf94de update reports.sql. Migration of materialized view
Thomas Junk <thomas.junk@intevation.de>
parents:
diff changeset
3 CREATE MATERIALIZED VIEW waterway.dqr_bottleneck_stats AS
47ee6ecf94de update reports.sql. Migration of materialized view
Thomas Junk <thomas.junk@intevation.de>
parents:
diff changeset
4 WITH d AS ( SELECT ym::date
47ee6ecf94de update reports.sql. Migration of materialized view
Thomas Junk <thomas.junk@intevation.de>
parents:
diff changeset
5 FROM generate_series( '2019-10-01'::date,
47ee6ecf94de update reports.sql. Migration of materialized view
Thomas Junk <thomas.junk@intevation.de>
parents:
diff changeset
6 now() - interval '1 day',
47ee6ecf94de update reports.sql. Migration of materialized view
Thomas Junk <thomas.junk@intevation.de>
parents:
diff changeset
7 '1 month'::interval ) ym),
47ee6ecf94de update reports.sql. Migration of materialized view
Thomas Junk <thomas.junk@intevation.de>
parents:
diff changeset
8 bn AS ( SELECT DISTINCT bottleneck_id ,max(objnam) as objnam, responsible_country AS cc,
47ee6ecf94de update reports.sql. Migration of materialized view
Thomas Junk <thomas.junk@intevation.de>
parents:
diff changeset
9 min ((lower(stretch)).hectometre) AS hm
47ee6ecf94de update reports.sql. Migration of materialized view
Thomas Junk <thomas.junk@intevation.de>
parents:
diff changeset
10 FROM waterway.bottlenecks
47ee6ecf94de update reports.sql. Migration of materialized view
Thomas Junk <thomas.junk@intevation.de>
parents:
diff changeset
11 WHERE validity @> tstzrange(now() - interval '1 hour', now() + interval '1 hour', '[)')
47ee6ecf94de update reports.sql. Migration of materialized view
Thomas Junk <thomas.junk@intevation.de>
parents:
diff changeset
12 GROUP BY bottleneck_id,cc
47ee6ecf94de update reports.sql. Migration of materialized view
Thomas Junk <thomas.junk@intevation.de>
parents:
diff changeset
13 )
47ee6ecf94de update reports.sql. Migration of materialized view
Thomas Junk <thomas.junk@intevation.de>
parents:
diff changeset
14 SELECT bn.cc, bn.hm, d.ym AS month, bn.objnam, bn.bottleneck_id,
47ee6ecf94de update reports.sql. Migration of materialized view
Thomas Junk <thomas.junk@intevation.de>
parents:
diff changeset
15 COALESCE(count(distinct(sr.date_info)),0) AS srcnt,
47ee6ecf94de update reports.sql. Migration of materialized view
Thomas Junk <thomas.junk@intevation.de>
parents:
diff changeset
16 COALESCE(count(distinct(efa.measure_date)),0) AS fwacnt
47ee6ecf94de update reports.sql. Migration of materialized view
Thomas Junk <thomas.junk@intevation.de>
parents:
diff changeset
17 FROM bn
47ee6ecf94de update reports.sql. Migration of materialized view
Thomas Junk <thomas.junk@intevation.de>
parents:
diff changeset
18 CROSS JOIN d
47ee6ecf94de update reports.sql. Migration of materialized view
Thomas Junk <thomas.junk@intevation.de>
parents:
diff changeset
19 LEFT OUTER JOIN waterway.sounding_results sr
47ee6ecf94de update reports.sql. Migration of materialized view
Thomas Junk <thomas.junk@intevation.de>
parents:
diff changeset
20 ON sr.bottleneck_id = bn.bottleneck_id
47ee6ecf94de update reports.sql. Migration of materialized view
Thomas Junk <thomas.junk@intevation.de>
parents:
diff changeset
21 AND d.ym <= sr.date_info
47ee6ecf94de update reports.sql. Migration of materialized view
Thomas Junk <thomas.junk@intevation.de>
parents:
diff changeset
22 AND sr.date_info < (d.ym + interval '1 month')
47ee6ecf94de update reports.sql. Migration of materialized view
Thomas Junk <thomas.junk@intevation.de>
parents:
diff changeset
23 LEFT OUTER JOIN waterway.fairway_availability fa
47ee6ecf94de update reports.sql. Migration of materialized view
Thomas Junk <thomas.junk@intevation.de>
parents:
diff changeset
24 ON fa.bottleneck_id = bn.bottleneck_id
47ee6ecf94de update reports.sql. Migration of materialized view
Thomas Junk <thomas.junk@intevation.de>
parents:
diff changeset
25 LEFT OUTER JOIN waterway.effective_fairway_availability efa
47ee6ecf94de update reports.sql. Migration of materialized view
Thomas Junk <thomas.junk@intevation.de>
parents:
diff changeset
26 ON fairway_availability_id = fa.id
47ee6ecf94de update reports.sql. Migration of materialized view
Thomas Junk <thomas.junk@intevation.de>
parents:
diff changeset
27 AND d.ym <= efa.measure_date
47ee6ecf94de update reports.sql. Migration of materialized view
Thomas Junk <thomas.junk@intevation.de>
parents:
diff changeset
28 AND efa.measure_date < (d.ym + interval '1 month')
47ee6ecf94de update reports.sql. Migration of materialized view
Thomas Junk <thomas.junk@intevation.de>
parents:
diff changeset
29 AND efa.measure_type = 'Measured'
47ee6ecf94de update reports.sql. Migration of materialized view
Thomas Junk <thomas.junk@intevation.de>
parents:
diff changeset
30 GROUP BY bn.cc, bn.hm, d.ym, bn.bottleneck_id, bn.objnam;