Skip to content

Commit fb0ee0c

Browse files
committed
Updated the insterted_hours method
1 parent 9a9f3cf commit fb0ee0c

File tree

3 files changed

+54
-5
lines changed

3 files changed

+54
-5
lines changed

check.py

+4-1
Original file line numberDiff line numberDiff line change
@@ -82,9 +82,12 @@
8282

8383
from ingest.lcs import (
8484
load_metadata,
85+
load_metadata_batch,
86+
)
87+
88+
from ingest.lcsV2 import (
8589
load_measurements,
8690
load_measurements_batch,
87-
load_metadata_batch,
8891
)
8992

9093
from ingest.fetch import (

ingest/etl_process_measurements.sql

+23-1
Original file line numberDiff line numberDiff line change
@@ -53,7 +53,7 @@ FROM staging_measurements;
5353
-- this is a short term fix
5454
-- a long term fix would not allow duplicate source_id's
5555
WITH staged_sensors AS (
56-
-- this first part signficantly speeds it up on slow machines
56+
-- this first part significantly speeds it up on slow machines
5757
SELECT DISTINCT ingest_id
5858
FROM staging_measurements
5959
), ranked_sensors AS (
@@ -377,6 +377,28 @@ SET datetime_last = GREATEST(sensors_rollup.datetime_last, EXCLUDED.datetime_las
377377
SET modified_on = now();
378378

379379

380+
381+
WITH inserted_hours AS (
382+
-- first we group things, adding an hour to make it time-ending after truncating
383+
SELECT datetime + '1h'::interval as datetime
384+
, utc_offset(datetime + '1h'::interval, tz.tzid) as tz_offset
385+
FROM measurements m
386+
JOIN sensors s ON (s.sensors_id = m.sensors_id)
387+
JOIN sensor_systems sy ON (s.sensor_systems_id = sy.sensor_systems_id)
388+
JOIN sensor_nodes sn ON (sy.sensor_nodes_id = sn.sensor_nodes_id)
389+
JOIN timezones tz ON (sn.timezones_id = tz.timezones_id)
390+
WHERE m.added_on > now() - '1h'::interval
391+
GROUP BY 1, 2
392+
)
393+
INSERT INTO hourly_data_queue (datetime, tz_offset)
394+
SELECT as_utc_hour(datetime, tz_offset), tz_offset
395+
FROM inserted_hours
396+
GROUP BY 1, 2
397+
ON CONFLICT (datetime, tz_offset) DO UPDATE
398+
SET modified_on = now();
399+
400+
401+
380402
--Update the export queue/logs to export these records
381403
--wrap it in a block just in case the database does not have this module installed
382404
--we subtract the second because the data is assumed to be time ending

ingest/lcs_meas_ingest.sql

+27-3
Original file line numberDiff line numberDiff line change
@@ -47,17 +47,41 @@ INTO __total_measurements
4747
FROM meas;
4848

4949

50+
-- -- The ranking is to deal with the current possibility
51+
-- -- that duplicate sensors with the same ingest/source id are created
52+
-- -- this is a short term fix
53+
-- -- a long term fix would not allow duplicate source_id's
54+
-- WITH ranked_sensors AS (
55+
-- SELECT s.sensors_id
56+
-- , s.source_id
57+
-- , RANK() OVER (PARTITION BY s.source_id ORDER BY added_on ASC) as rnk
58+
-- FROM sensors s
59+
-- JOIN meas m ON (s.source_id = m.ingest_id)
60+
-- WHERE s.is_active
61+
-- ), active_sensors AS (
62+
-- SELECT source_id
63+
-- , sensors_id
64+
-- FROM ranked_sensors
65+
-- WHERE rnk = 1)
66+
-- UPDATE meas
67+
-- SET sensors_id=s.sensors_id
68+
-- FROM active_sensors s
69+
-- WHERE s.source_id=ingest_id;
70+
5071
-- The ranking is to deal with the current possibility
5172
-- that duplicate sensors with the same ingest/source id are created
5273
-- this is a short term fix
5374
-- a long term fix would not allow duplicate source_id's
54-
WITH ranked_sensors AS (
75+
WITH staged_sensors AS (
76+
-- this first part signficantly speeds it up on slow machines
77+
SELECT DISTINCT ingest_id
78+
FROM meas
79+
), ranked_sensors AS (
5580
SELECT s.sensors_id
5681
, s.source_id
5782
, RANK() OVER (PARTITION BY s.source_id ORDER BY added_on ASC) as rnk
5883
FROM sensors s
59-
JOIN meas m ON (s.source_id = m.ingest_id)
60-
WHERE s.is_active
84+
JOIN staged_sensors m ON (s.source_id = m.ingest_id)
6185
), active_sensors AS (
6286
SELECT source_id
6387
, sensors_id

0 commit comments

Comments
 (0)