Skip to content

Commit

Permalink
updates timezone data (#23)
Browse files Browse the repository at this point in the history
  • Loading branch information
russbiggs authored May 10, 2024
1 parent 2e5351a commit f8d80ce
Show file tree
Hide file tree
Showing 14 changed files with 36 additions and 28 deletions.
12 changes: 6 additions & 6 deletions openaqdb/idempotent/exports_views.sql
Original file line number Diff line number Diff line change
Expand Up @@ -43,8 +43,8 @@ JOIN measurands p ON (s.measurands_id = p.measurands_id)
JOIN sensor_systems ss ON (s.sensor_systems_id = ss.sensor_systems_id)
JOIN sensor_nodes sn ON (ss.sensor_nodes_id = sn.sensor_nodes_id)
JOIN providers pr ON (sn.source_name = pr.source_name)
JOIN timezones t ON (sn.timezones_id = t.gid)
WHERE t.gid IS NOT NULL
JOIN timezones t ON (sn.timezones_id = t.timezones_id)
WHERE t.timezones_id IS NOT NULL
-- once we have versioning we can uncomment this line
--AND s.sensors_id NOT IN (SELECT sensors_id FROM versions)
;
Expand Down Expand Up @@ -121,7 +121,7 @@ SELECT l.sensor_nodes_id
, utc_offset(tz.tzid) as utc_offset
FROM public.open_data_export_logs l
JOIN public.sensor_nodes sn ON (l.sensor_nodes_id = sn.sensor_nodes_id)
JOIN public.timezones tz ON (sn.timezones_id = tz.gid)
JOIN public.timezones tz ON (sn.timezones_id = tz.timezones_id)
WHERE
-- older than 72 hours to give us time to collect data
day < (now() AT TIME ZONE tz.tzid - '72hours'::interval)::date
Expand All @@ -142,7 +142,7 @@ SELECT
, COUNT(1) as n
FROM public.open_data_export_logs l
JOIN public.sensor_nodes sn ON (l.sensor_nodes_id = sn.sensor_nodes_id)
JOIN public.timezones tz ON (sn.timezones_id = tz.gid)
JOIN public.timezones tz ON (sn.timezones_id = tz.timezones_id)
GROUP BY 1,2,3,4
ORDER BY 1,2,3,4;

Expand Down Expand Up @@ -312,8 +312,8 @@ COMMIT;
-- JOIN sensor_systems ss ON (s.sensor_systems_id = ss.sensor_systems_id)
-- JOIN sensor_nodes sn ON (ss.sensor_nodes_id = sn.sensor_nodes_id)
-- JOIN providers pr ON (sn.source_name = pr.source_name)
-- JOIN timezones t ON (sn.timezones_id = t.gid)
-- WHERE t.gid IS NOT NULL;
-- JOIN timezones t ON (sn.timezones_id = t.timezones_id)
-- WHERE t.timezones_id IS NOT NULL;

-- \timing on

Expand Down
4 changes: 2 additions & 2 deletions openaqdb/idempotent/util_functions.sql
Original file line number Diff line number Diff line change
Expand Up @@ -108,14 +108,14 @@ $$ LANGUAGE SQL IMMUTABLE STRICT PARALLEL SAFE;
CREATE OR REPLACE FUNCTION utc_offset(dt timestamptz, sn int) RETURNS interval AS $$
SELECT utc_offset(dt, t.tzid)
FROM sensor_nodes n
JOIN timezones t ON (t.gid = n.timezones_id)
JOIN timezones t ON (t.timezones_id = n.timezones_id)
WHERE sensor_nodes_id = sn;
$$ LANGUAGE SQL IMMUTABLE STRICT PARALLEL SAFE;

CREATE OR REPLACE FUNCTION utc_offset(sn int) RETURNS interval AS $$
SELECT utc_offset(t.tzid)
FROM sensor_nodes n
JOIN timezones t ON (t.gid = n.timezones_id)
JOIN timezones t ON (t.timezones_id = n.timezones_id)
WHERE sensor_nodes_id = sn;
$$ LANGUAGE SQL IMMUTABLE STRICT PARALLEL SAFE;

Expand Down
2 changes: 1 addition & 1 deletion openaqdb/idempotent/views.sql
Original file line number Diff line number Diff line change
Expand Up @@ -643,7 +643,7 @@ SELECT sn.sensor_nodes_id
, s.added_on as sensor_added_on
, sn.added_on as node_added_on
FROM sensor_nodes sn
LEFT JOIN timezones tz ON (sn.timezones_id = tz.gid)
LEFT JOIN timezones tz ON (sn.timezones_id = tz.timezones_id)
LEFT JOIN providers p ON (sn.providers_id = p.providers_id)
LEFT JOIN sensor_systems sy USING (sensor_nodes_id)
LEFT JOIN sensors s USING (sensor_systems_id)
Expand Down
4 changes: 2 additions & 2 deletions openaqdb/import_sensors.sql
Original file line number Diff line number Diff line change
Expand Up @@ -41,7 +41,7 @@ GROUP BY 1;

CREATE TABLE IF NOT EXISTS sensor_nodes_migrate (
sensor_nodes_id int primary key,
timezones_id int REFERENCES timezones(gid),
timezones_id int REFERENCES timezones(timezones_id),
ismobile boolean,
geom geometry,
site_name text,
Expand Down Expand Up @@ -217,7 +217,7 @@ SELECT n.sensor_nodes_id
, s.source_id
, n.site_name
, st_setsrid(st_makepoint(lon,lat), 4326)
, t.gid
, t.timezones_id
, n.origin
, CASE WHEN lon IS NULL THEN true ELSE false END
, json_build_object('imported', 'production')
Expand Down
2 changes: 1 addition & 1 deletion openaqdb/init.sh
Original file line number Diff line number Diff line change
Expand Up @@ -43,7 +43,7 @@ psql --single-transaction -v ON_ERROR_STOP=1 -f lookups/measurands_map.sql
psql --single-transaction -v ON_ERROR_STOP=1 -f lookups/thresholds.sql
psql --single-transaction -v ON_ERROR_STOP=1 -f lookups/thresholds.sql
gunzip -c lookups/countries.tsv.gz | psql --single-transaction -v ON_ERROR_STOP=1 -c "copy countries from stdin"
gunzip -c lookups/timezones.tsv.gz | psql --single-transaction -v ON_ERROR_STOP=1 -c "copy timezones from stdin"
gunzip -c lookups/timezones.csv.gz | psql --single-transaction -v ON_ERROR_STOP=1 -c "copy timezones (tzid, geog) from stdin DELIMITER ',' CSV HEADER"
gunzip -c lookups/providers_data.csv.gz | psql --single-transaction -v ON_ERROR_STOP=1 -c "COPY providers (providers_id,label,description,source_name,export_prefix,license,metadata,owner_entities_id) FROM stdin DELIMITER ',' CSV HEADER"
gunzip -c lookups/sources_from_openaq.tsv.gz | psql --single-transaction -v ON_ERROR_STOP=1 -c "copy sources_from_openaq from stdin"

Expand Down
2 changes: 1 addition & 1 deletion openaqdb/locations/locations.sql
Original file line number Diff line number Diff line change
Expand Up @@ -109,7 +109,7 @@ SELECT
, pl.licenses
, l.providers_id
FROM sensor_nodes l
JOIN timezones t ON (l.timezones_id = t.gid)
JOIN timezones t ON (l.timezones_id = t.timezones_id)
JOIN countries c ON (c.countries_id = l.countries_id)
JOIN entities oc ON (oc.entities_id = l.owner_entities_id)
JOIN providers p ON (p.providers_id = l.providers_id)
Expand Down
Binary file not shown.
2 changes: 1 addition & 1 deletion openaqdb/metadata_transfer.sql
Original file line number Diff line number Diff line change
Expand Up @@ -107,7 +107,7 @@ LIMIT 10;

-- move the timezone data from the metadata to the timezones_id field
UPDATE sensor_nodes
SET timezones_id = t.gid
SET timezones_id = t.timezones_id
FROM timezones t
WHERE sensor_nodes.metadata->>'timezone' IS NOT NULL
AND sensor_nodes.metadata->>'timezone' = t.tzid
Expand Down
6 changes: 3 additions & 3 deletions openaqdb/tables/daily_data_rollups.sql
Original file line number Diff line number Diff line change
Expand Up @@ -103,7 +103,7 @@ FROM hourly_data m
JOIN sensors s ON (m.sensors_id = s.sensors_id)
JOIN sensor_systems sy ON (s.sensor_systems_id = sy.sensor_systems_id)
JOIN sensor_nodes sn ON (sy.sensor_nodes_id = sn.sensor_nodes_id)
JOIN timezones t ON (sn.timezones_id = t.gid)
JOIN timezones t ON (sn.timezones_id = t.timezones_id)
WHERE value_count > 0
AND datetime > as_utc(sd, t.tzid)
AND datetime <= as_utc(ed, t.tzid)
Expand Down Expand Up @@ -153,7 +153,7 @@ FROM hourly_data m
JOIN sensors s ON (m.sensors_id = s.sensors_id)
JOIN sensor_systems sy ON (s.sensor_systems_id = sy.sensor_systems_id)
JOIN sensor_nodes sn ON (sy.sensor_nodes_id = sn.sensor_nodes_id)
JOIN timezones t ON (sn.timezones_id = t.gid)
JOIN timezones t ON (sn.timezones_id = t.timezones_id)
WHERE value_count > 0
AND datetime > as_utc(dy, t.tzid)
AND datetime <= as_utc(dy + 1, t.tzid)
Expand Down Expand Up @@ -271,7 +271,7 @@ FROM hourly_data m
JOIN sensors s ON (m.sensors_id = s.sensors_id)
JOIN sensor_systems sy ON (s.sensor_systems_id = sy.sensor_systems_id)
JOIN sensor_nodes sn ON (sy.sensor_nodes_id = sn.sensor_nodes_id)
JOIN timezones t ON (sn.timezones_id = t.gid)
JOIN timezones t ON (sn.timezones_id = t.timezones_id)
WHERE value_count > 0
AND datetime > as_utc(sd, t.tzid)
AND datetime <= as_utc(ed, t.tzid)
Expand Down
2 changes: 1 addition & 1 deletion openaqdb/tables/daily_data_rollups_check.sql
Original file line number Diff line number Diff line change
Expand Up @@ -51,7 +51,7 @@ SELECT m.sensors_id
JOIN sensors s ON (m.sensors_id = s.sensors_id)
JOIN sensor_systems sy ON (s.sensor_systems_id = sy.sensor_systems_id)
JOIN sensor_nodes sn ON (sy.sensor_nodes_id = sn.sensor_nodes_id)
JOIN timezones t ON (sn.timezones_id = t.gid)
JOIN timezones t ON (sn.timezones_id = t.timezones_id)
WHERE m.sensors_id = :sensor
AND datetime > :day::timestamptz - :hr::interval
AND datetime <= (:day::date + 1)::timestamptz - :hr::interval
Expand Down
2 changes: 1 addition & 1 deletion openaqdb/tables/metadata.sql
Original file line number Diff line number Diff line change
Expand Up @@ -33,7 +33,7 @@ BEGIN
ALTER TABLE sensor_nodes
ADD COLUMN added_on timestamptz DEFAULT now(),
ADD COLUMN modified_on timestamptz,
ADD COLUMN timezones_id int REFERENCES timezones(gid);
ADD COLUMN timezones_id int REFERENCES timezones(timezones_id);
EXCEPTION WHEN OTHERS THEN
RAISE NOTICE 'sensors alter error';
--END;
Expand Down
2 changes: 1 addition & 1 deletion openaqdb/tables/timezones.sql
Original file line number Diff line number Diff line change
@@ -1,5 +1,5 @@
CREATE TABLE IF NOT EXISTS timezones (
gid integer primary key,
timezones_id int generated always as identity primary key,
tzid text,
geog geography
);
Expand Down
16 changes: 8 additions & 8 deletions openaqdb/tables/timezones_views.sql
Original file line number Diff line number Diff line change
Expand Up @@ -3,7 +3,7 @@ RETURNS text LANGUAGE sql IMMUTABLE STRICT PARALLEL SAFE AS $$
SELECT tzid
FROM timezones
WHERE st_intersects(g, geog)
ORDER BY gid ASC
ORDER BY timezones_id ASC
LIMIT 1;
$$;

Expand All @@ -12,22 +12,22 @@ RETURNS text LANGUAGE sql IMMUTABLE STRICT PARALLEL SAFE AS $$
SELECT tzid
FROM timezones
WHERE st_intersects(g::geography, geog)
ORDER BY gid ASC
ORDER BY timezones_id ASC
LIMIT 1;
$$;

CREATE OR REPLACE FUNCTION get_timezones_id(g geometry)
RETURNS int LANGUAGE sql IMMUTABLE STRICT PARALLEL SAFE AS $$
SELECT gid
SELECT timezones_id
FROM timezones
WHERE st_intersects(g::geography, geog)
ORDER BY gid ASC
ORDER BY timezones_id ASC
LIMIT 1;
$$;

CREATE OR REPLACE FUNCTION get_timezones_id(tz text)
RETURNS int LANGUAGE sql IMMUTABLE STRICT PARALLEL SAFE AS $$
SELECT gid
SELECT timezones_id
FROM timezones
WHERE lower(tzid) = lower(tz)
LIMIT 1;
Expand All @@ -44,9 +44,9 @@ WHERE added_on > current_date
LIMIT 2)
SELECT n.sensor_nodes_id
, n.geom
, gid
, n.timezones_id
, tzid
, timezones_id
, timezones.timezones_id
, st_area(geog::geometry)
, st_xmin(geog::geometry)
, st_xmax(geog::geometry)
Expand All @@ -56,7 +56,7 @@ LIMIT 2)
WHERE st_intersects(geom::geography, geog);


SELECT gid
SELECT timezones_id
, tzid
, substring(st_astext(geog) from 0 for 100)
, substring(st_astext(geog::geometry) from 0 for 100)
Expand Down
8 changes: 8 additions & 0 deletions scripts/tz_data.sh
Original file line number Diff line number Diff line change
@@ -0,0 +1,8 @@
#!/bin/bash

wget https://github.com/evansiroky/timezone-boundary-builder/releases/download/2024a/timezones-with-oceans.geojson.zip
unzip timezones-with-oceans.geojson.zip
ogr2ogr -f CSV timezones.csv combined-with-oceans.json -dialect SQLite -sql "SELECT tzid, 'SRID=4326;' || ST_AsText(geometry) AS geog FROM combined-with-oceans"
gzip -c timezones.csv > timezones.csv.gz


0 comments on commit f8d80ce

Please sign in to comment.