-
Notifications
You must be signed in to change notification settings - Fork 1
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
Merge pull request #461 from cagov/kg-station-level-martmodel
Daily Station Count Mart Model
- Loading branch information
Showing
1 changed file
with
75 additions
and
0 deletions.
There are no files selected for viewing
75 changes: 75 additions & 0 deletions
75
transform/models/marts/quality/quality__station_row_count_summary.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,75 @@ | ||
with | ||
|
||
ML_HV_DETECTOR_STATUS_DAILY_COUNT as ( | ||
/* | ||
* This CTE returns the number of total rows by station created daily in | ||
* the int_diagnostics__detector_status model. This count should be | ||
* to checked against the daily station counts for the following models: | ||
* - int_clearinghouse__detector_agg_five_minutes_with_missing_rows | ||
* - int_imputation__detector_imputed_agg_five_minutes | ||
* - int_performance__station_metrics_agg_five_minutes | ||
* The daily station counts for these models should match for HV and ML | ||
* station types | ||
*/ | ||
select | ||
SAMPLE_DATE, | ||
count(distinct STATION_ID) as ML_HV_DETECTOR_STATUS_STATION_COUNT | ||
from {{ ref('int_diagnostics__detector_status') }} | ||
where | ||
STATION_TYPE in ('ML', 'HV') | ||
and SAMPLE_DATE >= current_date - 16 | ||
group by SAMPLE_DATE | ||
), | ||
|
||
-- Clearinghouse Station Count per Day | ||
ML_HV_CLEARINGHOUSE_STATION_DAILY_COUNT as ( | ||
select | ||
SAMPLE_DATE, | ||
count(distinct STATION_ID) as ML_HV_CLEARINGHOUSE_STATION_COUNT | ||
from {{ ref('int_clearinghouse__detector_agg_five_minutes_with_missing_rows') }} | ||
where | ||
STATION_TYPE in ('ML', 'HV') | ||
and SAMPLE_DATE >= current_date - 16 | ||
group by SAMPLE_DATE | ||
), | ||
|
||
-- Imputation Station Count per Day | ||
ML_HV_IMPUTATION_STATION_DAILY_COUNT as ( | ||
select | ||
SAMPLE_DATE, | ||
count(distinct STATION_ID) as ML_HV_IMPUTATION_STATION_COUNT | ||
from {{ ref('int_imputation__detector_imputed_agg_five_minutes') }} | ||
where | ||
STATION_TYPE in ('ML', 'HV') | ||
and SAMPLE_DATE >= current_date - 16 | ||
group by SAMPLE_DATE | ||
), | ||
|
||
-- Performance Station Count per Day | ||
ML_HV_PERFORMANCE_STATION_DAILY_COUNT as ( | ||
select | ||
SAMPLE_DATE, | ||
count(distinct STATION_ID) as ML_HV_PERFORMANCE_STATION_COUNT | ||
from {{ ref('int_performance__station_metrics_agg_five_minutes') }} | ||
where | ||
STATION_TYPE in ('ML', 'HV') | ||
and SAMPLE_DATE >= current_date - 16 | ||
group by SAMPLE_DATE | ||
), | ||
|
||
DAILY_STATION_COUNT_CHECK as ( | ||
select | ||
MHDSDC.*, | ||
CSDC.ML_HV_CLEARINGHOUSE_STATION_COUNT, | ||
ISDC.ML_HV_IMPUTATION_STATION_COUNT, | ||
PSDC.ML_HV_PERFORMANCE_STATION_COUNT | ||
from ML_HV_DETECTOR_STATUS_DAILY_COUNT as MHDSDC | ||
left join ML_HV_CLEARINGHOUSE_STATION_DAILY_COUNT as CSDC | ||
on MHDSDC.SAMPLE_DATE = CSDC.SAMPLE_DATE | ||
left join ML_HV_IMPUTATION_STATION_DAILY_COUNT as ISDC | ||
on MHDSDC.SAMPLE_DATE = ISDC.SAMPLE_DATE | ||
left join ML_HV_PERFORMANCE_STATION_DAILY_COUNT as PSDC | ||
on MHDSDC.SAMPLE_DATE = PSDC.SAMPLE_DATE | ||
) | ||
|
||
select * from DAILY_STATION_COUNT_CHECK |