This commit is contained in:
parent
879825a260
commit
b374b7f49d
@ -45,3 +45,10 @@ create or replace view temperature_v as
|
|||||||
from measurements
|
from measurements
|
||||||
where application in ('Temperature Multisensor', 'Temperature Shelly Plus HT');
|
where application in ('Temperature Multisensor', 'Temperature Shelly Plus HT');
|
||||||
|
|
||||||
|
create or replace view humidity_v as
|
||||||
|
select time,
|
||||||
|
cast(values->'Value'->>'value' as float) as humidity,
|
||||||
|
device
|
||||||
|
from measurements
|
||||||
|
where application in ('Humidity Multisensor');
|
||||||
|
|
||||||
|
73
queries/old-pv-yield-query.sql
Normal file
73
queries/old-pv-yield-query.sql
Normal file
@ -0,0 +1,73 @@
|
|||||||
|
-- query
|
||||||
|
|
||||||
|
with
|
||||||
|
first_day_in_year as (
|
||||||
|
select
|
||||||
|
date_trunc('day', min(time)) as day
|
||||||
|
from pv_power_measurement_t
|
||||||
|
where
|
||||||
|
time between date_trunc('year', time) and now()
|
||||||
|
),
|
||||||
|
first_value_in_year as (
|
||||||
|
select
|
||||||
|
time_bucket('1 day', time) as interval,
|
||||||
|
first(exportenergyactive, time) as energy
|
||||||
|
from pv_power_measurement_t
|
||||||
|
where
|
||||||
|
time between (select day from first_day_in_year) and (select day from first_day_in_year) + interval '1 day' and
|
||||||
|
status = 'Ok'
|
||||||
|
group by interval
|
||||||
|
),
|
||||||
|
first_day_in_month as (
|
||||||
|
select
|
||||||
|
date_trunc('day', min(time)) as day
|
||||||
|
from pv_power_measurement_t
|
||||||
|
where
|
||||||
|
time between date_trunc('month', now()) and now()
|
||||||
|
),
|
||||||
|
first_value_in_month as (
|
||||||
|
select
|
||||||
|
time_bucket('1 day', time) as interval,
|
||||||
|
first(exportenergyactive, time) as energy
|
||||||
|
from pv_power_measurement_t
|
||||||
|
where
|
||||||
|
time between (select day from first_day_in_month) and (select day from first_day_in_month) + interval '1 day' and
|
||||||
|
status = 'Ok'
|
||||||
|
group by interval
|
||||||
|
),
|
||||||
|
first_value_in_day as (
|
||||||
|
select
|
||||||
|
time_bucket('1 day', time) as interval,
|
||||||
|
first(exportenergyactive, time) as energy
|
||||||
|
from pv_power_measurement_t
|
||||||
|
where time >= date_trunc('day', now())
|
||||||
|
group by interval
|
||||||
|
),
|
||||||
|
last_value as (
|
||||||
|
select
|
||||||
|
time_bucket('1 day', time) as interval,
|
||||||
|
last(exportenergyactive, time) as energy
|
||||||
|
from pv_power_measurement_t
|
||||||
|
where
|
||||||
|
time between date_trunc('day', now()) and date_trunc('day', now()) + interval '1 day' and
|
||||||
|
status = 'Ok'
|
||||||
|
group by interval
|
||||||
|
)
|
||||||
|
select
|
||||||
|
extract(year from (select day from first_day_in_year))::text as period_value,
|
||||||
|
'Year' as period_name,
|
||||||
|
round(((select energy from last_value) - (select energy from first_value_in_year))::numeric, 2) as yield
|
||||||
|
union
|
||||||
|
select
|
||||||
|
to_char((select day from first_day_in_month), 'Month') as period_value,
|
||||||
|
'Month' as period_name,
|
||||||
|
round(((select energy from last_value) - (select energy from first_value_in_month))::numeric, 2) as yield
|
||||||
|
union
|
||||||
|
select
|
||||||
|
now()::date::text as period_value,
|
||||||
|
'Day' as period_name,
|
||||||
|
round(((select energy from last_value) - (select energy from first_value_in_day))::numeric, 2) as yield;
|
||||||
|
|
||||||
|
-- output format
|
||||||
|
-- wn@atuin:~/Workspace/go-workspace/src/universal-data-ingest [main ≡ +0 ~1 -0 !]$ mosquitto_sub -h 172.23.1.102 -v -t IoT/PV/Yields
|
||||||
|
-- IoT/PV/Yields {"Month":"1.43","Year":"285.39","Day":"0.00"}
|
Loading…
x
Reference in New Issue
Block a user