mirror of
https://github.com/SyncrowIOT/data.git
synced 2025-11-26 07:24:55 +00:00
new tables
This commit is contained in:
@ -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
|
||||
Reference in New Issue
Block a user