Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

1149 add geojson export to ecocounter open data #1151

Merged
merged 4 commits into from
Feb 19, 2025
Merged
Show file tree
Hide file tree
Changes from 3 commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
40 changes: 17 additions & 23 deletions dags/ecocounter_open_data.py
Original file line number Diff line number Diff line change
Expand Up @@ -35,6 +35,12 @@
README_PATH = os.path.join(repo_path, 'volumes/ecocounter/readme.md')
DOC_MD = get_readme_docmd(README_PATH, DAG_NAME)
EXPORT_PATH = '/home/airflow/open_data/permanent-bike-counters' #'/data/open_data/permanent-bike-counters'
BASH_ENV = {
'HOST': '{{ conn.ecocounter_bot.host }}',
'LOGIN': '{{ conn.ecocounter_bot.login }}',
'PGPASSWORD': '{{ conn.ecocounter_bot.password }}',
'EXPORT_PATH': EXPORT_PATH
}

default_args = {
'owner': ','.join(DAG_OWNERS),
Expand Down Expand Up @@ -132,14 +138,7 @@ def insert_15min(yr):
)
return t.execute(context=context)

@task.bash(
env = {
'HOST': '{{ conn.ecocounter_bot.host }}',
'LOGIN': '{{ conn.ecocounter_bot.login }}',
'PGPASSWORD': '{{ conn.ecocounter_bot.password }}',
'EXPORT_PATH': EXPORT_PATH
}
)
@task.bash(env = BASH_ENV)
def download_daily_open_data()->str:
return '''/usr/bin/psql -h $HOST -U $LOGIN -d bigdata -c \
"SELECT
Expand All @@ -151,12 +150,7 @@ def download_daily_open_data()->str:
--csv -o "$EXPORT_PATH/cycling_permanent_counts_daily.csv"'''

@task.bash(
env = {
'HOST': '{{ conn.ecocounter_bot.host }}',
'LOGIN': '{{ conn.ecocounter_bot.login }}',
'PGPASSWORD': '{{ conn.ecocounter_bot.password }}',
'EXPORT_PATH': EXPORT_PATH
},
env = BASH_ENV,
map_index_template="{{ yr }}"
)
def download_15min_open_data(yr)->str:
Expand All @@ -175,14 +169,7 @@ def download_15min_open_data(yr)->str:
insert_daily(yr) >> download_daily_open_data()
insert_15min(yr) >> download_15min_open_data(yr)

@task.bash(
env = {
'HOST': '{{ conn.ecocounter_bot.host }}',
'LOGIN': '{{ conn.ecocounter_bot.login }}',
'PGPASSWORD': '{{ conn.ecocounter_bot.password }}',
'EXPORT_PATH': EXPORT_PATH
}
)
@task.bash(env = BASH_ENV)
def download_locations_open_data()->str:
return '''/usr/bin/psql -h $HOST -U $LOGIN -d bigdata -c \
"SELECT location_dir_id, location_name, direction, linear_name_full, side_street,
Expand All @@ -191,7 +178,13 @@ def download_locations_open_data()->str:
FROM open_data.cycling_permanent_counts_locations
ORDER BY location_dir_id;" \
--csv -o "$EXPORT_PATH/cycling_permanent_counts_locations.csv"'''


@task.bash(env = BASH_ENV)
def download_locations_open_data_geojson()->str:
return '''/usr/bin/psql -h $HOST -U $LOGIN -d bigdata -c \
"SELECT featurecollection FROM open_data.cycling_permanent_counts_locations_geojson;" \
--tuples-only -o "$EXPORT_PATH/cycling_permanent_counts_locations.geojson"'''

@task.bash()
def output_readme()->str:
source='/home/airflow/data_scripts/volumes/open_data/sql/cycling_permanent_counts_readme.md'
Expand Down Expand Up @@ -220,6 +213,7 @@ def status_message(ds = None, **context):
update_locations >> [
insert_and_download_data.expand(yr = yrs),
download_locations_open_data(),
download_locations_open_data_geojson(),
output_readme()
] >>
status_message()
Expand Down
Original file line number Diff line number Diff line change
@@ -0,0 +1,39 @@
CREATE OR REPLACE VIEW open_data.cycling_permanent_counts_locations_geojson AS
WITH features AS (
SELECT
json_build_object(
'type', 'Feature',
'id', location_dir_id,
'geometry', st_asgeojson(st_setsrid(st_makepoint(longitude, latitude), 4326))::jsonb,
'attributes', json_build_object(
'location_dir_id', location_dir_id,
'location_name', location_name,
'direction', direction,
'linear_name_full', linear_name_full,
'side_street', side_street,
'centreline_id', centreline_id,
'bin_size', bin_size,
'latest_calibration_study', latest_calibration_study,
'first_active', first_active,
'last_active', last_active,
'date_decommissioned', date_decommissioned,
'technology', technology
)
) AS features
FROM open_data.cycling_permanent_counts_locations
)

--aggregate features into FeatureCollection
SELECT
json_build_object(
'type',
'FeatureCollection',
'features',
json_agg(features.features)
) AS featurecollection
FROM features;

ALTER VIEW open_data.cycling_permanent_counts_locations_geojson OWNER TO od_admins;

GRANT SELECT ON open_data.cycling_permanent_counts_locations_geojson TO ecocounter_bot;
GRANT SELECT ON open_data.cycling_permanent_counts_locations_geojson TO bdit_humans;