From 6ccf225dff198046d58e3fa89a35c9b46a527450 Mon Sep 17 00:00:00 2001 From: Juan Carlos Heredia Date: Fri, 16 Jun 2023 00:00:55 +0200 Subject: [PATCH] Improve query to avoid nulls when there are no long charging sessions --- grafana/dashboards/battery-health.json | 36 ++++++++++++++++---------- 1 file changed, 22 insertions(+), 14 deletions(-) diff --git a/grafana/dashboards/battery-health.json b/grafana/dashboards/battery-health.json index a905db7616..10c3d39cbb 100644 --- a/grafana/dashboards/battery-health.json +++ b/grafana/dashboards/battery-health.json @@ -17,7 +17,7 @@ "type": "grafana", "id": "grafana", "name": "Grafana", - "version": "8.5.15" + "version": "8.5.26" }, { "type": "panel", @@ -70,7 +70,7 @@ "fiscalYearStartMonth": 0, "graphTooltip": 1, "id": null, - "iteration": 1681675288666, + "iteration": 1686866079807, "links": [ { "icon": "dashboard", @@ -97,7 +97,7 @@ "type": "postgres", "uid": "TeslaMate" }, - "description": "**Usable (now)** is the estimated current battery capacity. \n\n**Usable (new)** is the estimated Battery Capacity since you begun to use Teslamate. That's why, the more data you have logged from your brand new car the better. ", + "description": "**Usable (now)** is the estimated current battery capacity.\n\nIf you see just '1.0 kWh' here, it means that you need at least a long charge session on the lasth month.\n\n**Usable (new)** is the estimated Battery Capacity since you begun to use Teslamate. That's why, the more data you have logged from your brand new car the better. ", "fieldConfig": { "defaults": { "color": { @@ -111,6 +111,14 @@ { "color": "super-light-blue", "value": null + }, + { + "color": "dark-red", + "value": 1 + }, + { + "color": "super-light-blue", + "value": 2 } ] }, @@ -139,7 +147,7 @@ }, "textMode": "value_and_name" }, - "pluginVersion": "8.5.15", + "pluginVersion": "8.5.26", "targets": [ { "datasource": { @@ -284,7 +292,7 @@ }, "textMode": "value_and_name" }, - "pluginVersion": "8.5.15", + "pluginVersion": "8.5.26", "targets": [ { "datasource": { @@ -367,7 +375,7 @@ }, "textMode": "value_and_name" }, - "pluginVersion": "8.5.15", + "pluginVersion": "8.5.26", "targets": [ { "datasource": { @@ -501,7 +509,7 @@ }, "textMode": "value_and_name" }, - "pluginVersion": "8.5.15", + "pluginVersion": "8.5.26", "targets": [ { "datasource": { @@ -629,7 +637,7 @@ "showThresholdLabels": false, "showThresholdMarkers": true }, - "pluginVersion": "8.5.15", + "pluginVersion": "8.5.26", "targets": [ { "datasource": { @@ -724,7 +732,7 @@ }, "showUnfilled": true }, - "pluginVersion": "8.5.15", + "pluginVersion": "8.5.26", "targets": [ { "datasource": { @@ -807,7 +815,7 @@ }, "textMode": "value_and_name" }, - "pluginVersion": "8.5.15", + "pluginVersion": "8.5.26", "targets": [ { "datasource": { @@ -1030,7 +1038,7 @@ "showUnfilled": true, "text": {} }, - "pluginVersion": "8.5.15", + "pluginVersion": "8.5.26", "targets": [ { "datasource": { @@ -1147,7 +1155,7 @@ "showUnfilled": true, "text": {} }, - "pluginVersion": "8.5.15", + "pluginVersion": "8.5.26", "targets": [ { "datasource": { @@ -1488,13 +1496,13 @@ "type": "postgres", "uid": "TeslaMate" }, - "definition": "-- CONCATENATED JOIN QUERIES TO IMPROVE PERFORMANCE\nWITH\naux\tAS\n(\n\tSELECT cp.charge_energy_added,\n\t\tcp.car_id, (SELECT efficiency FROM cars WHERE cp.car_id = $car_id) * 100.0 AS rated_efficiency,\n\t\t(cp.end_rated_range_km - cp.start_rated_range_km) AS added_range_km\n\tFROM charging_processes cp\n\t\tJOIN (SELECT charging_process_id, MAX(date) as date\n\t\tFROM charges\n\t\tGROUP BY charging_process_id) AS last_charges\n\t\tON cp.id = last_charges.charging_process_id\n\t\tINNER JOIN charges c\n\t\tON c.charging_process_id = cp.id AND c.date = last_charges.date\n\tWHERE cp.car_id = $car_id\n\t\tAND cp.end_date IS NOT NULL\n\t\tAND cp.end_rated_range_km > cp.start_rated_range_km\n\tORDER BY cp.end_date DESC \n\tLIMIT 1\n), \nCurrentCapacity\t AS\n(\n\tSELECT AVG(Capacity) AS CurrentCapacity FROM\n (SELECT (100.0 * cp.charge_energy_added) / (GREATEST(1,MAX(usable_battery_level) - MIN(usable_battery_level))) AS Capacity\t\n FROM charging_processes cp\n\t INNER JOIN charges c\tON cp.id = c.charging_process_id\n INNER JOIN aux ON cp.car_id = aux.car_id\n\t WHERE cp.car_id = $car_id AND cp.charge_energy_added >= aux.rated_efficiency AND cp.end_date >= date_trunc('month', current_date - interval '1 month') \n GROUP BY cp.charge_energy_added, cp.end_date\n ) AS lastEstimatedCapacity\n), \nMaxCapacity AS\n(\n\tSELECT MAX(c.rated_battery_range_km * cars.efficiency * 100.0 / c.usable_battery_level) AS MaxCapacity\n\tFROM charging_processes cp\n\t\tJOIN (SELECT charging_process_id, MAX(date) as date\n\t\tFROM charges\n\t\tGROUP BY charging_process_id) AS last_charges\n\t\tON cp.id = last_charges.charging_process_id\n\t\tINNER JOIN charges c\n\t\tON c.charging_process_id = cp.id AND c.date = last_charges.date\n\t\tINNER JOIN cars ON cp.car_id = cars.id\n\tWHERE cp.car_id = $car_id\n\t\tAND cp.end_date IS NOT NULL\n\t\tAND cp.end_rated_range_km > cp.start_rated_range_km\n\t\tAND c.charge_energy_added >= cars. Efficiency\n), \nCurrentRange AS\n(\n SELECT\n\t\tfloor(extract(epoch from date)/86400)*86400 AS timecurrent,\n\t\tsum(rated_battery_range_km) / sum(usable_battery_level) * 100 AS rated_range_km\n\tFROM (\n\t\tSELECT battery_level, usable_battery_level, date, rated_battery_range_km from charges c \n\t\tJOIN charging_processes p ON p.id = c.charging_process_id \n\t\tWHERE p.car_id = $car_id AND usable_battery_level IS NOT NULL) AS data\n\tGROUP BY 1\n\tORDER BY 1 DESC\n\tLIMIT 1\n), \nMaxRange AS\n(\n SELECT\n\t\tfloor(extract(epoch from date)/86400)*86400 AS time,\n\t\tsum(rated_battery_range_km) / sum(usable_battery_level) * 100 AS max_rated_range_km\n\tFROM (\n\t\tSELECT battery_level, usable_battery_level, date, rated_battery_range_km from charges c \n\t\tJOIN charging_processes p ON p.id = c.charging_process_id \n\t\tWHERE p.car_id = $car_id AND usable_battery_level IS NOT NULL) AS data\n\tGROUP BY 1\n\tORDER BY 2 DESC\n\tLIMIT 1\n) \nSELECT CONCAT('{\"LastChargekWhAdded\": ', aux.charge_energy_added, \n ', \"LastMileageAdded\" : ', convert_km(aux.added_range_km,'$length_unit'),\n ', \"MaxRange\": ', convert_km(MaxRange.max_rated_range_km,'$length_unit'),\n ', \"CurrentRange\": ',convert_km(CurrentRange.rated_range_km,'$length_unit'),\n ', \"MaxCapacity\": ', MaxCapacity.MaxCapacity,\n ', \"CurrentCapacity\": ',CurrentCapacity.CurrentCapacity,\n ', \"RatedEfficiency\": ',aux.rated_efficiency, '}') \nFROM MaxRange, CurrentRange, Aux, MaxCapacity, CurrentCapacity;\n-- The following query is the result of many tests and hours of work. This panel is for your own personal use. \n-- If you think you can improve it and contribute, please create a pull request and do not take it to your repository, \n-- much less upload it to another repository as if the original idea were yours, nor do you share it on social media\n-- without mentioning the author. Respect the ingenuity and work of others. Cheers!\n-- 16/04/2023\n-- By @jheredianet - Twitter: @juanheredia", + "definition": "-- CONCATENATED JOIN QUERIES TO IMPROVE PERFORMANCE\n-- The following query is the result of many tests and hours of work. This panel is for your own personal use. \n-- If you think you can improve it and contribute, please create a pull request and do not take it to your repository, \n-- much less upload it to another repository as if the original idea were yours, nor do you share it on social media\n-- without mentioning the author. Respect the ingenuity and work of others. Cheers!\n-- 16/04/2023\n-- By @jheredianet - Twitter: @juanheredia", "hide": 2, "includeAll": false, "multi": false, "name": "aux", "options": [], - "query": "-- CONCATENATED JOIN QUERIES TO IMPROVE PERFORMANCE\nWITH\naux\tAS\n(\n\tSELECT cp.charge_energy_added,\n\t\tcp.car_id, (SELECT efficiency FROM cars WHERE cp.car_id = $car_id) * 100.0 AS rated_efficiency,\n\t\t(cp.end_rated_range_km - cp.start_rated_range_km) AS added_range_km\n\tFROM charging_processes cp\n\t\tJOIN (SELECT charging_process_id, MAX(date) as date\n\t\tFROM charges\n\t\tGROUP BY charging_process_id) AS last_charges\n\t\tON cp.id = last_charges.charging_process_id\n\t\tINNER JOIN charges c\n\t\tON c.charging_process_id = cp.id AND c.date = last_charges.date\n\tWHERE cp.car_id = $car_id\n\t\tAND cp.end_date IS NOT NULL\n\t\tAND cp.end_rated_range_km > cp.start_rated_range_km\n\tORDER BY cp.end_date DESC \n\tLIMIT 1\n), \nCurrentCapacity\t AS\n(\n\tSELECT AVG(Capacity) AS CurrentCapacity FROM\n (SELECT (100.0 * cp.charge_energy_added) / (GREATEST(1,MAX(usable_battery_level) - MIN(usable_battery_level))) AS Capacity\t\n FROM charging_processes cp\n\t INNER JOIN charges c\tON cp.id = c.charging_process_id\n INNER JOIN aux ON cp.car_id = aux.car_id\n\t WHERE cp.car_id = $car_id AND cp.charge_energy_added >= aux.rated_efficiency AND cp.end_date >= date_trunc('month', current_date - interval '1 month') \n GROUP BY cp.charge_energy_added, cp.end_date\n ) AS lastEstimatedCapacity\n), \nMaxCapacity AS\n(\n\tSELECT MAX(c.rated_battery_range_km * cars.efficiency * 100.0 / c.usable_battery_level) AS MaxCapacity\n\tFROM charging_processes cp\n\t\tJOIN (SELECT charging_process_id, MAX(date) as date\n\t\tFROM charges\n\t\tGROUP BY charging_process_id) AS last_charges\n\t\tON cp.id = last_charges.charging_process_id\n\t\tINNER JOIN charges c\n\t\tON c.charging_process_id = cp.id AND c.date = last_charges.date\n\t\tINNER JOIN cars ON cp.car_id = cars.id\n\tWHERE cp.car_id = $car_id\n\t\tAND cp.end_date IS NOT NULL\n\t\tAND cp.end_rated_range_km > cp.start_rated_range_km\n\t\tAND c.charge_energy_added >= cars. Efficiency\n), \nCurrentRange AS\n(\n SELECT\n\t\tfloor(extract(epoch from date)/86400)*86400 AS timecurrent,\n\t\tsum(rated_battery_range_km) / sum(usable_battery_level) * 100 AS rated_range_km\n\tFROM (\n\t\tSELECT battery_level, usable_battery_level, date, rated_battery_range_km from charges c \n\t\tJOIN charging_processes p ON p.id = c.charging_process_id \n\t\tWHERE p.car_id = $car_id AND usable_battery_level IS NOT NULL) AS data\n\tGROUP BY 1\n\tORDER BY 1 DESC\n\tLIMIT 1\n), \nMaxRange AS\n(\n SELECT\n\t\tfloor(extract(epoch from date)/86400)*86400 AS time,\n\t\tsum(rated_battery_range_km) / sum(usable_battery_level) * 100 AS max_rated_range_km\n\tFROM (\n\t\tSELECT battery_level, usable_battery_level, date, rated_battery_range_km from charges c \n\t\tJOIN charging_processes p ON p.id = c.charging_process_id \n\t\tWHERE p.car_id = $car_id AND usable_battery_level IS NOT NULL) AS data\n\tGROUP BY 1\n\tORDER BY 2 DESC\n\tLIMIT 1\n) \nSELECT CONCAT('{\"LastChargekWhAdded\": ', aux.charge_energy_added, \n ', \"LastMileageAdded\" : ', convert_km(aux.added_range_km,'$length_unit'),\n ', \"MaxRange\": ', convert_km(MaxRange.max_rated_range_km,'$length_unit'),\n ', \"CurrentRange\": ',convert_km(CurrentRange.rated_range_km,'$length_unit'),\n ', \"MaxCapacity\": ', MaxCapacity.MaxCapacity,\n ', \"CurrentCapacity\": ',CurrentCapacity.CurrentCapacity,\n ', \"RatedEfficiency\": ',aux.rated_efficiency, '}') \nFROM MaxRange, CurrentRange, Aux, MaxCapacity, CurrentCapacity;\n-- The following query is the result of many tests and hours of work. This panel is for your own personal use. \n-- If you think you can improve it and contribute, please create a pull request and do not take it to your repository, \n-- much less upload it to another repository as if the original idea were yours, nor do you share it on social media\n-- without mentioning the author. Respect the ingenuity and work of others. Cheers!\n-- 16/04/2023\n-- By @jheredianet - Twitter: @juanheredia", + "query": "WITH\naux\tAS\n(\n\tSELECT cp.charge_energy_added,\n\t\tcp.car_id, (SELECT efficiency FROM cars WHERE id = $car_id) * 100.0 AS rated_efficiency,\n\t\t(cp.end_rated_range_km - cp.start_rated_range_km) AS added_range_km\n\tFROM charging_processes cp\n\t\tJOIN (SELECT charging_process_id, MAX(date) as date\n\t\tFROM charges\n\t\tGROUP BY charging_process_id) AS last_charges\n\t\tON cp.id = last_charges.charging_process_id\n\t\tINNER JOIN charges c\n\t\tON c.charging_process_id = cp.id AND c.date = last_charges.date\n\tWHERE cp.car_id = $car_id\n\t\tAND cp.end_date IS NOT NULL\n\t\tAND cp.end_rated_range_km > cp.start_rated_range_km\n\tORDER BY cp.end_date DESC \n\tLIMIT 1\n), \nCurrentCapacity\t AS\n(\n\tSELECT AVG(Capacity) AS CurrentCapacity FROM\n (SELECT (100.0 * cp.charge_energy_added) / (GREATEST(1,MAX(usable_battery_level) - MIN(usable_battery_level))) AS Capacity\t\n FROM charging_processes cp\n\t INNER JOIN charges c\tON cp.id = c.charging_process_id\n INNER JOIN aux ON cp.car_id = aux.car_id\n\t WHERE cp.car_id = $car_id AND cp.charge_energy_added >= aux.rated_efficiency AND cp.end_date >= date_trunc('month', current_date - interval '1 month') \n GROUP BY cp.charge_energy_added, cp.end_date\n ) AS lastEstimatedCapacity\n), \nMaxCapacity AS\n(\n\tSELECT MAX(c.rated_battery_range_km * cars.efficiency * 100.0 / c.usable_battery_level) AS MaxCapacity\n\tFROM charging_processes cp\n\t\tJOIN (SELECT charging_process_id, MAX(date) as date\n\t\tFROM charges\n\t\tGROUP BY charging_process_id) AS last_charges\n\t\tON cp.id = last_charges.charging_process_id\n\t\tINNER JOIN charges c\n\t\tON c.charging_process_id = cp.id AND c.date = last_charges.date\n\t\tINNER JOIN cars ON cp.car_id = cars.id\n\tWHERE cp.car_id = $car_id\n\t\tAND cp.end_date IS NOT NULL\n\t\tAND cp.end_rated_range_km > cp.start_rated_range_km\n\t\tAND c.charge_energy_added >= cars. Efficiency\n), \nCurrentRange AS\n(\n SELECT\n\t\tfloor(extract(epoch from date)/86400)*86400 AS timecurrent,\n\t\tsum(rated_battery_range_km) / sum(usable_battery_level) * 100 AS rated_range_km\n\tFROM (\n\t\tSELECT battery_level, usable_battery_level, date, rated_battery_range_km from charges c \n\t\tJOIN charging_processes p ON p.id = c.charging_process_id \n\t\tWHERE p.car_id = $car_id AND usable_battery_level IS NOT NULL) AS data\n\tGROUP BY 1\n\tORDER BY 1 DESC\n\tLIMIT 1\n), \nMaxRange AS\n(\n SELECT\n\t\tfloor(extract(epoch from date)/86400)*86400 AS time,\n\t\tsum(rated_battery_range_km) / sum(usable_battery_level) * 100 AS max_rated_range_km\n\tFROM (\n\t\tSELECT battery_level, usable_battery_level, date, rated_battery_range_km from charges c \n\t\tJOIN charging_processes p ON p.id = c.charging_process_id \n\t\tWHERE p.car_id = $car_id AND usable_battery_level IS NOT NULL) AS data\n\tGROUP BY 1\n\tORDER BY 2 DESC\n\tLIMIT 1\n) \nSELECT CONCAT('{\"LastChargekWhAdded\": ', aux.charge_energy_added, \n ', \"LastMileageAdded\" : ', convert_km(aux.added_range_km,'$length_unit'),\n ', \"MaxRange\": ', convert_km(MaxRange.max_rated_range_km,'$length_unit'),\n ', \"CurrentRange\": ',convert_km(CurrentRange.rated_range_km,'$length_unit'),\n ', \"MaxCapacity\": ', MaxCapacity.MaxCapacity,\n ', \"CurrentCapacity\": ', CASE WHEN CurrentCapacity.CurrentCapacity IS NULL THEN 1 ELSE CurrentCapacity.CurrentCapacity END,\n ', \"RatedEfficiency\": ',aux.rated_efficiency, '}') \nFROM MaxRange, CurrentRange, Aux, MaxCapacity, CurrentCapacity;", "refresh": 1, "regex": "", "skipUrlSync": false,