From 303ea696cbdec8e2041c92ae27943278fc442d0b Mon Sep 17 00:00:00 2001 From: faris Aljohari <83524184+farisaljohari@users.noreply.github.com> Date: Mon, 14 Apr 2025 13:47:32 +0300 Subject: [PATCH] Add SQL queries for device logs, energy consumption, presence detection, and product category definitions --- .../device_logs_clean/device_logs_clean.sql | 12 ++ .../src/sql/queries/dim_date/dim_date.sql | 5 + .../fact_daily_device_presence_duration.sql | 66 +++++++++++ .../fact_daily_energy_consumed.sql | 0 .../fact_daily_space_presence_duration.sql | 91 +++++++++++++++ .../fact_device_user_permission.sql | 15 +++ .../fact_hourly_device_presence_detected.sql | 72 ++++++++++++ ...act_hourly_space_temperature_balancing.sql | 78 +++++++++++++ .../fact_presence_state_timestamp.sql | 44 ++++++++ .../product_category_code_definition.csv | 104 ++++++++++++++++++ 10 files changed, 487 insertions(+) create mode 100644 libs/common/src/sql/queries/device_logs_clean/device_logs_clean.sql create mode 100644 libs/common/src/sql/queries/dim_date/dim_date.sql create mode 100644 libs/common/src/sql/queries/fact_daily_device_presence_duration/fact_daily_device_presence_duration.sql rename libs/common/src/sql/queries/{power-clamp => fact_daily_energy_consumed}/fact_daily_energy_consumed.sql (100%) create mode 100644 libs/common/src/sql/queries/fact_daily_space_presence_duration/fact_daily_space_presence_duration.sql create mode 100644 libs/common/src/sql/queries/fact_device_user_permission/fact_device_user_permission.sql create mode 100644 libs/common/src/sql/queries/fact_hourly_device_presence_detected/fact_hourly_device_presence_detected.sql create mode 100644 libs/common/src/sql/queries/fact_hourly_space_temperature_balancing/fact_hourly_space_temperature_balancing.sql create mode 100644 libs/common/src/sql/queries/fact_presence_state_timestamp/fact_presence_state_timestamp.sql create mode 100644 libs/common/src/sql/queries/seed files/product_category_code_definition.csv diff --git a/libs/common/src/sql/queries/device_logs_clean/device_logs_clean.sql b/libs/common/src/sql/queries/device_logs_clean/device_logs_clean.sql new file mode 100644 index 0000000..6175ccb --- /dev/null +++ b/libs/common/src/sql/queries/device_logs_clean/device_logs_clean.sql @@ -0,0 +1,12 @@ +select device_id , +product."name" as "device_type", +event_time::date as date , +event_time::time as time, +code , +value +from "device-status-log" dsl +join product + on dsl.product_id = product.prod_id +join device d + on d."uuid" = dsl.device_id +order by 1,3,4 \ No newline at end of file diff --git a/libs/common/src/sql/queries/dim_date/dim_date.sql b/libs/common/src/sql/queries/dim_date/dim_date.sql new file mode 100644 index 0000000..4f25c21 --- /dev/null +++ b/libs/common/src/sql/queries/dim_date/dim_date.sql @@ -0,0 +1,5 @@ + SELECT generate_series( + DATE '2024-01-01', -- Start date + DATE '2065-12-31', -- End date + INTERVAL '1 day' -- Step size + )::DATE AS daily_date; \ No newline at end of file diff --git a/libs/common/src/sql/queries/fact_daily_device_presence_duration/fact_daily_device_presence_duration.sql b/libs/common/src/sql/queries/fact_daily_device_presence_duration/fact_daily_device_presence_duration.sql new file mode 100644 index 0000000..1bcec42 --- /dev/null +++ b/libs/common/src/sql/queries/fact_daily_device_presence_duration/fact_daily_device_presence_duration.sql @@ -0,0 +1,66 @@ +WITH start_date AS ( + SELECT + device.uuid AS device_id, + device.created_at, + device.device_tuya_uuid, + device.space_device_uuid AS space_id, + "device-status-log".event_id, + "device-status-log".event_time::timestamp, + "device-status-log".code, + "device-status-log".value, + "device-status-log".log, + LAG("device-status-log".event_time::timestamp) + OVER (PARTITION BY device.uuid -- Partition only by device.uuid + ORDER BY "device-status-log".event_time) AS prev_timestamp, + LAG("device-status-log".value) + OVER (PARTITION BY device.uuid + ORDER BY "device-status-log".event_time) AS prev_value + FROM device + LEFT JOIN "device-status-log" + ON device.uuid = "device-status-log".device_id + LEFT JOIN product + ON product.uuid = device.product_device_uuid + WHERE product.cat_name = 'hps' + AND "device-status-log".code = 'presence_state' + ORDER BY device.uuid, "device-status-log".event_time +), + +time_differences AS ( + SELECT + device_id, + value, + prev_value, + event_time, + prev_timestamp, + event_time::date AS event_date, + EXTRACT(EPOCH FROM (event_time - COALESCE(prev_timestamp, event_time))) AS time_diff_in_seconds + FROM start_date +), + + +duration as ( +SELECT + device_id, + event_date, + SUM(CASE WHEN prev_value = 'motion' THEN time_diff_in_seconds ELSE 0 END) AS motion_seconds, + SUM(CASE WHEN prev_value = 'presence' THEN time_diff_in_seconds ELSE 0 END) AS presence_seconds, + SUM(CASE WHEN prev_value = 'none' THEN time_diff_in_seconds ELSE 0 END) AS none_seconds +FROM time_differences +WHERE prev_timestamp::date=event_date +GROUP BY device_id, event_date +ORDER BY device_id, event_date) + + +, data_final AS( +select device_id, + event_date, + motion_seconds, + CONCAT(FLOOR(motion_seconds / 3600), ':',LPAD(FLOOR((motion_seconds % 3600) / 60)::TEXT, 2, '0'), ':',LPAD(FLOOR(motion_seconds % 60)::TEXT, 2, '0')) AS motion_formatted_duration, + presence_seconds, + CONCAT(FLOOR(presence_seconds / 3600), ':',LPAD(FLOOR((presence_seconds % 3600) / 60)::TEXT, 2, '0'), ':',LPAD(FLOOR(presence_seconds % 60)::TEXT, 2, '0')) AS presence_formatted_duration, + none_seconds, + CONCAT(FLOOR(none_seconds / 3600), ':',LPAD(FLOOR((none_seconds % 3600) / 60)::TEXT, 2, '0'), ':',LPAD(FLOOR(none_seconds % 60)::TEXT, 2, '0')) AS none_formatted_duration +from duration +order by 1,2) + +SELECT * FROM data_final diff --git a/libs/common/src/sql/queries/power-clamp/fact_daily_energy_consumed.sql b/libs/common/src/sql/queries/fact_daily_energy_consumed/fact_daily_energy_consumed.sql similarity index 100% rename from libs/common/src/sql/queries/power-clamp/fact_daily_energy_consumed.sql rename to libs/common/src/sql/queries/fact_daily_energy_consumed/fact_daily_energy_consumed.sql diff --git a/libs/common/src/sql/queries/fact_daily_space_presence_duration/fact_daily_space_presence_duration.sql b/libs/common/src/sql/queries/fact_daily_space_presence_duration/fact_daily_space_presence_duration.sql new file mode 100644 index 0000000..5b2b68d --- /dev/null +++ b/libs/common/src/sql/queries/fact_daily_space_presence_duration/fact_daily_space_presence_duration.sql @@ -0,0 +1,91 @@ +-- Step 1: Get device presence events with previous timestamps +WITH start_date AS ( + SELECT + d.uuid AS device_id, + d.space_device_uuid AS space_id, + l.value, + l.event_time::timestamp AS event_time, + LAG(l.event_time::timestamp) OVER (PARTITION BY d.uuid ORDER BY l.event_time) AS prev_timestamp + FROM device d + LEFT JOIN "device-status-log" l + ON d.uuid = l.device_id + LEFT JOIN product p + ON p.uuid = d.product_device_uuid + WHERE p.cat_name = 'hps' + AND l.code = 'presence_state' +), + +-- Step 2: Identify periods when device reports "none" +device_none_periods AS ( + SELECT + space_id, + device_id, + event_time AS empty_from, + LEAD(event_time) OVER (PARTITION BY device_id ORDER BY event_time) AS empty_until + FROM start_date + WHERE value = 'none' +), + +-- Step 3: Clip the "none" periods to the edges of each day +clipped_device_none_periods AS ( + SELECT + space_id, + GREATEST(empty_from, DATE_TRUNC('day', empty_from)) AS clipped_from, + LEAST(empty_until, DATE_TRUNC('day', empty_until) + INTERVAL '1 day') AS clipped_until + FROM device_none_periods + WHERE empty_until IS NOT NULL +), + +-- Step 4: Break multi-day periods into daily intervals +generated_daily_intervals AS ( + SELECT + space_id, + gs::date AS day, + GREATEST(clipped_from, gs) AS interval_start, + LEAST(clipped_until, gs + INTERVAL '1 day') AS interval_end + FROM clipped_device_none_periods, + LATERAL generate_series(DATE_TRUNC('day', clipped_from), DATE_TRUNC('day', clipped_until), INTERVAL '1 day') AS gs +), + +-- Step 5: Merge overlapping or adjacent intervals per day +merged_intervals AS ( + SELECT + space_id, + day, + interval_start, + interval_end + FROM ( + SELECT + space_id, + day, + interval_start, + interval_end, + LAG(interval_end) OVER (PARTITION BY space_id, day ORDER BY interval_start) AS prev_end + FROM generated_daily_intervals + ) sub + WHERE prev_end IS NULL OR interval_start > prev_end +), + +-- Step 6: Sum up total missing seconds (device reported "none") per day +missing_seconds_per_day AS ( + SELECT + space_id, + day AS missing_date, + SUM(EXTRACT(EPOCH FROM (interval_end - interval_start))) AS total_missing_seconds + FROM merged_intervals + GROUP BY space_id, day +), + +-- Step 7: Calculate total occupied time per day (86400 - missing) +occupied_seconds_per_day AS ( + SELECT + space_id, + missing_date, + 86400 - total_missing_seconds AS total_occupied_seconds + FROM missing_seconds_per_day +) + +-- Final Output +SELECT * +FROM occupied_seconds_per_day +ORDER BY 1,2; diff --git a/libs/common/src/sql/queries/fact_device_user_permission/fact_device_user_permission.sql b/libs/common/src/sql/queries/fact_device_user_permission/fact_device_user_permission.sql new file mode 100644 index 0000000..a3f7838 --- /dev/null +++ b/libs/common/src/sql/queries/fact_device_user_permission/fact_device_user_permission.sql @@ -0,0 +1,15 @@ +select dup."uuid" as primary_key, +dup.device_uuid, +product.name, +pt.type, +dup.user_uuid as authorized_user_id, +dup.created_at::date as permission_creation_date, +dup.updated_at::date as permission_update_date +from "device-user-permission" dup +left join "permission-type" pt + on dup.permission_type_uuid =pt."uuid" +left join device + on device."uuid" =dup.device_uuid +LEFT JOIN product + ON product.uuid = device.product_device_uuid; + \ No newline at end of file diff --git a/libs/common/src/sql/queries/fact_hourly_device_presence_detected/fact_hourly_device_presence_detected.sql b/libs/common/src/sql/queries/fact_hourly_device_presence_detected/fact_hourly_device_presence_detected.sql new file mode 100644 index 0000000..ed7c30c --- /dev/null +++ b/libs/common/src/sql/queries/fact_hourly_device_presence_detected/fact_hourly_device_presence_detected.sql @@ -0,0 +1,72 @@ +--This model shows the number of times a presence was detected per hour, per day. + + +WITH device_logs AS ( + SELECT + device.uuid AS device_id, + device.created_at, + device.device_tuya_uuid, + device.space_device_uuid AS space_id, + "device-status-log".event_id, + "device-status-log".event_time::timestamp, + "device-status-log".code, + "device-status-log".value, + "device-status-log".log, + LAG("device-status-log".event_time::timestamp) + OVER (PARTITION BY device.uuid + ORDER BY "device-status-log".event_time) AS prev_timestamp, + LAG("device-status-log".value) + OVER (PARTITION BY device.uuid + ORDER BY "device-status-log".event_time) AS prev_value + FROM device + LEFT JOIN "device-status-log" + ON device.uuid = "device-status-log".device_id + LEFT JOIN product + ON product.uuid = device.product_device_uuid + WHERE product.cat_name = 'hps' -- presence sensors + AND "device-status-log".code = 'presence_state' + ORDER BY device.uuid, "device-status-log".event_time +) + +, presence_detection AS ( + SELECT *, + CASE + WHEN value IN ('presence', 'motion') AND prev_value = 'none' THEN 1 -- detects a change in status from no presence to presence or motion + ELSE 0 + END AS presence_detected + FROM device_logs +) + + +, presence_detection_summary AS ( + SELECT device_id, + subspace_id, + space_id, + event_time::date AS event_date, + EXTRACT(HOUR FROM date_trunc('hour', event_time)) AS event_hour, + sum(presence_detected) AS count_presence_detected + FROM presence_detection + LEFT JOIN device + ON device."uuid" = device_id + GROUP BY 1, 2, 3, 4, 5 +) + +-- Generate all 24 hours for each unique event_date +, all_dates_and_hours AS ( + SELECT device_id, subspace_id, space_id, event_date, event_hour + FROM ( + SELECT DISTINCT device_id, subspace_id, space_id, event_date + FROM presence_detection_summary + ) d, + generate_series(0, 23) AS event_hour +) + +SELECT + adah.*, + COALESCE(pds.count_presence_detected, 0) AS count_presence_detected +FROM all_dates_and_hours adah +left JOIN presence_detection_summary pds + ON pds.device_id = adah.device_id + AND pds.event_date = adah.event_date + AND pds.event_hour = adah.event_hour +ORDER BY 1,4,5; \ No newline at end of file diff --git a/libs/common/src/sql/queries/fact_hourly_space_temperature_balancing/fact_hourly_space_temperature_balancing.sql b/libs/common/src/sql/queries/fact_hourly_space_temperature_balancing/fact_hourly_space_temperature_balancing.sql new file mode 100644 index 0000000..d28304a --- /dev/null +++ b/libs/common/src/sql/queries/fact_hourly_space_temperature_balancing/fact_hourly_space_temperature_balancing.sql @@ -0,0 +1,78 @@ +-- This model gives the average hourly set and current temperatures per space, per device +-- The only issue witht this model is that it does not represent 24 hours/device. which is normal when no changelog is being recorded. +--Shall I fill the missing hours +WITH avg_set_temp AS (-- average set temperature per device per hour + SELECT + device.uuid AS device_id, + device.space_device_uuid AS space_id, + event_time::date AS date, + DATE_PART('hour', event_time) AS hour, + AVG("device-status-log".value::INTEGER) AS avg_set_temp + FROM device + LEFT JOIN "device-status-log" + ON device.uuid = "device-status-log".device_id + LEFT JOIN product + ON product.uuid = device.product_device_uuid + WHERE product.name = 'Smart Thermostat' + AND "device-status-log".code = 'temp_set' + GROUP BY 1,2,3,4 +) + +, avg_current_temp as ( + SELECT + device.uuid AS device_id, + device.space_device_uuid AS space_id, + event_time::date AS date, + DATE_PART('hour', event_time) AS hour, + AVG("device-status-log".value::INTEGER) AS avg_current_temp + FROM device + LEFT JOIN "device-status-log" + ON device.uuid = "device-status-log".device_id + LEFT JOIN product + ON product.uuid = device.product_device_uuid + WHERE product.name = 'Smart Thermostat' + AND "device-status-log".code = 'temp_current' + GROUP BY 1,2,3,4 +) + +, joined_data AS ( -- this will return null values for hours where there was no previously set temperature + SELECT + current_temp.device_id, + current_temp.space_id, + current_temp.date, + current_temp.hour, + set_temp.avg_set_temp, + current_temp.avg_current_temp, + ROW_NUMBER() OVER (PARTITION BY current_temp.device_id, current_temp.space_id ORDER BY current_temp.date, current_temp.hour) AS row_num + FROM avg_current_temp AS current_temp + LEFT JOIN avg_set_temp AS set_temp + ON set_temp.device_id = current_temp.device_id + AND set_temp.space_id = current_temp.space_id + AND set_temp.date = current_temp.date + AND set_temp.hour = current_temp.hour +) + +, filled_data AS ( + SELECT + a.device_id, + a.space_id, + a.date, + a.hour, + COALESCE( + a.avg_set_temp, + (SELECT b.avg_set_temp + FROM joined_data b + WHERE b.device_id = a.device_id + AND b.space_id = a.space_id + AND b.row_num < a.row_num + AND b.avg_set_temp IS NOT NULL + ORDER BY b.row_num DESC + LIMIT 1) + ) AS avg_set_temp, + a.avg_current_temp + FROM joined_data a +) + +SELECT * +FROM filled_data +ORDER BY 1,3,4; \ No newline at end of file diff --git a/libs/common/src/sql/queries/fact_presence_state_timestamp/fact_presence_state_timestamp.sql b/libs/common/src/sql/queries/fact_presence_state_timestamp/fact_presence_state_timestamp.sql new file mode 100644 index 0000000..5cf3710 --- /dev/null +++ b/libs/common/src/sql/queries/fact_presence_state_timestamp/fact_presence_state_timestamp.sql @@ -0,0 +1,44 @@ +/* + * This model tracks the timestamp when a presence state went from no-presence --> presence detected, per device. + * This model should be used to display the presence logs Talal requested on the platform + */ + +WITH device_logs AS ( + SELECT + device.uuid AS device_id, + device.created_at, + device.device_tuya_uuid, + device.space_device_uuid AS space_id, + "device-status-log".event_id, + "device-status-log".event_time::timestamp, + "device-status-log".code, + "device-status-log".value, + "device-status-log".log, + LAG("device-status-log".event_time::timestamp) + OVER (PARTITION BY device.uuid + ORDER BY "device-status-log".event_time) AS prev_timestamp, + LAG("device-status-log".value) + OVER (PARTITION BY device.uuid + ORDER BY "device-status-log".event_time) AS prev_value + FROM device + LEFT JOIN "device-status-log" + ON device.uuid = "device-status-log".device_id + LEFT JOIN product + ON product.uuid = device.product_device_uuid + WHERE product.cat_name = 'hps' -- presence sensors + AND "device-status-log".code = 'presence_state' + ORDER BY device.uuid, "device-status-log".event_time +) + +, presence_detection AS ( + SELECT *, + CASE + WHEN value IN ('presence', 'motion') AND prev_value = 'none' THEN 1 -- detects a change in status from no presence to presence or motion + ELSE 0 + END AS presence_detected + FROM device_logs +) + +SELECT event_time as "time_presence_detected", device_id, space_id +FROM presence_detection +WHERE presence_detected=1 \ No newline at end of file diff --git a/libs/common/src/sql/queries/seed files/product_category_code_definition.csv b/libs/common/src/sql/queries/seed files/product_category_code_definition.csv new file mode 100644 index 0000000..155e1ed --- /dev/null +++ b/libs/common/src/sql/queries/seed files/product_category_code_definition.csv @@ -0,0 +1,104 @@ +Category code,Description +dj,Light +xdd,Ceiling light +fwd,Ambiance light +dc,String lights +dd,Strip lights +gyd,Motion sensor light +fsd,Ceiling fan light +tyndj,Solar light +tgq,Dimmer +ykq,Remote control +kg,Switch +pc,Power strip +cz,Socket +cjkg,Scene switch +ckqdkg,Card switch +clkg,Curtain switch +ckmkzq,Garage door opener +tgkg,Dimmer switch +rs,Water heater +xfj,Ventilation system +bx,Refrigerator +yg,Bathtub +xy,Washing machine +kt,Air conditioner +ktkzq,Air conditioner controller +bgl,Wall-hung boiler +sd,Robot vacuum +qn,Heater +kj,Air purifier +lyj,Drying rack +xxj,Diffuser +cl,Curtain +mc,Door/window controller +wk,Thermostat +yb,Bathroom heater +ggq,Irrigator +jsq,Humidifier +cs,Dehumidifier +fs,Fan +js,Water purifier +dr,Electric blanket +cwtswsq,Pet treat feeder +cwwqfsq,Pet ball thrower +ntq,HVAC +cwwsq,Pet feeder +cwysj,Pet fountain +sf,Sofa +dbl,Electric fireplace +tnq,Smart milk kettle +msp,Cat toilet +mjj,Towel rack +sz,Smart indoor garden +bh,Smart kettle +mb,Bread maker +kfj,Coffee maker +nnq,Bottle warmer +cn,Milk dispenser +mzj,Sous vide cooker +mg,Rice cabinet +dcl,Induction cooker +kqzg,Air fryer +znfh,Bento box +mal,Alarm host +sp,Smart camera +sgbj,Siren alarm +zd,Vibration sensor +mcs,Contact sensor +rqbj,Gas alarm +ywbj,Smoke alarm +wsdcg,Temperature and humidity sensor +sj,Water leak detector +ylcg,Pressure sensor +ldcg,Luminance sensor +sos,Emergency button +pm2.5,PM2.5 detector +pir,Human motion sensor +cobj,CO detector +co2bj,CO2 detector +dgnbj,Multi-functional alarm +jwbj,Methane detector +hps,Human presence sensor +ms,Residential lock +bxx,Safe box +gyms,Business lock +jtmspro,Residential lock pro +hotelms,Hotel lock +ms_category,Lock accessories +jtmsbh,Smart lock (keep alive) +mk,Access control +videolock,Lock with camera +photolock,Audio and video lock +amy,Massage chair +liliao,Physiotherapy product +ts,Smart jump rope +tzc1,Body fat scale +sb,Watch/band +zndb,Smart electricity meter +znsb,Smart water meter +dlq,Circuit breaker +ds,TV set +tyy,Projector +tracker,Tracker +znyh,Smart pill box \ No newline at end of file