Skip to content

Commit

Permalink
further improve accuracy in low precision mode and low data sample count
Browse files Browse the repository at this point in the history
  • Loading branch information
swiffer committed Nov 17, 2024
1 parent 25c35ef commit a993710
Show file tree
Hide file tree
Showing 2 changed files with 2 additions and 2 deletions.
2 changes: 1 addition & 1 deletion grafana/dashboards/statistics.json
Original file line number Diff line number Diff line change
Expand Up @@ -823,7 +823,7 @@
"format": "table",
"hide": false,
"rawQuery": true,
"rawSql": "-- This query is used to calculate \"Ø Consumption (gross)\" in Statistics and Trips (with minor changes).\n-- Please make sure to apply changes in both places!\n\nwith gen_date_series as (\n\n select \n generate_series(\n date_trunc('$period', to_timestamp(${__from:date:seconds})),\n date_trunc('$period', to_timestamp(${__to:date:seconds})),\n interval '1 $period'\n ) as series_id\n\n),\n\ndate_series as (\n\n select\n greatest(series_id, to_timestamp(${__from:date:seconds})) at time zone 'UTC' as series_id,\n -- before joining, get beginning of next series to be able to left join `charging_processes`\n least(lead(series_id) over (order by series_id asc), to_timestamp(${__to:date:seconds})) at time zone 'UTC' as next_series_id\n from gen_date_series\n where series_id >= (select date_trunc('$period', p.\"date\" at time zone 'UTC') from positions p where car_id = $car_id and ideal_battery_range_km is not null order by date asc limit 1)\n\n),\n\nbuckets_x_charging_processes as (\n\n select\n ds.*,\n coalesce(cp.car_id, $car_id) as car_id,\n lag(cp.end_${preferred_range}_range_km) over w as start_range_km,\n lag(cp.start_date) over w as start_date,\n lag(p.odometer) over w as start_odometer,\n case\n when lag(cp.end_${preferred_range}_range_km) over w is null then null\n else cp.start_${preferred_range}_range_km\n end as end_range_km,\n case\n when lag(cp.end_date) over w is null then null\n else cp.start_date\n end as end_date,\n case\n when lag(p.odometer) over w is null then null\n else p.odometer\n end as end_odometer,\n count(start_date) over w as charging_processes_count\n from date_series ds\n left join charging_processes cp on ds.series_id <= cp.start_date and ds.next_series_id >= cp.end_date\n left join positions p on cp.position_id = p.id\n where cp.car_id = $car_id or cp.car_id is null\n window w as (partition by ds.series_id order by cp.start_date)\n\n),\n\nbuckets_incl_charging_processes as (\n\n select\n series_id,\n next_series_id,\n car_id,\n coalesce(sum(start_range_km - end_range_km), 0) as range_loss,\n coalesce(max(end_odometer) - min(start_odometer), 0) as distance,\n coalesce(min(start_date), next_series_id) as start_date,\n coalesce(max(end_date), next_series_id) as end_date\n from buckets_x_charging_processes\n where start_range_km is not null or charging_processes_count < 2\n group by 1, 2, 3\n\n),\n\nbuckets_incl_charging_processes_x_surrounding_data as (\n\n select\n b_incl_cp.*,\n date_trunc('$period', timezone('UTC', series_id)) as date,\n lag(coalesce(d.start_${preferred_range}_range_km, p.${preferred_range}_battery_range_km)) OVER w - coalesce(d.start_${preferred_range}_range_km, p.${preferred_range}_battery_range_km) AS range_loss_b_and_a_cp,\n coalesce(d.start_km, p.odometer) - lag(coalesce(d.start_km, p.odometer)) OVER w AS distance_b_and_a_cp\n from buckets_incl_charging_processes b_incl_cp\n left join drives d on\n 0 = $high_precision\n and d.car_id = b_incl_cp.car_id\n and (\n d.start_date >= b_incl_cp.series_id\n and d.end_date < b_incl_cp.start_date\n or d.start_date > b_incl_cp.end_date\n and d.end_date < b_incl_cp.next_series_id\n )\n left join positions p on\n 1 = $high_precision\n and p.ideal_battery_range_km is not null\n and p.car_id = b_incl_cp.car_id\n and (\n p.\"date\" >= b_incl_cp.series_id\n and p.\"date\" < b_incl_cp.start_date\n or p.\"date\" > b_incl_cp.end_date\n and p.\"date\" <= b_incl_cp.next_series_id\n )\n window w as (partition by b_incl_cp.series_id, coalesce(d.start_date, p.\"date\") >= b_incl_cp.end_date ORDER BY coalesce(d.start_date, p.\"date\"))\n \n)\n\nselect\n EXTRACT(EPOCH FROM date)*1000 AS date_from,\n EXTRACT(EPOCH FROM date + interval '1 $period')*1000 AS date_to,\n CASE '$period'\n WHEN 'month' THEN to_char(date, 'YYYY Month')\n WHEN 'year' THEN to_char(date, 'YYYY')\n WHEN 'week' THEN 'week ' || to_char(date, 'WW') || ' starting ' || to_char(date, 'YYYY-MM-DD')\n ELSE to_char(date, 'YYYY-MM-DD')\n END AS display,\n date,\n ((range_loss + coalesce(sum(range_loss_b_and_a_cp), 0)) * c.efficiency * 1000) / nullif(convert_km((distance + coalesce(sum(distance_b_and_a_cp), 0))::numeric, '$length_unit'), 0) as consumption_gross_$length_unit\nfrom buckets_incl_charging_processes_x_surrounding_data\n inner join cars c on car_id = c.id\n where range_loss_b_and_a_cp >= 0 and distance_b_and_a_cp = 0 or distance_b_and_a_cp > 0 or range_loss_b_and_a_cp is null and distance_b_and_a_cp is null\n group by 1, 2, 3, 4, range_loss, distance, c.efficiency\n order by date desc\n",
"rawSql": "-- This query is used to calculate \"Ø Consumption (gross)\" in Statistics and Trips (with minor changes).\n-- Please make sure to apply changes in both places!\n\nwith gen_date_series as (\n\n select \n generate_series(\n date_trunc('$period', to_timestamp(${__from:date:seconds})),\n date_trunc('$period', to_timestamp(${__to:date:seconds})),\n interval '1 $period'\n ) as series_id\n\n),\n\ndate_series as (\n\n select\n greatest(series_id, to_timestamp(${__from:date:seconds})) at time zone 'UTC' as series_id,\n -- before joining, get beginning of next series to be able to left join `charging_processes`\n least(lead(series_id) over (order by series_id asc), to_timestamp(${__to:date:seconds})) at time zone 'UTC' as next_series_id\n from gen_date_series\n where series_id >= (select date_trunc('$period', p.\"date\" at time zone 'UTC') from positions p where car_id = $car_id and ideal_battery_range_km is not null order by date asc limit 1)\n\n),\n\nbuckets_x_charging_processes as (\n\n select\n ds.*,\n coalesce(cp.car_id, $car_id) as car_id,\n -- used to skip drives / positions between first charging process start & last charging process end\n first_value(cp.start_date) over w as min_cp_start_date,\n last_value(cp.end_date) over w as max_cp_end_date,\n -- used to correctly calculate range loss of last drive / position before first charging process\n first_value(cp.start_${preferred_range}_range_km) over w as range_before_first_cp,\n first_value(p.odometer) over w as odometer_before_first_cp,\n -- used to correctly calculate range loss of first drive / position after last charging process\n last_value(cp.end_${preferred_range}_range_km) over w as range_after_last_cp,\n -- building \"drives\" by taking total range loss and distance between between charging processes\n lag(cp.end_${preferred_range}_range_km) over w as start_range_km,\n lag(p.odometer) over w as start_odometer,\n case\n when lag(cp.end_${preferred_range}_range_km) over w is null then null\n else cp.start_${preferred_range}_range_km\n end as end_range_km,\n case\n when lag(p.odometer) over w is null then null\n else p.odometer\n end as end_odometer,\n count(start_date) over w as charging_processes_count\n from date_series ds\n left join charging_processes cp on ds.series_id <= cp.start_date and ds.next_series_id >= cp.end_date\n left join positions p on cp.position_id = p.id\n where cp.car_id = $car_id or cp.car_id is null\n window w as (partition by ds.series_id order by cp.start_date rows between unbounded preceding and unbounded following)\n\n),\n\nbuckets_incl_charging_processes as (\n\n select\n series_id,\n next_series_id,\n car_id,\n -- if no charging process occurred, move dates to end of period so that all drives / positions are used\n coalesce(min_cp_start_date, next_series_id) as start_date,\n coalesce(max_cp_end_date, next_series_id) as end_date,\n -- used to correctly calculate range loss of last drive / position before first charging process\n range_before_first_cp,\n odometer_before_first_cp,\n -- used to correctly calculate range loss of first drive / position after last charging process\n range_after_last_cp,\n -- range loss / distance of \"drives\" between charging processes, only available if min. 2 charging processes occurred\n coalesce(sum(start_range_km - end_range_km), 0) as range_loss,\n coalesce(max(end_odometer) - min(start_odometer), 0) as distance\n from buckets_x_charging_processes\n where start_range_km is not null or charging_processes_count < 2\n group by 1, 2, 3, 4, 5, 6, 7, 8\n\n),\n\nbuckets_incl_charging_processes_x_surrounding_data as (\n\n select\n b_incl_cp.*,\n date_trunc('$period', timezone('UTC', series_id)) as date,\n case\n -- if first drive / position after last charging process\n when coalesce(d.start_date, p.\"date\") = first_value(coalesce(d.start_date, p.\"date\")) over w \n and coalesce(d.start_date, p.\"date\") >= b_incl_cp.end_date\n -- use range after last charging process\n then range_after_last_cp\n -- else use (start) range of drive / position\n else coalesce(d.start_${preferred_range}_range_km, p.${preferred_range}_battery_range_km)\n end - coalesce(\n -- subtract (start) range of next drive / position\n lead(coalesce(d.start_${preferred_range}_range_km, p.${preferred_range}_battery_range_km)) over w,\n -- in case of last drive / position before first charging process, use range before charging process\n case\n when coalesce(d.start_date, p.\"date\") < b_incl_cp.start_date\n then range_before_first_cp\n else null\n end\n ) AS range_loss_b_and_a_cp,\n coalesce(\n -- (start) odometer of next drive / position\n lead(coalesce(d.start_km, p.odometer)) over w,\n -- in case of last drive / position before first charging process, use odometer of charging process\n case\n when coalesce(d.start_date, p.\"date\") < b_incl_cp.start_date\n then odometer_before_first_cp\n else null\n end\n ) - coalesce(d.start_km, p.odometer) AS distance_b_and_a_cp\n from buckets_incl_charging_processes b_incl_cp\n left join drives d on\n 0 = $high_precision\n and d.car_id = b_incl_cp.car_id\n and (\n d.start_date >= b_incl_cp.series_id\n and d.end_date < b_incl_cp.start_date\n or d.start_date > b_incl_cp.end_date\n and d.end_date < b_incl_cp.next_series_id\n )\n left join positions p on\n 1 = $high_precision\n and p.ideal_battery_range_km is not null\n and p.car_id = b_incl_cp.car_id\n and (\n p.\"date\" >= b_incl_cp.series_id\n and p.\"date\" < b_incl_cp.start_date\n or p.\"date\" > b_incl_cp.end_date\n and p.\"date\" <= b_incl_cp.next_series_id\n )\n window w as (partition by b_incl_cp.series_id, coalesce(d.start_date, p.\"date\") >= b_incl_cp.end_date ORDER BY coalesce(d.start_date, p.\"date\"))\n \n)\n\nselect\n EXTRACT(EPOCH FROM date)*1000 AS date_from,\n EXTRACT(EPOCH FROM date + interval '1 $period')*1000 AS date_to,\n CASE '$period'\n WHEN 'month' THEN to_char(date, 'YYYY Month')\n WHEN 'year' THEN to_char(date, 'YYYY')\n WHEN 'week' THEN 'week ' || to_char(date, 'WW') || ' starting ' || to_char(date, 'YYYY-MM-DD')\n ELSE to_char(date, 'YYYY-MM-DD')\n END AS display,\n date,\n ((range_loss + coalesce(sum(range_loss_b_and_a_cp), 0)) * c.efficiency * 1000) / nullif(convert_km((distance + coalesce(sum(distance_b_and_a_cp), 0))::numeric, '$length_unit'), 0) as consumption_gross_$length_unit\nfrom buckets_incl_charging_processes_x_surrounding_data\n inner join cars c on car_id = c.id\n where range_loss_b_and_a_cp >= 0 and distance_b_and_a_cp = 0 or distance_b_and_a_cp > 0 or range_loss_b_and_a_cp is null and distance_b_and_a_cp is null\n group by 1, 2, 3, 4, range_loss, distance, c.efficiency\n order by date desc\n",
"refId": "D",
"sql": {
"columns": [
Expand Down
Loading

0 comments on commit a993710

Please sign in to comment.