From 1e9d7f04f363feac578c64fa182674508433671e Mon Sep 17 00:00:00 2001 From: Yingting Chen Date: Thu, 12 Sep 2024 17:14:53 +1200 Subject: [PATCH] feat: change ref update process for admin_bdys --- buildings/reference_data/admin_bdys.py | 122 +++++++++++------- buildings/reference_data/topo50.py | 5 +- .../buildings_reference_select_statements.py | 16 +++ buildings/utilities/database.py | 16 ++- .../functions/suburb_locality.sql | 43 ++++-- .../functions/territorial_authority.sql | 51 +++++--- .../functions/suburb_locality.sql | 4 +- .../functions/territorial_authority.sql | 4 +- .../functions/suburb_locality.sql | 4 +- .../functions/territorial_authority.sql | 4 +- 10 files changed, 179 insertions(+), 90 deletions(-) diff --git a/buildings/reference_data/admin_bdys.py b/buildings/reference_data/admin_bdys.py index a7b6187f..1e5845cf 100644 --- a/buildings/reference_data/admin_bdys.py +++ b/buildings/reference_data/admin_bdys.py @@ -4,7 +4,7 @@ from buildings.sql import buildings_reference_select_statements as reference_select from buildings.utilities import database as db -from qgis.core import QgsVectorLayer +from qgis.core import QgsGeometry, QgsVectorLayer # TODO: review if the filter works LAYERS = { @@ -55,7 +55,7 @@ def current_date(): # todo: add kx_api_key in config # todo: combine suburb_locality- and town city -def update_admin_bdys(kx_api_key, dataset, dbconn): +def update_admin_bdys(kx_api_key, dataset, dbconn: db): # get last update of layer date from log from_var = last_update(dataset) @@ -83,21 +83,19 @@ def update_admin_bdys(kx_api_key, dataset, dbconn): external_id = LAYERS[dataset]["primary_id"] - ids_updates = [] ids_attr_updates = [] - + geoms_diff = [] for feature in layer.getFeatures(): if feature.attribute("__change__") == "DELETE": + geoms_diff.append(feature.geometry()) sql = "SELECT buildings_reference.{}_delete_by_external_id(%s)".format( dataset ) - result = dbconn.execute_no_commit(sql, (feature[external_id],)) - result = result.fetchone() - if result is not None: - ids_updates.append(result[0]) + dbconn.execute_no_commit(sql, (feature[external_id],)) elif feature.attribute("__change__") == "UPDATE": if dataset == "suburb_locality": + # get attribute differences result = dbconn.execute_return( reference_select.suburb_locality_attribute_updates, ( @@ -109,8 +107,21 @@ def update_admin_bdys(kx_api_key, dataset, dbconn): result = result.fetchone() if result is not None: ids_attr_updates.append(result[0]) + + # get geometry differences + result = dbconn.execute_return( + reference_select.suburb_locality_shape_updates, + ( + feature.geometry().asWkt(), + feature[external_id], + ), + ) + result = result.fetchone() + if result is not None: + geoms_diff.append(QgsGeometry.fromWkt(result[0])) + sql = "SELECT buildings_reference.suburb_locality_update_by_external_id(%s, %s, %s, %s)" - result = dbconn.execute_no_commit( + dbconn.execute_no_commit( sql, ( feature[external_id], @@ -119,10 +130,8 @@ def update_admin_bdys(kx_api_key, dataset, dbconn): feature.geometry().asWkt(), ), ) - result = result.fetchone() - if result is not None: - ids_updates.append(result[0]) else: + # get attribute differences result = dbconn.execute_return( reference_select.territorial_authority_attribute_updates, ( @@ -133,8 +142,21 @@ def update_admin_bdys(kx_api_key, dataset, dbconn): result = result.fetchone() if result is not None: ids_attr_updates.append(result[0]) + + # get geometry differences + result = dbconn.execute_return( + reference_select.territorial_authority_shape_updates, + ( + feature.geometry().asWkt(), + feature[external_id], + ), + ) + result = result.fetchone() + if result is not None: + geoms_diff.append(QgsGeometry.fromWkt(result[0])) + sql = "SELECT buildings_reference.territorial_authority_update_by_external_id(%s, %s, %s)" - result = dbconn.execute_no_commit( + dbconn.execute_no_commit( sql, ( feature[external_id], @@ -142,9 +164,6 @@ def update_admin_bdys(kx_api_key, dataset, dbconn): feature.geometry().asWkt(), ), ) - result = result.fetchone() - if result is not None: - ids_updates.append(result[0]) elif feature.attribute("__change__") == "INSERT": # Check if feature is already in reference table @@ -153,42 +172,53 @@ def update_admin_bdys(kx_api_key, dataset, dbconn): (feature[external_id],), ) result = result.fetchone() - if result is None: - if dataset == "suburb_locality": - sql = "SELECT buildings_reference.suburb_locality_insert(%s, %s, %s, %s)" - dbconn.execute_no_commit( - sql, - ( - feature[external_id], - correct_name_format(feature["name"]), - correct_name_format(feature["major_name"]), - feature.geometry().asWkt(), - ), - ) - else: - sql = "SELECT buildings_reference.territorial_authority_insert(%s, %s, %s)" - dbconn.execute_no_commit( - sql, - ( - feature[external_id], - correct_name_format(feature["name"]), - feature.geometry().asWkt(), - ), - ) - print("updated_id {}".format(ids_updates)) - print("updated_attrs {}".format(ids_attr_updates)) - sql = "SELECT buildings_reference.{}_update_building_outlines(%s, %s)".format( + if result is not None: + dbconn.rollback_open_cursor() + raise Exception( + "INSERT type feature exists in buildings db. Please contact devs." + ) + geoms_diff.append(feature.geometry()) + if dataset == "suburb_locality": + sql = ( + "SELECT buildings_reference.suburb_locality_insert(%s, %s, %s, %s)" + ) + dbconn.execute_no_commit( + sql, + ( + feature[external_id], + correct_name_format(feature["name"]), + correct_name_format(feature["major_name"]), + feature.geometry().asWkt(), + ), + ) + else: + sql = "SELECT buildings_reference.territorial_authority_insert(%s, %s, %s)" + dbconn.execute_no_commit( + sql, + ( + feature[external_id], + correct_name_format(feature["name"]), + feature.geometry().asWkt(), + ), + ) + print("updated_attrs: {}".format(ids_attr_updates)) + print("updated_geom: {}".format(len(geoms_diff))) + geom_union = QgsGeometry.unaryUnion(geoms_diff).asWkt() + print(geom_union) + sql = "SELECT buildings_reference.{}_attribute_update_building_outlines(%s)".format( + dataset + ) + dbconn.execute_no_commit(sql, (ids_attr_updates,)) + + sql = "SELECT buildings_reference.{}_geometry_update_building_outlines(%s)".format( dataset ) - dbconn.execute_no_commit(sql, (ids_updates, ids_attr_updates)) + dbconn.execute_no_commit(sql, (geom_union,)) return "updated" def correct_name_format(name): - if name: - if "'" in name: - name = "{}".format(name.replace("'", "''")) - else: + if not name: name = "" return str(name) diff --git a/buildings/reference_data/topo50.py b/buildings/reference_data/topo50.py index 193e8280..cf64248e 100644 --- a/buildings/reference_data/topo50.py +++ b/buildings/reference_data/topo50.py @@ -166,9 +166,6 @@ def update_topo50(kx_api_key, dataset, dbconn): def correct_name_format(name): - if name: - if "'" in name: - name = "{}".format(name.replace("'", "''")) - else: + if not name: name = "" return str(name) diff --git a/buildings/sql/buildings_reference_select_statements.py b/buildings/sql/buildings_reference_select_statements.py index 47815c53..9c1540e9 100644 --- a/buildings/sql/buildings_reference_select_statements.py +++ b/buildings/sql/buildings_reference_select_statements.py @@ -133,6 +133,14 @@ AND NOT (suburb_locality = %s AND town_city = %s) """ +suburb_locality_shape_updates = """ +SELECT ST_AsText( + ST_SymDifference(shape, ST_SetSRID(ST_GeometryFromText(%s), 2193), 0.001) + ) AS diff +FROM buildings_reference.suburb_locality +WHERE external_suburb_locality_id = %s +""" + # territorial Authority territorial_authority_intersect_geom = """ @@ -170,6 +178,14 @@ AND NOT name = %s """ +territorial_authority_shape_updates = """ +SELECT ST_AsText( + ST_SymDifference(shape, ST_SetSRID(ST_GeometryFromText(%s), 2193), 0.001) + ) AS diff +FROM buildings_reference.territorial_authority +WHERE external_territorial_authority_id = %s +""" + # territorial authority grid refresh_ta_grid_view = """ diff --git a/buildings/utilities/database.py b/buildings/utilities/database.py index 53cd2164..0ccd8aae 100644 --- a/buildings/utilities/database.py +++ b/buildings/utilities/database.py @@ -34,7 +34,9 @@ _open_cursor = None try: - _conn = psycopg2.connect(host=_host, port=_port, database=_dbname, user=_user, password=_pw) + _conn = psycopg2.connect( + host=_host, port=_port, database=_dbname, user=_user, password=_pw + ) except psycopg2.DatabaseError as error: _conn = None buildings_warning("Database Error", str(error), "critical") @@ -64,7 +66,9 @@ def connect(): """Connect to DB""" global _conn try: - _conn = psycopg2.connect(host=_host, port=_port, database=_dbname, user=_user, password=_pw) + _conn = psycopg2.connect( + host=_host, port=_port, database=_dbname, user=_user, password=_pw + ) except psycopg2.DatabaseError as error: _conn = None buildings_warning("Database Error", str(error), "critical") @@ -118,7 +122,7 @@ def execute_return(sql, data=None): def execute(sql, data=None): - """ Execute an update or insert statement with no return + """Execute an update or insert statement with no return @param sql: sql statement @type sql: string @@ -144,13 +148,13 @@ def execute_no_commit(sql, data=None): except psycopg2.DatabaseError as error: _conn.rollback() buildings_warning("Database Error", str(error), "critical") - return None + raise error except psycopg2.InterfaceError as error: # Raise the error cursor.close() _conn.rollback() buildings_warning("Interface Error", str(error), "critical") - return None + raise error return cursor @@ -171,7 +175,7 @@ def close_cursor(): def set_uri(): - """ Creates a QgsDataSourceUri with connection + """Creates a QgsDataSourceUri with connection @return: QGIS URI object @rtype: qgis.core.QgsDataSourceUri diff --git a/db/sql/deploy/buildings_reference/functions/suburb_locality.sql b/db/sql/deploy/buildings_reference/functions/suburb_locality.sql index bb34056a..57f6f783 100644 --- a/db/sql/deploy/buildings_reference/functions/suburb_locality.sql +++ b/db/sql/deploy/buildings_reference/functions/suburb_locality.sql @@ -23,8 +23,12 @@ BEGIN; -- params: integer external_suburb_locality_id, varchar suburb_locality, varchar town_city, varchar geometry -- return: integer suburb_locality_id --- suburb_locality_update_building_outlines - -- params: integer[] suburb_locality_id, integer[] suburb_locality_id +-- suburb_locality_attribute_update_building_outlines + -- params: integer[] suburb_locality_id + -- return: integer building_outline_id + +-- suburb_locality_geometry_update_building_outlines + -- params: varchar shape -- return: integer building_outline_id -------------------------------------------- @@ -113,26 +117,39 @@ COMMENT ON FUNCTION buildings_reference.suburb_locality_update_by_external_id(in 'Update suburb_locality table by external id'; --- suburb_locality_update_building_outlines - -- params: integer[] suburb_locality_id, integer[] suburb_locality_id +-- suburb_locality_attribute_update_building_outlines + -- params: integer[] suburb_locality_id -- return: integer building_outline_id -CREATE OR REPLACE FUNCTION buildings_reference.suburb_locality_update_building_outlines(integer[], integer[]) +CREATE OR REPLACE FUNCTION buildings_reference.suburb_locality_attribute_update_building_outlines(integer[]) +RETURNS integer AS +$$ + UPDATE buildings.building_outlines + SET last_modified = NOW() + WHERE suburb_locality_id = ANY($1) + RETURNING building_outline_id; +$$ +LANGUAGE sql VOLATILE; + +COMMENT ON FUNCTION buildings_reference.suburb_locality_attribute_update_building_outlines(integer[]) IS +'Update building_outlines last_modified value as suburb_locality/town_city attributes were updated'; + + +-- suburb_locality_geometry_update_building_outlines + -- params: varchar shape + -- return: integer building_outline_id +CREATE OR REPLACE FUNCTION buildings_reference.suburb_locality_geometry_update_building_outlines(varchar) RETURNS integer AS $$ UPDATE buildings.building_outlines SET suburb_locality_id = buildings_reference.suburb_locality_intersect_polygon(shape), last_modified = NOW() - WHERE ( - suburb_locality_id = ANY($1) - AND suburb_locality_id != buildings_reference.suburb_locality_intersect_polygon(shape) - ) - OR suburb_locality_id = ANY($2) + WHERE ST_Intersects(shape, ST_SetSRID(ST_GeometryFromText($1), 2193)) + AND suburb_locality_id != buildings_reference.suburb_locality_intersect_polygon(shape) RETURNING building_outline_id; $$ LANGUAGE sql VOLATILE; -COMMENT ON FUNCTION buildings_reference.suburb_locality_update_building_outlines(integer[], integer[]) IS -'Update building_outlines suburb_locality_id value using suburb_locality table'; - +COMMENT ON FUNCTION buildings_reference.suburb_locality_geometry_update_building_outlines(varchar) IS +'Update building_outlines suburb_locality_id value where building_outlines intersects with updated suburb_locality'; COMMIT; diff --git a/db/sql/deploy/buildings_reference/functions/territorial_authority.sql b/db/sql/deploy/buildings_reference/functions/territorial_authority.sql index f17fd960..09475f35 100644 --- a/db/sql/deploy/buildings_reference/functions/territorial_authority.sql +++ b/db/sql/deploy/buildings_reference/functions/territorial_authority.sql @@ -27,8 +27,12 @@ BEGIN; -- params: integer external_territorial_authority_id, varchar territorial_authority, varchar geometry -- return: integer territorial_authority_id --- territorial_authority_update_building_outlines - -- params: integer[] territorial_authority_id, integer[] territorial_authority_id +-- territorial_authority_attribute_update_building_outlines + -- params: integer[] territorial_authority_id + -- return: integer building_outline_id + +-- territorial_authority_geometry_update_building_outlines + -- params: varchar shape -- return: integer building_outline_id ---------------------------------------------------------------------------------------------- @@ -83,9 +87,9 @@ LANGUAGE sql VOLATILE; COMMENT ON FUNCTION buildings_reference.territorial_authority_intersect_polygon(geometry) IS 'Return id of territorial authority with most overlap'; -DROP FUNCTION buildings_reference.territorial_auth_delete_areas(); -DROP FUNCTION buildings_reference.territorial_auth_insert_areas(); -DROP FUNCTION buildings_reference.territorial_auth_update_areas(); +DROP FUNCTION IF EXISTS buildings_reference.territorial_auth_delete_areas(); +DROP FUNCTION IF EXISTS buildings_reference.territorial_auth_insert_areas(); +DROP FUNCTION IF EXISTS buildings_reference.territorial_auth_update_areas(); -- territorial_authority_delete_by_external_id @@ -144,26 +148,39 @@ COMMENT ON FUNCTION buildings_reference.territorial_authority_update_by_external 'Update territorial_authority table by external id'; --- territorial_authority_update_building_outlines - -- params: integer[] territorial_authority_id, integer[] territorial_authority_id +-- territorial_authority_attribute_update_building_outlines + -- params: integer[] territorial_authority_id -- return: integer building_outline_id -CREATE OR REPLACE FUNCTION buildings_reference.territorial_authority_update_building_outlines(integer[], integer[]) +CREATE OR REPLACE FUNCTION buildings_reference.territorial_authority_attribute_update_building_outlines(integer[]) RETURNS integer AS $$ UPDATE buildings.building_outlines - SET territorial_authority_id = buildings_reference.territorial_authority_intersect_polygon(shape), - last_modified = NOW() - WHERE ( - territorial_authority_id = ANY($1) - AND territorial_authority_id != buildings_reference.territorial_authority_intersect_polygon(shape) - ) - OR territorial_authority_id = ANY($2) + SET last_modified = NOW() + WHERE territorial_authority_id = ANY($1) RETURNING building_outline_id; $$ LANGUAGE sql VOLATILE; -COMMENT ON FUNCTION buildings_reference.territorial_authority_update_building_outlines(integer[], integer[]) IS -'Update building_outlines territorial_authority_id value using territorial_authority table'; +COMMENT ON FUNCTION buildings_reference.territorial_authority_attribute_update_building_outlines(integer[]) IS +'Update building_outlines last_modified value as territorial_authority attribute was updated'; + + +-- territorial_authority_geometry_update_building_outlines + -- params: varchar shape + -- return: integer building_outline_id +CREATE OR REPLACE FUNCTION buildings_reference.territorial_authority_geometry_update_building_outlines(varchar) +RETURNS integer AS +$$ + UPDATE buildings.building_outlines + SET territorial_authority_id = buildings_reference.territorial_authority_grid_intersect_polygon(shape), + last_modified = NOW() + WHERE ST_Intersects(shape, ST_SetSRID(ST_GeometryFromText($1), 2193)) + AND territorial_authority_id != buildings_reference.territorial_authority_grid_intersect_polygon(shape) + RETURNING building_outline_id; +$$ +LANGUAGE sql VOLATILE; +COMMENT ON FUNCTION buildings_reference.territorial_authority_geometry_update_building_outlines(varchar) IS +'Update building_outlines territorial_authority_id value where building_outlines intersects with updated territorial_authority'; COMMIT; diff --git a/db/sql/revert/buildings_reference/functions/suburb_locality.sql b/db/sql/revert/buildings_reference/functions/suburb_locality.sql index 6611951f..d632d3dc 100644 --- a/db/sql/revert/buildings_reference/functions/suburb_locality.sql +++ b/db/sql/revert/buildings_reference/functions/suburb_locality.sql @@ -45,6 +45,8 @@ DROP FUNCTION IF EXISTS buildings_reference.suburb_locality_insert(integer, varc DROP FUNCTION IF EXISTS buildings_reference.suburb_locality_update_by_external_id(integer, varchar, varchar, varchar); -DROP FUNCTION IF EXISTS buildings_reference.suburb_locality_update_building_outlines(integer[], integer[]); +DROP FUNCTION IF EXISTS buildings_reference.suburb_locality_attribute_update_building_outlines(integer[]); + +DROP FUNCTION IF EXISTS buildings_reference.suburb_locality_geometry_update_building_outlines(varchar); COMMIT; diff --git a/db/sql/revert/buildings_reference/functions/territorial_authority.sql b/db/sql/revert/buildings_reference/functions/territorial_authority.sql index 1420817c..5815bd3e 100644 --- a/db/sql/revert/buildings_reference/functions/territorial_authority.sql +++ b/db/sql/revert/buildings_reference/functions/territorial_authority.sql @@ -8,7 +8,9 @@ DROP FUNCTION IF EXISTS buildings_reference.territorial_authority_insert(integer DROP FUNCTION IF EXISTS buildings_reference.territorial_authority_update_by_external_id(integer, varchar, varchar); -DROP FUNCTION IF EXISTS buildings_reference.territorial_authority_update_building_outlines(integer[], integer[]); +DROP FUNCTION IF EXISTS buildings_reference.territorial_authority_attribute_update_building_outlines(integer[]); + +DROP FUNCTION IF EXISTS buildings_reference.territorial_authority_geometry_update_building_outlines(varchar); ---------------------------------------------------------------------------------------------- -- buildings_reference.territorial_authority && buildings_reference.territorial_authority_grid diff --git a/db/sql/verify/buildings_reference/functions/suburb_locality.sql b/db/sql/verify/buildings_reference/functions/suburb_locality.sql index 02829e04..797dc234 100644 --- a/db/sql/verify/buildings_reference/functions/suburb_locality.sql +++ b/db/sql/verify/buildings_reference/functions/suburb_locality.sql @@ -10,6 +10,8 @@ SELECT has_function_privilege('buildings_reference.suburb_locality_insert(intege SELECT has_function_privilege('buildings_reference.suburb_locality_update_by_external_id(integer, varchar, varchar, varchar)', 'execute'); -SELECT has_function_privilege('buildings_reference.suburb_locality_update_building_outlines(integer[], integer[])', 'execute'); +SELECT has_function_privilege('buildings_reference.suburb_locality_attribute_update_building_outlines(integer[])', 'execute'); + +SELECT has_function_privilege('buildings_reference.suburb_locality_geometry_update_building_outlines(varchar)', 'execute'); ROLLBACK; diff --git a/db/sql/verify/buildings_reference/functions/territorial_authority.sql b/db/sql/verify/buildings_reference/functions/territorial_authority.sql index b2789c36..9fc9891d 100644 --- a/db/sql/verify/buildings_reference/functions/territorial_authority.sql +++ b/db/sql/verify/buildings_reference/functions/territorial_authority.sql @@ -12,7 +12,9 @@ SELECT has_function_privilege('buildings_reference.territorial_authority_insert( SELECT has_function_privilege('buildings_reference.territorial_authority_update_by_external_id(integer, varchar, varchar)', 'execute'); -SELECT has_function_privilege('buildings_reference.territorial_authority_update_building_outlines(integer[], integer[])', 'execute'); +SELECT has_function_privilege('buildings_reference.territorial_authority_attribute_update_building_outlines(integer[])', 'execute'); + +SELECT has_function_privilege('buildings_reference.territorial_authority_geometry_update_building_outlines(varchar)', 'execute'); DO $$ BEGIN