Skip to content

Commit

Permalink
add changes to view period_standardised (#42)
Browse files Browse the repository at this point in the history
* add changes to view period_standardised

* remove V20

* change branch in yml file

* test commit

* change drop in V27

* add view name

* replace '

* change branch in yml
  • Loading branch information
sisiphos3 authored Oct 26, 2023
1 parent f394766 commit 4e5f646
Show file tree
Hide file tree
Showing 2 changed files with 61 additions and 41 deletions.
41 changes: 0 additions & 41 deletions migrations/V20__update_logs_view_with_periodicity.sql

This file was deleted.

61 changes: 61 additions & 0 deletions migrations/V27__view_period_standardised_groupedbyyear.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,61 @@
CREATE or REPLACE VIEW public.kpi_values_period_standardized as
select *,
Case when target_value > 0 then ROUND(cumulative_value/target_value*100, 0) else null end as target_fulfilled
FROM
(
select distinct
on (
kd.kpi_id,
standardized_date,
t1.circle_id
) t1.kpi_value_history_id,
t1.kpi_id,
t1.circle_id,
t1.user_id,
t1.value,
t1.period_date,
t1.action,
t1.created_at,
kd.periodicity as kpi_periodicity,
case
when kd.periodicity = 'yearly'::periodicity then date_trunc(
'year'::text,
t1.period_date::timestamp with time zone
) + '1 year'::interval - '1 day'::interval
when kd.periodicity = 'monthly'::periodicity then date_trunc(
'month'::text,
t1.period_date::timestamp with time zone
) + '1 mon'::interval - '1 day'::interval
when kd.periodicity = 'quarterly'::periodicity then date_trunc(
'quarter'::text,
t1.period_date::timestamp with time zone
) + '3 mons'::interval - '1 day'::interval
when kd.periodicity = 'weekly'::periodicity then date_trunc(
'week'::text,
t1.period_date::timestamp with time zone
) - '1 day'::interval + '7 days'::interval
else t1.period_date::timestamp with time zone
end as standardized_date,
ku.user_name,
t1.comment,
case when kd.cumulative = false and kd.formula = 'aggregate' then sum(t1.value) over (partition by t1.kpi_id, t1.circle_id, EXTRACT(YEAR FROM t1.period_date) order by t1.period_date)
when kd.cumulative = true and kd.formula = 'aggregate' then t1.value
when kd.cumulative = false and kd.formula = 'average' then avg(t1.value) over (partition by t1.kpi_id, t1.circle_id, EXTRACT(YEAR FROM t1.period_date) order by t1.period_date)
when kd.cumulative = true and kd.formula = 'average' then t1.value
end as cumulative_value,
case when kd.formula = 'aggregate' then 'area_graph'
when kd.formula = 'average' and kd.unit in ('numeric', '%') then 'line_graph'
when kd.formula = 'average' and kd.unit = 'boolean' then 'donut_graph'
end as graph_type,
tar.target_value
from
kpi_values_history t1
join kpi_definition kd on t1.kpi_id = kd.kpi_id
left join kpi_user ku on t1.user_id = ku.user_id
left join target tar on tar.kpi_id = t1.kpi_id AND tar.circle_id = t1.circle_id
order by
kd.kpi_id,
standardized_date desc,
t1.circle_id,
t1.created_at desc
) as sq;

0 comments on commit 4e5f646

Please sign in to comment.