Skip to content

Commit

Permalink
Merge pull request #51 from nihar1024/main
Browse files Browse the repository at this point in the history
Implement heatmap gravity access-to-areas, allow case-insensitive column name search
  • Loading branch information
nihar1024 authored Oct 24, 2024
2 parents c60a159 + 95b5c94 commit d8be568
Show file tree
Hide file tree
Showing 4 changed files with 90 additions and 41 deletions.
40 changes: 23 additions & 17 deletions src/crud/crud_heatmap_gravity.py
Original file line number Diff line number Diff line change
Expand Up @@ -61,11 +61,12 @@ async def create_distributed_opportunity_table(
)

# Create distributed point table using sql
potential_column = (
1
if not layer["layer"].destination_potential_column
else layer["layer"].destination_potential_column
)
potential_column = layer["layer"].destination_potential_column
if layer["layer"].destination_potential_column == "$area":
potential_column = "'ST_Area(geom::geography)'"
elif not potential_column:
potential_column = 1

await self.async_session.execute(
f"""SELECT basic.create_heatmap_gravity_opportunity_table(
{layer["layer"].opportunity_layer_project_id},
Expand All @@ -81,6 +82,7 @@ async def create_distributed_opportunity_table(
'{layer["where_query"].replace("'", "''")}',
'{temp_points}',
{TRAVELTIME_MATRIX_RESOLUTION[routing_type]},
{layer["geom_type"] == FeatureGeometryType.polygon},
{append_to_existing}
)"""
)
Expand Down Expand Up @@ -131,19 +133,23 @@ def build_query(

query = f"""
INSERT INTO {result_table} (layer_id, geom, text_attr1, float_attr1)
SELECT '{result_layer_id}', ST_SetSRID(h3_cell_to_boundary(dest_id.value)::geometry, 4326), dest_id.value,
SELECT '{result_layer_id}', ST_SetSRID(h3_cell_to_boundary(dest_id)::geometry, 4326), dest_id,
{impedance_function} AS accessibility
FROM
(
SELECT matrix.orig_id, matrix.dest_id, CAST(matrix.traveltime AS float) AS traveltime,
opportunity.sensitivity, opportunity.potential
FROM {opportunity_table} opportunity, {TRAVELTIME_MATRIX_TABLE[params.routing_type]} matrix
WHERE matrix.h3_3 = opportunity.h3_3
AND matrix.orig_id = opportunity.h3_index
AND matrix.traveltime <= opportunity.max_traveltime
) sub_matrix
JOIN LATERAL UNNEST(sub_matrix.dest_id) dest_id(value) ON TRUE
GROUP BY dest_id.value;
FROM (
SELECT opportunity_id, dest_id.value AS dest_id, min(traveltime) AS traveltime, sensitivity, potential
FROM
(
SELECT opportunity.id AS opportunity_id, matrix.orig_id, matrix.dest_id, CAST(matrix.traveltime AS float) AS traveltime,
opportunity.sensitivity, opportunity.potential
FROM {opportunity_table} opportunity, {TRAVELTIME_MATRIX_TABLE[params.routing_type]} matrix
WHERE matrix.h3_3 = opportunity.h3_3
AND matrix.orig_id = opportunity.h3_index
AND matrix.traveltime <= opportunity.max_traveltime
) sub_matrix
JOIN LATERAL UNNEST(sub_matrix.dest_id) dest_id(value) ON TRUE
GROUP BY opportunity_id, dest_id.value, sensitivity, potential
) grouped_opportunities
GROUP BY dest_id;
"""

return query
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -3,12 +3,13 @@ CREATE OR REPLACE FUNCTION basic.create_heatmap_gravity_opportunity_table(
input_layer_project_id int, input_table text, customer_schema text, scenario_id text,
geofence_table text, geofence_where_filter text, geofence_buffer_dist float,
max_traveltime int, sensitivity float, potential_column text, where_filter text,
result_table_name text, grid_resolution int, append_existing boolean
result_table_name text, grid_resolution int, is_area_based boolean, append_existing boolean
)
RETURNS SETOF void
LANGUAGE plpgsql
AS $function$
DECLARE
temp_opportunities_table TEXT;
base_query TEXT;
BEGIN
IF NOT append_existing THEN
Expand All @@ -34,32 +35,68 @@ BEGIN
RAISE EXCEPTION 'Unsupported grid resolution specified';
END IF;

-- Produce h3 grid at specified resolution while applying a scenario if specified
base_query := format(
-- Create a temporary table containing opportunities after applying scenarios
SELECT 'temporal.opportunities_' || basic.uuid_generate_v7() INTO temp_opportunities_table;
EXECUTE format(
'
CREATE TABLE %I AS
WITH scenario_features AS (
SELECT sf.feature_id AS id, sf.geom, sf.edit_type, %s AS potential
FROM %s.scenario_scenario_feature ssf
INNER JOIN %s.scenario_feature sf ON sf.id = ssf.scenario_feature_id
WHERE ssf.scenario_id = %L
AND sf.layer_project_id = %s
)
SELECT of.id, geom, %s AS potential
FROM (SELECT * FROM %s WHERE %s) of
LEFT JOIN (SELECT id FROM scenario_features) sf ON of.id = sf.id
WHERE sf.id IS NULL
UNION ALL
SELECT id, geom, potential
FROM scenario_features
WHERE edit_type IN (''n'', ''m'');
',
temp_opportunities_table, potential_column, customer_schema, customer_schema,
scenario_id, input_layer_project_id, potential_column, input_table, where_filter
);

-- Produce h3 grid at specified resolution
IF NOT is_area_based THEN
base_query := format(
'INSERT INTO %s
SELECT id, h3_lat_lng_to_cell(input_features.geom::point, %s) AS h3_index, %s AS max_traveltime, %s AS sensitivity,
potential, basic.to_short_h3_3(h3_lat_lng_to_cell(input_features.geom::point, 3)::bigint) AS h3_3
SELECT
id,
h3_lat_lng_to_cell(input_features.geom::point, %s) AS h3_index,
%s AS max_traveltime,
%s AS sensitivity,
potential,
basic.to_short_h3_3(h3_lat_lng_to_cell(input_features.geom::point, 3)::bigint) AS h3_3
FROM (
WITH scenario_features AS (
SELECT sf.feature_id AS id, sf.geom, sf.edit_type, %s AS potential
FROM %s.scenario_scenario_feature ssf
INNER JOIN %s.scenario_feature sf ON sf.id = ssf.scenario_feature_id
WHERE ssf.scenario_id = %L
AND sf.layer_project_id = %s
)
SELECT original_features.id, original_features.geom, %s AS potential
FROM (SELECT * FROM %s WHERE %s) original_features
LEFT JOIN scenario_features ON original_features.id = scenario_features.id
WHERE scenario_features.id IS NULL
UNION ALL
SELECT scenario_features.id, scenario_features.geom, scenario_features.potential
FROM scenario_features
WHERE edit_type IN (''n'', ''m'')
SELECT *
FROM %I
) input_features',
result_table_name, grid_resolution, max_traveltime, sensitivity,
potential_column, customer_schema, customer_schema, scenario_id,
input_layer_project_id, potential_column, input_table, where_filter
temp_opportunities_table
);
ELSE
base_query := format(
'INSERT INTO %s
SELECT
DISTINCT ON (id, h3_lat_lng_to_cell(input_features.geom::point, %s))
id,
h3_lat_lng_to_cell(input_features.geom::point, %s) AS h3_index,
%s AS max_traveltime,
%s AS sensitivity,
potential,
basic.to_short_h3_3(h3_lat_lng_to_cell(input_features.geom::point, 3)::bigint) AS h3_3
FROM (
SELECT id, (ST_DumpPoints(ST_Boundary(geom))).geom AS geom, potential
FROM %I
) input_features',
result_table_name, grid_resolution, grid_resolution, max_traveltime,
sensitivity, temp_opportunities_table
);
END IF;

-- Append geofence check if required
IF geofence_table IS NOT NULL THEN
Expand All @@ -79,6 +116,12 @@ BEGIN
EXECUTE format('CREATE INDEX ON %s (h3_index, h3_3);', result_table_name);
END IF;

-- Cleanup
EXECUTE format(
'DROP TABLE IF EXISTS %I;',
temp_opportunities_table
);

END;
$function$
PARALLEL SAFE;
3 changes: 1 addition & 2 deletions src/schemas/heatmap.py
Original file line number Diff line number Diff line change
Expand Up @@ -9,7 +9,6 @@
from src.schemas.layer import ToolType
from src.schemas.toolbox_base import (
DefaultResultLayerName,
input_layer_type_point,
input_layer_type_point_polygon,
input_layer_type_polygon,
)
Expand Down Expand Up @@ -160,7 +159,7 @@ def validate_max_traveltime(routing_type, values):
@property
def input_layer_types(self):
return {
"opportunity_layer_project_id": input_layer_type_point,
"opportunity_layer_project_id": input_layer_type_point_polygon,
"opportunity_geofence_layer_project_id": input_layer_type_polygon,
}

Expand Down
1 change: 1 addition & 0 deletions src/utils.py
Original file line number Diff line number Diff line change
Expand Up @@ -473,6 +473,7 @@ def build_where(id: UUID, table_name: str, query: str | dict, attribute_mapping:
r"(ST_GeomFromWKB\((.*?)\))", r"ST_SetSRID(\1, 4326)", converted_cql
)
where = where + converted_cql
where = where.replace("LIKE", "ILIKE")
return where


Expand Down

0 comments on commit d8be568

Please sign in to comment.