From a70c6a1495aa2a69c7b71545849e45c02e70ad23 Mon Sep 17 00:00:00 2001 From: Yingting Chen Date: Wed, 11 Sep 2024 18:08:20 +1200 Subject: [PATCH] feat: update processes for update reference via WFS --- buildings/gui/bulk_load_changes.py | 2 +- buildings/gui/production_changes.py | 2 +- buildings/gui/reference_data.py | 141 ++++--------- buildings/reference_data/admin_bdys.py | 194 ++++++++++++++++++ buildings/reference_data/topo50.py | 80 +++++--- .../buildings_reference_select_statements.py | 14 ++ .../tests/gui/test_setup_reference_data.py | 10 - .../functions/reference_update_log.sql | 20 +- .../functions/suburb_locality.sql | 96 +++++++++ .../functions/suburb_locality@v4.0.0-dev1.sql | 42 ++++ .../functions/territorial_authority.sql | 142 ++++++------- .../territorial_authority@v4.0.0-dev1.sql | 169 +++++++++++++++ .../functions/suburb_locality.sql | 122 +---------- .../functions/suburb_locality@v4.0.0-dev1.sql | 160 +++++++++++++++ .../functions/territorial_authority.sql | 18 +- .../territorial_authority@v4.0.0-dev1.sql | 173 ++++++++++++++++ db/sql/sqitch.plan | 2 + .../functions/reference_update_log.sql | 11 + .../functions/suburb_locality.sql | 14 +- .../functions/suburb_locality@v4.0.0-dev1.sql | 21 ++ .../functions/territorial_authority.sql | 36 +++- .../territorial_authority@v4.0.0-dev1.sql | 28 +++ 22 files changed, 1138 insertions(+), 359 deletions(-) create mode 100644 buildings/reference_data/admin_bdys.py create mode 100644 db/sql/deploy/buildings_reference/functions/suburb_locality@v4.0.0-dev1.sql create mode 100644 db/sql/deploy/buildings_reference/functions/territorial_authority@v4.0.0-dev1.sql create mode 100644 db/sql/revert/buildings_reference/functions/suburb_locality@v4.0.0-dev1.sql create mode 100644 db/sql/revert/buildings_reference/functions/territorial_authority@v4.0.0-dev1.sql create mode 100644 db/sql/verify/buildings_reference/functions/suburb_locality@v4.0.0-dev1.sql create mode 100644 db/sql/verify/buildings_reference/functions/territorial_authority@v4.0.0-dev1.sql diff --git a/buildings/gui/bulk_load_changes.py b/buildings/gui/bulk_load_changes.py index 563a1fbb..4c4ab99a 100644 --- a/buildings/gui/bulk_load_changes.py +++ b/buildings/gui/bulk_load_changes.py @@ -77,7 +77,7 @@ def populate_edit_comboboxes(self): ) self.edit_dialog.ids_suburb = [] for (id_suburb, suburb_locality, town_city) in result.fetchall(): - if name is not None: + if suburb_locality is not None: self.edit_dialog.cmb_suburb.addItem(suburb_locality) self.edit_dialog.cmb_town.addItem(town_city) self.edit_dialog.ids_suburb.append(id_suburb) diff --git a/buildings/gui/production_changes.py b/buildings/gui/production_changes.py index 8ff398ee..7ffa0332 100644 --- a/buildings/gui/production_changes.py +++ b/buildings/gui/production_changes.py @@ -91,7 +91,7 @@ def populate_edit_comboboxes(self): ) self.edit_dialog.ids_suburb = [] for (id_suburb, suburb_locality, town_city) in result.fetchall(): - if name is not None: + if suburb_locality is not None: self.edit_dialog.cmb_suburb.addItem(suburb_locality) self.edit_dialog.cmb_town.addItem(town_city) self.edit_dialog.ids_suburb.append(id_suburb) diff --git a/buildings/gui/reference_data.py b/buildings/gui/reference_data.py index 40dd0739..b281ade1 100644 --- a/buildings/gui/reference_data.py +++ b/buildings/gui/reference_data.py @@ -9,7 +9,7 @@ from qgis.PyQt.QtGui import QIcon from buildings.gui.error_dialog import ErrorDialog -from buildings.reference_data import topo50 +from buildings.reference_data import topo50, admin_bdys from buildings.sql import buildings_bulk_load_select_statements as bulk_load_select from buildings.sql import buildings_reference_select_statements as reference_select from buildings.utilities import database as db @@ -29,6 +29,22 @@ os.path.join(os.path.dirname(__file__), "reference_data.ui") ) +DATASET_LINZ = [ + "canal_polygons", + "lagoon_polygons", + "lake_polygons", + "pond_polygons", + "river_polygons", + "swamp_polygons", + "hut_points", + "shelter_points", + "bivouac_points", + "protected_areas_polygons", + "coastlines and islands", + "suburb_locality", +] +DATASET_STATSNZ = ["territorial_authority"] + class UpdateReferenceData(QFrame, FORM_CLASS): def __init__(self, dockwidget, parent=None): @@ -87,7 +103,6 @@ def enable_checkboxes(self): self.chbx_bivouacs.setEnabled(1) self.chbx_protected_areas.setEnabled(1) self.chbx_suburbs.setEnabled(1) - self.chbx_town.setEnabled(1) self.chbx_ta.setEnabled(1) self.btn_update.setEnabled(1) # clear message @@ -109,7 +124,6 @@ def disable_checkboxes(self): self.chbx_bivouacs.setDisabled(1) self.chbx_protected_areas.setDisabled(1) self.chbx_suburbs.setDisabled(1) - self.chbx_town.setDisabled(1) self.chbx_ta.setDisabled(1) self.btn_update.setDisabled(1) # add message @@ -125,6 +139,8 @@ def update_clicked(self, commit_status=True): # setup self.message = "" self.updates = [] + if self.db._open_cursor is None: + self.db.open_cursor() # canals if self.chbx_canals.isChecked(): self.topo_layer_processing("canal_polygons") @@ -158,89 +174,12 @@ def update_clicked(self, commit_status=True): # coastlines and islands (placeholder) if self.chbx_coastline_and_islands.isChecked(): self.message += "The coastlines and islands table must be updated manually" - if self.db._open_cursor is None: - self.db.open_cursor() # suburb localities if self.chbx_suburbs.isChecked(): - # update building_outlines suburb values (changed, deleted & added) - # delete remove suburbs and update modified suburbs - db.execute_no_commit("SELECT buildings_reference.building_outlines_update_changed_and_deleted_suburb();") - # add new suburbs and update building outlines - db.execute_no_commit("SELECT buildings_reference.building_outlines_update_added_suburb();") - # update messages and log - self.update_message("updated", "suburb_locality") - self.updates.append("suburb_locality") - # town_city - if self.chbx_town.isChecked(): - town_list = [] - # delete existing areas where the external id is no longer in the town_city table - result = db.execute_no_commit( - "SELECT buildings_reference.town_city_delete_removed_areas();" - ) - if result is not None: - town_list.extend(result.fetchone()[0]) - # modify all existing areas to check they are up to date - result = db.execute_no_commit( - "SELECT buildings_reference.town_city_insert_new_areas();" - ) - if result is not None: - town_list.extend(result.fetchone()[0]) - # insert into table ids in nz_localities that are not in town_city - result = db.execute_no_commit( - "SELECT buildings_reference.town_city_update_areas();" - ) - if result is not None: - town_list.extend(result.fetchone()[0]) - # update bulk_load_outlines town/city values - db.execute_no_commit( - "SELECT buildings_bulk_load.bulk_load_outlines_update_all_town_cities(%s);", - (town_list,), - ) - # update building outlines town/city values - db.execute_no_commit( - "SELECT buildings.building_outlines_update_town_city(%s);", (town_list,) - ) - # update messages and log - self.update_message("updated", "town_city") - self.updates.append("town_city") + self.admin_bdy_layer_processing("suburb_locality") # territorial authority and grid if self.chbx_ta.isChecked(): - ta_list = [] - # delete removed TA areas - result = db.execute_no_commit( - "SELECT buildings_reference.territorial_auth_delete_areas();" - ) - if result is not None: - ta_list.extend(result.fetchone()[0]) - # Insert TA areas - result = db.execute_no_commit( - "SELECT buildings_reference.territorial_auth_insert_areas();" - ) - if result is not None: - ta_list.extend(result.fetchone()[0]) - # Update new TA areas - result = db.execute_no_commit( - "SELECT buildings_reference.territorial_auth_update_areas();" - ) - if result is not None: - ta_list.extend(result.fetchone()[0]) - # update bulk_load_outlines territorial authority values - db.execute_no_commit( - "SELECT buildings_bulk_load.bulk_load_outlines_update_all_territorial_authorities(%s);", - (ta_list,), - ) - # update building outlines territorial authority values - db.execute_no_commit( - "SELECT buildings.building_outlines_update_territorial_authority(%s);", - (ta_list,), - ) - # update message and log - self.update_message("updated", "territorial_authority") - self.updates.append("territorial_authority") - # refresh grid - db.execute_no_commit(reference_select.refresh_ta_grid_view) - self.update_message("updated", "territorial_authority_grid") - self.updates.append("territorial_authority_grid") + self.admin_bdy_layer_processing("territorial_authority") # create log for this update if len(self.updates) > 0: @@ -277,36 +216,19 @@ def close_frame(self): @pyqtSlot() def check_all_topo(self): - """ Called when combobox to check all topo layers is toggled""" + """Called when combobox to check all topo layers is toggled""" if self.grbx_topo.isChecked(): for box in self.grbx_topo.findChildren(QCheckBox): box.setChecked(True) box.setEnabled(1) - self.chbx_clicked() else: for box in self.grbx_topo.findChildren(QCheckBox): box.setChecked(False) box.setEnabled(1) - @pyqtSlot() - def chbx_clicked(self): - """Called when topo checkboxes are checked""" - if not self.loop_topo_boxes(): - self.le_key.setDisabled(1) - self.btn_view_key.setDisabled(1) - - def loop_topo_boxes(self): - """loops through topo check boxes returns true if one is checked and enables api key features""" - for box in self.grbx_topo.findChildren(QCheckBox): - if box.isChecked(): - self.le_key.setEnabled(1) - self.btn_view_key.setEnabled(1) - return True - return False - @pyqtSlot() def check_all_admin(self): - """ Called when combobox to check all admin layers is toggled""" + """Called when combobox to check all admin layers is toggled""" if self.grbx_admin.isChecked(): for box in self.grbx_admin.findChildren(QCheckBox): box.setChecked(True) @@ -338,10 +260,23 @@ def topo_layer_processing(self, layer): """Processes to run for all topo layers""" if not self.check_api_key(layer): return - status = topo50.update_topo50(self.api_key, layer) - self.update_message(status, "{}_polygons".format(layer)) + status = topo50.update_topo50(self.api_key, layer, self.db) + self.update_message(status, layer) + if status != "error": + self.updates.append(layer) + + def admin_bdy_layer_processing(self, layer): + """Processes to run for all admin bdy layers""" + if not self.check_api_key(layer): + return + status = admin_bdys.update_admin_bdys(self.api_key, layer, self.db) + self.update_message(status, layer) if status != "error": self.updates.append(layer) + if layer == "territorial_authority": + self.db.execute_no_commit(reference_select.refresh_ta_grid_view) + self.update_message("updated", "territorial_authority_grid") + self.updates.append("territorial_authority_grid") def check_api_key(self, layer): # check for API key diff --git a/buildings/reference_data/admin_bdys.py b/buildings/reference_data/admin_bdys.py new file mode 100644 index 00000000..a7b6187f --- /dev/null +++ b/buildings/reference_data/admin_bdys.py @@ -0,0 +1,194 @@ +from builtins import str + +# script to update canal data + +from buildings.sql import buildings_reference_select_statements as reference_select +from buildings.utilities import database as db +from qgis.core import QgsVectorLayer + +# TODO: review if the filter works +LAYERS = { + "suburb_locality": { + "layer_id": 113764, + "primary_id": "id", + "url_base": "https://data.linz.govt.nz", + "cql_filter": "&cql_filter=type = 'Conservation Land' OR type = 'Island' OR type = 'Locality' OR type ='Suburb'", + }, + "territorial_authority": { + "layer_id": 39939, + "primary_id": "TA_Code", + "url_base": "https://datafinder.stats.govt.nz", + "cql_filter": "", + }, +} + +URI = "{1}/services;key={0}/wfs/layer-{2}-changeset?SERVICE=WFS&VERSION=2.0.0&REQUEST=GetFeature&typeNames=layer-{2}-changeset&viewparams=from:{3};to:{4}{5}&SRSNAME=EPSG:2193&outputFormat=json" + + +def last_update(column_name): + + # get last update of layer date from log + from_var = db.execute_return( + reference_select.log_select_last_update.format(column_name) + ) + from_var = from_var.fetchone() + if from_var is None: + # default to beginning of 2018 + from_var = ( + "2018-01-01T02:15:47.317439" # TODO: check if we should use another date + ) + else: + from_var = str(from_var[0]).split("+")[0] + from_var = from_var.split(" ") + from_var = from_var[0] + "T" + from_var[1] + return from_var + + +def current_date(): + to_var = db.execute_return("SELECT now();") + to_var = to_var.fetchone()[0] + to_var = str(to_var).split("+")[0] + to_var = to_var.split(" ") + to_var = to_var[0] + "T" + to_var[1] + return to_var + + +# todo: add kx_api_key in config +# todo: combine suburb_locality- and town city +def update_admin_bdys(kx_api_key, dataset, dbconn): + + # get last update of layer date from log + from_var = last_update(dataset) + + # current date + to_var = current_date() + + layer = QgsVectorLayer( + URI.format( + kx_api_key, + LAYERS[dataset]["url_base"], + LAYERS[dataset]["layer_id"], + from_var, + to_var, + LAYERS[dataset]["cql_filter"], + ) + ) + + if not layer.isValid(): + # something went wrong + return "error" + + if layer.featureCount() == 0: + return "current" + + external_id = LAYERS[dataset]["primary_id"] + + ids_updates = [] + ids_attr_updates = [] + + for feature in layer.getFeatures(): + if feature.attribute("__change__") == "DELETE": + 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]) + + elif feature.attribute("__change__") == "UPDATE": + if dataset == "suburb_locality": + result = dbconn.execute_return( + reference_select.suburb_locality_attribute_updates, + ( + feature[external_id], + correct_name_format(feature["name"]), + correct_name_format(feature["major_name"]), + ), + ) + result = result.fetchone() + if result is not None: + ids_attr_updates.append(result[0]) + sql = "SELECT buildings_reference.suburb_locality_update_by_external_id(%s, %s, %s, %s)" + result = dbconn.execute_no_commit( + sql, + ( + feature[external_id], + correct_name_format(feature["name"]), + correct_name_format(feature["major_name"]), + feature.geometry().asWkt(), + ), + ) + result = result.fetchone() + if result is not None: + ids_updates.append(result[0]) + else: + result = dbconn.execute_return( + reference_select.territorial_authority_attribute_updates, + ( + feature[external_id], + correct_name_format(feature["name"]), + ), + ) + result = result.fetchone() + if result is not None: + ids_attr_updates.append(result[0]) + sql = "SELECT buildings_reference.territorial_authority_update_by_external_id(%s, %s, %s)" + result = dbconn.execute_no_commit( + sql, + ( + feature[external_id], + correct_name_format(feature["name"]), + 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 + result = dbconn.execute_return( + reference_select.select_admin_bdy_id_by_external_id.format(dataset), + (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( + dataset + ) + dbconn.execute_no_commit(sql, (ids_updates, ids_attr_updates)) + + return "updated" + + +def correct_name_format(name): + if name: + if "'" in name: + name = "{}".format(name.replace("'", "''")) + else: + name = "" + return str(name) diff --git a/buildings/reference_data/topo50.py b/buildings/reference_data/topo50.py index 11fa8955..193e8280 100644 --- a/buildings/reference_data/topo50.py +++ b/buildings/reference_data/topo50.py @@ -1,4 +1,5 @@ from builtins import str + # script to update canal data from buildings.sql import buildings_reference_select_statements as reference_select @@ -18,7 +19,15 @@ "protected_areas_polygons": 53564, } -URI = "srsname='EPSG:2193' typename='data.linz.govt.nz:layer-{0}-changeset' url=\"https://data.linz.govt.nz/services;key={1}/wfs/layer-{0}-changeset?viewparams=from:{2};to:{3}{4}\"" +LDS_LAYER_HAS_NAME = [ + "hut_points", + "shelter_points", + "bivouac_points", + "protected_areas_polygons", +] + +# URI = "srsname='EPSG:2193' typename='data.linz.govt.nz:layer-{0}-changeset' url=\"https://data.linz.govt.nz/services;key={1}/wfs/layer-{0}-changeset?viewparams=from:{2};to:{3}{4}\"" +URI = "https://data.linz.govt.nz/services;key={1}/wfs/layer-{0}-changeset?SERVICE=WFS&VERSION=2.0.0&REQUEST=GetFeature&typeNames=layer-{0}-changeset&viewparams=from:{2};to:{3}{4}&SRSNAME=EPSG:2193&outputFormat=json" def last_update(column_name): @@ -47,7 +56,7 @@ def current_date(): return to_var -def update_topo50(kx_api_key, dataset): +def update_topo50(kx_api_key, dataset, dbconn): # Get name of column in reference log table if "polygon" in dataset: @@ -76,11 +85,8 @@ def update_topo50(kx_api_key, dataset): external_id = "napalis_id" layer = QgsVectorLayer( - URI.format(LDS_LAYER_IDS[dataset], kx_api_key, from_var, to_var, cql_filter), - "changeset", - "WFS", + URI.format(LDS_LAYER_IDS[dataset], kx_api_key, from_var, to_var, cql_filter) ) - if not layer.isValid(): # something went wrong return "error" @@ -93,45 +99,69 @@ def update_topo50(kx_api_key, dataset): sql = "SELECT buildings_reference.{}_delete_by_external_id(%s)".format( dataset ) - db.execute(sql, (feature.attribute(external_id),)) + dbconn.execute_no_commit(sql, (feature.attribute(external_id),)) elif feature.attribute("__change__") == "INSERT": if "polygon" in dataset: - result = db.execute_return( + result = dbconn.execute_return( reference_select.select_polygon_id_by_external_id.format( column_name ), (feature.attribute(external_id),), ) elif "point" in dataset: - result = db.execute_return( + result = dbconn.execute_return( reference_select.select_point_id_by_external_id.format(column_name), (feature.attribute(external_id),), ) result = result.fetchone() if result is None: - sql = "SELECT buildings_reference.{}_insert(%s, %s, %s)".format(dataset) - db.execute( + if dataset in LDS_LAYER_HAS_NAME: + sql = "SELECT buildings_reference.{}_insert(%s, %s, %s)".format( + dataset + ) + dbconn.execute_no_commit( + sql, + ( + feature.attribute(external_id), + correct_name_format(feature["name"]), + feature.geometry().asWkt(), + ), + ) + else: + sql = "SELECT buildings_reference.{}_insert(%s, %s)".format(dataset) + dbconn.execute_no_commit( + sql, + ( + feature.attribute(external_id), + feature.geometry().asWkt(), + ), + ) + + elif feature.attribute("__change__") == "UPDATE": + if dataset in LDS_LAYER_HAS_NAME: + sql = "SELECT buildings_reference.{}_update_by_external_id(%s, %s, %s)".format( + dataset + ) + dbconn.execute_no_commit( sql, ( feature.attribute(external_id), correct_name_format(feature["name"]), - feature.geometry().exportToWkt(), + feature.geometry().asWkt(), + ), + ) + else: + sql = "SELECT buildings_reference.{}_update_shape_by_external_id(%s, %s)".format( + dataset + ) + dbconn.execute_no_commit( + sql, + ( + feature.attribute(external_id), + feature.geometry().asWkt(), ), ) - - elif feature.attribute("__change__") == "UPDATE": - sql = "SELECT buildings_reference.{}_update_by_external_id(%s, %s, %s)".format( - dataset - ) - db.execute( - sql, - ( - feature.attribute(external_id), - correct_name_format(feature["name"]), - feature.geometry().exportToWkt(), - ), - ) return "updated" diff --git a/buildings/sql/buildings_reference_select_statements.py b/buildings/sql/buildings_reference_select_statements.py index c50a8af7..47815c53 100644 --- a/buildings/sql/buildings_reference_select_statements.py +++ b/buildings/sql/buildings_reference_select_statements.py @@ -126,6 +126,13 @@ AND blo.bulk_load_outline_id = %s; """ +suburb_locality_attribute_updates = """ +SELECT suburb_locality_id +FROM buildings_reference.suburb_locality +WHERE external_suburb_locality_id = %s +AND NOT (suburb_locality = %s AND town_city = %s) +""" + # territorial Authority territorial_authority_intersect_geom = """ @@ -156,6 +163,13 @@ AND blo.bulk_load_outline_id = %s; """ +territorial_authority_attribute_updates = """ +SELECT territorial_authority_id +FROM buildings_reference.territorial_authority +WHERE external_territorial_authority_id = %s +AND NOT name = %s +""" + # territorial authority grid refresh_ta_grid_view = """ diff --git a/buildings/tests/gui/test_setup_reference_data.py b/buildings/tests/gui/test_setup_reference_data.py index 5d6a8d80..5bf44144 100644 --- a/buildings/tests/gui/test_setup_reference_data.py +++ b/buildings/tests/gui/test_setup_reference_data.py @@ -43,7 +43,6 @@ def tearDown(self): def test_disabled_on_start(self): """Test ui options disabled on opening as there is a current dataset""" - self.assertFalse(self.reference_frame.le_key.isEnabled()) self.assertFalse(self.reference_frame.grbx_topo.isEnabled()) self.assertFalse(self.reference_frame.grbx_admin.isEnabled()) self.assertFalse(self.reference_frame.chbx_canals.isEnabled()) @@ -53,16 +52,10 @@ def test_disabled_on_start(self): self.assertFalse(self.reference_frame.chbx_rivers.isEnabled()) self.assertFalse(self.reference_frame.chbx_swamps.isEnabled()) self.assertFalse(self.reference_frame.chbx_suburbs.isEnabled()) - self.assertFalse(self.reference_frame.chbx_town.isEnabled()) self.assertFalse(self.reference_frame.chbx_ta.isEnabled()) self.assertFalse(self.reference_frame.btn_update.isEnabled()) self.assertTrue(self.reference_frame.btn_exit.isEnabled()) - def test_lineedit_key(self): - """Check line edit is in password mode to hide key""" - self.reference_frame.le_key.setText("testing") - self.assertEqual(self.reference_frame.le_key.echoMode(), QLineEdit.Password) - def test_groupbx_check(self): """Check changing of group boxes changes the correct checkboxes""" self.reference_frame.grbx_topo.setChecked(True) @@ -73,7 +66,6 @@ def test_groupbx_check(self): self.assertTrue(self.reference_frame.chbx_rivers.isChecked()) self.assertTrue(self.reference_frame.chbx_swamps.isChecked()) self.assertFalse(self.reference_frame.chbx_suburbs.isChecked()) - self.assertFalse(self.reference_frame.chbx_town.isChecked()) self.assertFalse(self.reference_frame.chbx_ta.isChecked()) self.reference_frame.grbx_topo.setChecked(False) self.assertFalse(self.reference_frame.chbx_canals.isChecked()) @@ -84,7 +76,6 @@ def test_groupbx_check(self): self.assertFalse(self.reference_frame.chbx_swamps.isChecked()) self.reference_frame.grbx_admin.setChecked(True) self.assertTrue(self.reference_frame.chbx_suburbs.isChecked()) - self.assertTrue(self.reference_frame.chbx_town.isChecked()) self.assertTrue(self.reference_frame.chbx_ta.isChecked()) self.assertFalse(self.reference_frame.chbx_canals.isChecked()) self.assertFalse(self.reference_frame.chbx_lagoons.isChecked()) @@ -94,5 +85,4 @@ def test_groupbx_check(self): self.assertFalse(self.reference_frame.chbx_swamps.isChecked()) self.reference_frame.grbx_admin.setChecked(False) self.assertFalse(self.reference_frame.chbx_suburbs.isChecked()) - self.assertFalse(self.reference_frame.chbx_town.isChecked()) self.assertFalse(self.reference_frame.chbx_ta.isChecked()) diff --git a/db/sql/deploy/buildings_reference/functions/reference_update_log.sql b/db/sql/deploy/buildings_reference/functions/reference_update_log.sql index 4181a57c..8031f575 100644 --- a/db/sql/deploy/buildings_reference/functions/reference_update_log.sql +++ b/db/sql/deploy/buildings_reference/functions/reference_update_log.sql @@ -24,18 +24,22 @@ CREATE OR REPLACE FUNCTION buildings_reference.reference_update_log_insert_log(p RETURNS integer AS $$ - INSERT INTO buildings_reference.reference_update_log (river, lake, pond, swamp, lagoon, canal, coastlines_and_islands, capture_source_area, territorial_authority, territorial_authority_grid, suburb_locality) - VALUES(CASE WHEN ('river' = ANY(p_list)) THEN True ELSE False END, - CASE WHEN ('lake' = ANY(p_list)) THEN True ELSE False END, - CASE WHEN ('pond' = ANY(p_list)) THEN True ELSE False END, - CASE WHEN ('swamp' = ANY(p_list)) THEN True ELSE False END, - CASE WHEN ('lagoon' = ANY(p_list)) THEN True ELSE False END, - CASE WHEN ('canal' = ANY(p_list)) THEN True ELSE False END, + INSERT INTO buildings_reference.reference_update_log (river, lake, pond, swamp, lagoon, canal, coastlines_and_islands, capture_source_area, territorial_authority, territorial_authority_grid, suburb_locality, hut, shelter, bivouac, protected_areas) + VALUES(CASE WHEN ('river_polygon' = ANY(p_list)) THEN True ELSE False END, + CASE WHEN ('lake_polygons' = ANY(p_list)) THEN True ELSE False END, + CASE WHEN ('pond_polygons' = ANY(p_list)) THEN True ELSE False END, + CASE WHEN ('swamp_polygons' = ANY(p_list)) THEN True ELSE False END, + CASE WHEN ('lagoon_polygons' = ANY(p_list)) THEN True ELSE False END, + CASE WHEN ('canal_polygons' = ANY(p_list)) THEN True ELSE False END, CASE WHEN ('coastlines_and_islands' = ANY(p_list)) THEN True ELSE False END, CASE WHEN ('capture_source_area' = ANY(p_list)) THEN True ELSE False END, CASE WHEN ('territorial_authority' = ANY(p_list)) THEN True ELSE False END, CASE WHEN ('territorial_authority_grid' = ANY(p_list)) THEN True ELSE False END, - CASE WHEN ('suburb_locality' = ANY(p_list)) THEN True ELSE False END + CASE WHEN ('suburb_locality' = ANY(p_list)) THEN True ELSE False END, + CASE WHEN ('hut_points' = ANY(p_list)) THEN True ELSE False END, + CASE WHEN ('shelter_points' = ANY(p_list)) THEN True ELSE False END, + CASE WHEN ('bivouac_points' = ANY(p_list)) THEN True ELSE False END, + CASE WHEN ('protected_areas_polygons' = ANY(p_list)) THEN True ELSE False END ) RETURNING update_id; diff --git a/db/sql/deploy/buildings_reference/functions/suburb_locality.sql b/db/sql/deploy/buildings_reference/functions/suburb_locality.sql index 875b6a94..bb34056a 100644 --- a/db/sql/deploy/buildings_reference/functions/suburb_locality.sql +++ b/db/sql/deploy/buildings_reference/functions/suburb_locality.sql @@ -11,6 +11,22 @@ BEGIN; -- params: p_polygon_geometry geometry -- return: integer suburb_locality_id +-- suburb_locality_delete_by_external_id + -- params: integer external_suburb_locality_id + -- return: integer suburb_locality_id + +-- suburb_locality_insert + -- params: integer external_suburb_locality_id, varchar suburb_locality, varchar town_city, varchar geometry + -- return: integer suburb_locality_id + +-- suburb_locality_update_by_external_id + -- 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 + -- return: integer building_outline_id + -------------------------------------------- -- Functions @@ -39,4 +55,84 @@ LANGUAGE sql VOLATILE; COMMENT ON FUNCTION buildings_reference.suburb_locality_intersect_polygon(geometry) IS 'Return id of suburb/locality with most overlap'; + +-- suburb_locality_delete_by_external_id + -- params: integer external_suburb_locality_id + -- return: integer suburb_locality_id +CREATE OR REPLACE FUNCTION buildings_reference.suburb_locality_delete_by_external_id(integer) +RETURNS integer AS +$$ + + DELETE FROM buildings_reference.suburb_locality + WHERE external_suburb_locality_id = $1 + RETURNING suburb_locality_id; + +$$ +LANGUAGE sql VOLATILE; + +COMMENT ON FUNCTION buildings_reference.suburb_locality_delete_by_external_id(integer) IS +'Delete from suburb_locality table by external id'; + + +-- suburb_locality_insert + -- params: integer external_suburb_locality_id, varchar suburb_locality, varchar town_city, varchar geometry + -- return: integer suburb_locality_id +CREATE OR REPLACE FUNCTION buildings_reference.suburb_locality_insert(integer, varchar, varchar, varchar) +RETURNS integer AS +$$ + + INSERT INTO buildings_reference.suburb_locality (external_suburb_locality_id, suburb_locality, town_city, shape) + VALUES ($1, $2, $3, ST_SetSRID(ST_GeometryFromText($4), 2193)) + RETURNING suburb_locality_id; + +$$ +LANGUAGE sql VOLATILE; + +COMMENT ON FUNCTION buildings_reference.suburb_locality_insert(integer, varchar, varchar, varchar) IS +'Insert new entry into suburb_locality table'; + + +-- suburb_locality_update_by_external_id + -- params: integer external_suburb_locality_id, varchar suburb_locality, varchar town_city, varchar geometry + -- return: integer suburb_locality_id +CREATE OR REPLACE FUNCTION buildings_reference.suburb_locality_update_by_external_id(integer, varchar, varchar, varchar) +RETURNS integer AS +$$ + + UPDATE buildings_reference.suburb_locality + SET suburb_locality = $2, + town_city = $3, + shape = ST_SetSRID(ST_GeometryFromText($4), 2193) + WHERE external_suburb_locality_id = $1 + RETURNING suburb_locality_id; + +$$ +LANGUAGE sql VOLATILE; + +COMMENT ON FUNCTION buildings_reference.suburb_locality_update_by_external_id(integer, varchar, varchar, varchar) IS +'Update suburb_locality table by external id'; + + +-- suburb_locality_update_building_outlines + -- params: integer[] suburb_locality_id, integer[] suburb_locality_id + -- return: integer building_outline_id +CREATE OR REPLACE FUNCTION buildings_reference.suburb_locality_update_building_outlines(integer[], integer[]) +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) + 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'; + + COMMIT; diff --git a/db/sql/deploy/buildings_reference/functions/suburb_locality@v4.0.0-dev1.sql b/db/sql/deploy/buildings_reference/functions/suburb_locality@v4.0.0-dev1.sql new file mode 100644 index 00000000..875b6a94 --- /dev/null +++ b/db/sql/deploy/buildings_reference/functions/suburb_locality@v4.0.0-dev1.sql @@ -0,0 +1,42 @@ +-- Deploy nz-buildings:buildings_reference/functions/suburb_locality to pg + +BEGIN; + +-------------------------------------------- +-- buildings_reference.suburb_locality + +-- Functions + +-- suburb_locality_intersect_polygon (id of suburb with most overlap) + -- params: p_polygon_geometry geometry + -- return: integer suburb_locality_id + +-------------------------------------------- + +-- Functions + +-- suburb_locality_intersect_polygon (id of suburb with most overlap) + -- params: p_polygon_geometry geometry + -- return: integer suburb_locality_id + +CREATE OR REPLACE FUNCTION buildings_reference.suburb_locality_intersect_polygon( + p_polygon_geometry geometry +) +RETURNS integer AS +$$ + + SELECT suburb_locality_id + FROM buildings_reference.suburb_locality + WHERE shape && ST_Expand(p_polygon_geometry, 1000) + ORDER BY + ST_Area(ST_Intersection(p_polygon_geometry, shape)) DESC + , ST_Distance(p_polygon_geometry, shape) ASC + LIMIT 1; + +$$ +LANGUAGE sql VOLATILE; + +COMMENT ON FUNCTION buildings_reference.suburb_locality_intersect_polygon(geometry) IS +'Return id of suburb/locality with most overlap'; + +COMMIT; diff --git a/db/sql/deploy/buildings_reference/functions/territorial_authority.sql b/db/sql/deploy/buildings_reference/functions/territorial_authority.sql index 0d012677..f17fd960 100644 --- a/db/sql/deploy/buildings_reference/functions/territorial_authority.sql +++ b/db/sql/deploy/buildings_reference/functions/territorial_authority.sql @@ -15,17 +15,21 @@ BEGIN; -- params: p_polygon_geometry geometry -- return: integer territorial_authority_id --- territorial_auth_delete_areas(delete areas no long in admin_bdys) - -- params: - -- return: integer list of TAs deleted +-- territorial_authority_delete_by_external_id + -- params: integer external_territorial_authority_id + -- return: integer territorial_authority_id + +-- territorial_authority_insert + -- params: integer external_territorial_authority_id, varchar territorial_authority, varchar geometry + -- return: integer territorial_authority_id --- territorial_auth_insert_areas(insert new areas from admin_bdys) - -- params: - -- return: integer list of new areas added +-- territorial_authority_update_by_external_id + -- params: integer external_territorial_authority_id, varchar territorial_authority, varchar geometry + -- return: integer territorial_authority_id --- territorial_auth_update_areas(update geometries based on admin_bdys) - -- params: - -- return: integer list of areas updated +-- territorial_authority_update_building_outlines + -- params: integer[] territorial_authority_id, integer[] territorial_authority_id + -- return: integer building_outline_id ---------------------------------------------------------------------------------------------- @@ -79,91 +83,87 @@ LANGUAGE sql VOLATILE; COMMENT ON FUNCTION buildings_reference.territorial_authority_intersect_polygon(geometry) IS 'Return id of territorial authority with most overlap'; --- Update Territorial Authority table: +DROP FUNCTION buildings_reference.territorial_auth_delete_areas(); +DROP FUNCTION buildings_reference.territorial_auth_insert_areas(); +DROP FUNCTION buildings_reference.territorial_auth_update_areas(); --- territorial_auth_delete_areas(delete areas no long in admin_bdys) - -- params: - -- return: integer list of TAs deleted -CREATE OR REPLACE FUNCTION buildings_reference.territorial_auth_delete_areas() -RETURNS integer[] AS +-- territorial_authority_delete_by_external_id + -- params: integer external_territorial_authority_id + -- return: integer territorial_authority_id +CREATE OR REPLACE FUNCTION buildings_reference.territorial_authority_delete_by_external_id(integer) +RETURNS integer AS $$ - WITH delete_ta AS ( - DELETE FROM buildings_reference.territorial_authority - WHERE external_territorial_authority_id NOT IN (SELECT DISTINCT - ogc_fid - FROM admin_bdys.territorial_authority) - RETURNING * - ) - SELECT ARRAY(SELECT territorial_authority_id FROM delete_ta); + DELETE FROM buildings_reference.territorial_authority + WHERE external_territorial_authority_id = $1 + RETURNING territorial_authority_id; $$ LANGUAGE sql VOLATILE; -COMMENT ON FUNCTION buildings_reference.territorial_auth_delete_areas() IS -'Function to delete the attributes in the buildings_reference territorial_authority table that are not in the admin_bdys schema.'; +COMMENT ON FUNCTION buildings_reference.territorial_authority_delete_by_external_id(integer) IS +'Delete from territorial_authority table by external id'; --- territorial_auth_insert_areas(insert new areas from admin_bdys) - -- params: - -- return: integer list of new areas added -CREATE OR REPLACE FUNCTION buildings_reference.territorial_auth_insert_areas() -RETURNS integer[] AS +-- territorial_authority_insert + -- params: integer external_territorial_authority_id, varchar territorial_authority, varchar geometry + -- return: integer territorial_authority_id +CREATE OR REPLACE FUNCTION buildings_reference.territorial_authority_insert(integer, varchar, varchar) +RETURNS integer AS $$ - WITH insert_ta AS ( - INSERT INTO buildings_reference.territorial_authority (external_territorial_authority_id, name, shape) - SELECT - ogc_fid - , name - , ST_SetSRID(ST_Transform(shape, 2193), 2193) - FROM admin_bdys.territorial_authority - WHERE ogc_fid NOT IN ( - SELECT external_territorial_authority_id - FROM buildings_reference.territorial_authority - ) - RETURNING * - ) - SELECT ARRAY( - SELECT territorial_authority_id - FROM insert_ta - ); + INSERT INTO buildings_reference.territorial_authority (external_territorial_authority_id, name, shape) + VALUES ($1, $2, ST_SetSRID(ST_GeometryFromText($3), 2193)) + RETURNING territorial_authority_id; $$ LANGUAGE sql VOLATILE; -COMMENT ON FUNCTION buildings_reference.territorial_auth_insert_areas() IS -'Function to insert new territorial authority areas into the buildings_reference.territorial_authority table.'; +COMMENT ON FUNCTION buildings_reference.territorial_authority_insert(integer, varchar, varchar) IS +'Insert new entry into territorial_authority table'; + --- territorial_auth_update_areas(update geometries based on admin_bdys) - -- params: - -- return: integer list of areas updated +-- territorial_authority_update_by_external_id + -- params: integer external_territorial_authority_id, varchar territorial_authority, varchar geometry + -- return: integer territorial_authority_id +CREATE OR REPLACE FUNCTION buildings_reference.territorial_authority_update_by_external_id(integer, varchar, varchar) +RETURNS integer AS +$$ + + UPDATE buildings_reference.territorial_authority + SET name = $2, + shape = ST_SetSRID(ST_GeometryFromText($3), 2193) + WHERE external_territorial_authority_id = $1 + RETURNING territorial_authority_id; -CREATE OR REPLACE FUNCTION buildings_reference.territorial_auth_update_areas() -RETURNS integer[] AS $$ +LANGUAGE sql VOLATILE; - WITH update_ta AS ( - UPDATE buildings_reference.territorial_authority bta - SET - name = ata.name - , shape = ST_SetSRID(ST_Transform(ata.shape, 2193), 2193) - FROM admin_bdys.territorial_authority ata - WHERE bta.external_territorial_authority_id = ata.ogc_fid - AND (NOT ST_Equals(bta.shape, ST_SetSRID(ST_Transform(ata.shape, 2193), 2193)) - OR bta.name != ata.name) - RETURNING * - ) - SELECT ARRAY ( - SELECT territorial_authority_id - FROM update_ta - ); +COMMENT ON FUNCTION buildings_reference.territorial_authority_update_by_external_id(integer, varchar, varchar) IS +'Update territorial_authority table by external id'; + +-- territorial_authority_update_building_outlines + -- params: integer[] territorial_authority_id, integer[] territorial_authority_id + -- return: integer building_outline_id +CREATE OR REPLACE FUNCTION buildings_reference.territorial_authority_update_building_outlines(integer[], 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) + RETURNING building_outline_id; $$ LANGUAGE sql VOLATILE; -COMMENT ON FUNCTION buildings_reference.territorial_auth_update_areas() IS -'Function to update territorial_authority areas that have either name or geometry changes'; +COMMENT ON FUNCTION buildings_reference.territorial_authority_update_building_outlines(integer[], integer[]) IS +'Update building_outlines territorial_authority_id value using territorial_authority table'; + COMMIT; diff --git a/db/sql/deploy/buildings_reference/functions/territorial_authority@v4.0.0-dev1.sql b/db/sql/deploy/buildings_reference/functions/territorial_authority@v4.0.0-dev1.sql new file mode 100644 index 00000000..0d012677 --- /dev/null +++ b/db/sql/deploy/buildings_reference/functions/territorial_authority@v4.0.0-dev1.sql @@ -0,0 +1,169 @@ +-- Deploy nz-buildings:buildings_reference/functions/territorial_authority to pg + +BEGIN; + +---------------------------------------------------------------------------------------------- +-- buildings_reference.territorial_authority && buildings_reference.territorial_authority_grid + +-- Functions + +-- territorial_authority_grid_intersect_polygon (id of the TA that has the most overlap) + -- params: p_polygon_geometry, geometry + -- return: integer territorial_authority_id + +-- territorial_authority_intersect_polygon (id of the TA that has the most overlap) + -- params: p_polygon_geometry geometry + -- return: integer territorial_authority_id + +-- territorial_auth_delete_areas(delete areas no long in admin_bdys) + -- params: + -- return: integer list of TAs deleted + +-- territorial_auth_insert_areas(insert new areas from admin_bdys) + -- params: + -- return: integer list of new areas added + +-- territorial_auth_update_areas(update geometries based on admin_bdys) + -- params: + -- return: integer list of areas updated + +---------------------------------------------------------------------------------------------- + +-- Functions + +-- territorial_authority_grid_intersect_polygon (id of the TA that has the most overlap) + -- params: p_polygon_geometry, geometry + -- return: integer territorial_authority_id + +CREATE OR REPLACE FUNCTION buildings_reference.territorial_authority_grid_intersect_polygon( + p_polygon_geometry geometry +) +RETURNS integer AS +$$ + + SELECT territorial_authority_id + FROM buildings_reference.territorial_authority_grid + WHERE ST_DWithin(p_polygon_geometry, shape, 1000) + ORDER BY + ST_Area(ST_Intersection(p_polygon_geometry, shape)) / ST_Area(shape) DESC + , ST_Distance(p_polygon_geometry, shape) ASC + LIMIT 1; + +$$ +LANGUAGE sql VOLATILE; + +COMMENT ON FUNCTION buildings_reference.territorial_authority_grid_intersect_polygon(geometry) IS +'Returns id of the TA Grid that has the most overlap'; + +-- territorial_authority_intersect_polygon (id of the TA that has the most overlap) + -- params: p_polygon_geometry geometry + -- return: integer territorial_authority_id + +CREATE OR REPLACE FUNCTION buildings_reference.territorial_authority_intersect_polygon( + p_polygon_geometry geometry +) +RETURNS integer AS +$$ + + SELECT territorial_authority_id + FROM buildings_reference.territorial_authority + WHERE shape && ST_Expand(p_polygon_geometry, 1000) + ORDER BY + ST_Area(ST_Intersection(p_polygon_geometry, shape)) / ST_Area(shape) DESC + , ST_Distance(p_polygon_geometry, shape) ASC + LIMIT 1; + +$$ +LANGUAGE sql VOLATILE; + +COMMENT ON FUNCTION buildings_reference.territorial_authority_intersect_polygon(geometry) IS +'Return id of territorial authority with most overlap'; + +-- Update Territorial Authority table: + +-- territorial_auth_delete_areas(delete areas no long in admin_bdys) + -- params: + -- return: integer list of TAs deleted + +CREATE OR REPLACE FUNCTION buildings_reference.territorial_auth_delete_areas() +RETURNS integer[] AS +$$ + + WITH delete_ta AS ( + DELETE FROM buildings_reference.territorial_authority + WHERE external_territorial_authority_id NOT IN (SELECT DISTINCT + ogc_fid + FROM admin_bdys.territorial_authority) + RETURNING * + ) + SELECT ARRAY(SELECT territorial_authority_id FROM delete_ta); + +$$ +LANGUAGE sql VOLATILE; + +COMMENT ON FUNCTION buildings_reference.territorial_auth_delete_areas() IS +'Function to delete the attributes in the buildings_reference territorial_authority table that are not in the admin_bdys schema.'; + +-- territorial_auth_insert_areas(insert new areas from admin_bdys) + -- params: + -- return: integer list of new areas added + +CREATE OR REPLACE FUNCTION buildings_reference.territorial_auth_insert_areas() +RETURNS integer[] AS +$$ + + WITH insert_ta AS ( + INSERT INTO buildings_reference.territorial_authority (external_territorial_authority_id, name, shape) + SELECT + ogc_fid + , name + , ST_SetSRID(ST_Transform(shape, 2193), 2193) + FROM admin_bdys.territorial_authority + WHERE ogc_fid NOT IN ( + SELECT external_territorial_authority_id + FROM buildings_reference.territorial_authority + ) + RETURNING * + ) + SELECT ARRAY( + SELECT territorial_authority_id + FROM insert_ta + ); + +$$ +LANGUAGE sql VOLATILE; + +COMMENT ON FUNCTION buildings_reference.territorial_auth_insert_areas() IS +'Function to insert new territorial authority areas into the buildings_reference.territorial_authority table.'; + +-- territorial_auth_update_areas(update geometries based on admin_bdys) + -- params: + -- return: integer list of areas updated + +CREATE OR REPLACE FUNCTION buildings_reference.territorial_auth_update_areas() +RETURNS integer[] AS +$$ + + WITH update_ta AS ( + UPDATE buildings_reference.territorial_authority bta + SET + name = ata.name + , shape = ST_SetSRID(ST_Transform(ata.shape, 2193), 2193) + FROM admin_bdys.territorial_authority ata + WHERE bta.external_territorial_authority_id = ata.ogc_fid + AND (NOT ST_Equals(bta.shape, ST_SetSRID(ST_Transform(ata.shape, 2193), 2193)) + OR bta.name != ata.name) + RETURNING * + ) + SELECT ARRAY ( + SELECT territorial_authority_id + FROM update_ta + ); + +$$ +LANGUAGE sql VOLATILE; + +COMMENT ON FUNCTION buildings_reference.territorial_auth_update_areas() IS +'Function to update territorial_authority areas that have either name or geometry changes'; + +COMMIT; diff --git a/db/sql/revert/buildings_reference/functions/suburb_locality.sql b/db/sql/revert/buildings_reference/functions/suburb_locality.sql index 9fc0e63e..6611951f 100644 --- a/db/sql/revert/buildings_reference/functions/suburb_locality.sql +++ b/db/sql/revert/buildings_reference/functions/suburb_locality.sql @@ -1,4 +1,4 @@ --- Revert nz-buildings:buildings_reference/functions/suburb_locality to pg +-- Deploy nz-buildings:buildings_reference/functions/suburb_locality to pg BEGIN; @@ -11,18 +11,6 @@ BEGIN; -- params: p_polygon_geometry geometry -- return: integer suburb_locality_id --- suburb_locality_delete_removed_areas (delete suburbs that are no longer is admin_bdys) - -- params: - -- return: integer list of outlines deleted - --- suburb_locality_insert_new_areas (insert new areas from admin_bdys) - -- params: - -- return: integer list of areas inserted - --- suburb_locality_update_suburb_locality (update geometries based on those in admin_bdys) - -- params: - -- return: integer list of areas updated - -------------------------------------------- -- Functions @@ -41,7 +29,7 @@ $$ FROM buildings_reference.suburb_locality WHERE shape && ST_Expand(p_polygon_geometry, 1000) ORDER BY - ST_Area(ST_Intersection(p_polygon_geometry, shape)) / ST_Area(shape) DESC + ST_Area(ST_Intersection(p_polygon_geometry, shape)) DESC , ST_Distance(p_polygon_geometry, shape) ASC LIMIT 1; @@ -51,110 +39,12 @@ LANGUAGE sql VOLATILE; COMMENT ON FUNCTION buildings_reference.suburb_locality_intersect_polygon(geometry) IS 'Return id of suburb/locality with most overlap'; --- update suburb_table_functions - --- suburb_locality_delete_removed_areas (delete suburbs that are no longer is admin_bdys) - -- params: - -- return: integer list of outlines deleted - -CREATE OR REPLACE FUNCTION buildings_reference.suburb_locality_delete_removed_areas() -RETURNS integer[] AS -$$ - - WITH delete_suburb AS ( - DELETE FROM buildings_reference.suburb_locality - WHERE external_suburb_locality_id NOT IN ( - SELECT id - FROM admin_bdys.nz_locality - ) - RETURNING * - ) - SELECT ARRAY( - SELECT suburb_locality_id - FROM delete_suburb - ); - -$$ -LANGUAGE sql VOLATILE; - -COMMENT ON FUNCTION buildings_reference.suburb_locality_delete_removed_areas() IS -'Function to delete from the buildings_reference suburb locality table the areas that have been removed in the admin_bdys schema'; - --- suburb_locality_insert_new_areas (insert new areas from admin_bdys) - -- params: - -- return: integer list of areas inserted +DROP FUNCTION IF EXISTS buildings_reference.suburb_locality_delete_by_external_id(integer); -CREATE OR REPLACE FUNCTION buildings_reference.suburb_locality_insert_new_areas() -RETURNS integer[] AS -$$ - - WITH insert_suburb AS ( - INSERT INTO buildings_reference.suburb_locality ( - external_suburb_locality_id - , suburb_4th - , suburb_3rd - , suburb_2nd - , suburb_1st - , shape - ) - SELECT - id - , suburb_4th - , suburb_3rd - , suburb_2nd - , suburb_1st - , ST_SetSRID(ST_Transform(shape, 2193), 2193) - FROM admin_bdys.nz_locality - WHERE type in ('ISLAND','LOCALITY','PARK_RESERVE','SUBURB') - AND id NOT IN ( - SELECT external_suburb_locality_id - FROM buildings_reference.suburb_locality - ) - RETURNING * - ) - SELECT ARRAY( - SELECT suburb_locality_id - FROM insert_suburb - ); - -$$ -LANGUAGE sql VOLATILE; - -COMMENT ON FUNCTION buildings_reference.suburb_locality_insert_new_areas() IS -'Function to insert from the admin_bdys schema new areas not in the buildings_reference suburb locality table'; +DROP FUNCTION IF EXISTS buildings_reference.suburb_locality_insert(integer, varchar, varchar, varchar); --- suburb_locality_update_suburb_locality (update geometries based on those in admin_bdys) - -- params: - -- return: integer list of areas updated - -CREATE OR REPLACE FUNCTION buildings_reference.suburb_locality_update_suburb_locality() -RETURNS integer[] AS -$$ - - WITH update_suburb AS ( - UPDATE buildings_reference.suburb_locality bsl - SET - suburb_4th = nzl.suburb_4th - , suburb_3rd = nzl.suburb_3rd - , suburb_2nd = nzl.suburb_2nd - , suburb_1st = nzl.suburb_1st - , shape = ST_SetSRID(ST_Transform(nzl.shape, 2193), 2193) - FROM admin_bdys.nz_locality nzl - WHERE bsl.external_suburb_locality_id = nzl.id - AND ( NOT ST_Equals(ST_SetSRID(ST_Transform(nzl.shape, 2193), 2193), bsl.shape) - OR nzl.suburb_4th != bsl.suburb_4th - OR nzl.suburb_3rd != bsl.suburb_3rd - OR nzl.suburb_2nd != bsl.suburb_2nd - OR nzl.suburb_1st != bsl.suburb_1st - ) - RETURNING * - ) - SELECT ARRAY(SELECT suburb_locality_id FROM update_suburb); - -$$ -LANGUAGE sql VOLATILE; +DROP FUNCTION IF EXISTS buildings_reference.suburb_locality_update_by_external_id(integer, varchar, varchar, varchar); -COMMENT ON FUNCTION buildings_reference.suburb_locality_update_suburb_locality() IS -'Function to update the attributes in the buildings_reference suburb locality table from the admin_bdys schema'; +DROP FUNCTION IF EXISTS buildings_reference.suburb_locality_update_building_outlines(integer[], integer[]); COMMIT; diff --git a/db/sql/revert/buildings_reference/functions/suburb_locality@v4.0.0-dev1.sql b/db/sql/revert/buildings_reference/functions/suburb_locality@v4.0.0-dev1.sql new file mode 100644 index 00000000..9fc0e63e --- /dev/null +++ b/db/sql/revert/buildings_reference/functions/suburb_locality@v4.0.0-dev1.sql @@ -0,0 +1,160 @@ +-- Revert nz-buildings:buildings_reference/functions/suburb_locality to pg + +BEGIN; + +-------------------------------------------- +-- buildings_reference.suburb_locality + +-- Functions + +-- suburb_locality_intersect_polygon (id of suburb with most overlap) + -- params: p_polygon_geometry geometry + -- return: integer suburb_locality_id + +-- suburb_locality_delete_removed_areas (delete suburbs that are no longer is admin_bdys) + -- params: + -- return: integer list of outlines deleted + +-- suburb_locality_insert_new_areas (insert new areas from admin_bdys) + -- params: + -- return: integer list of areas inserted + +-- suburb_locality_update_suburb_locality (update geometries based on those in admin_bdys) + -- params: + -- return: integer list of areas updated + +-------------------------------------------- + +-- Functions + +-- suburb_locality_intersect_polygon (id of suburb with most overlap) + -- params: p_polygon_geometry geometry + -- return: integer suburb_locality_id + +CREATE OR REPLACE FUNCTION buildings_reference.suburb_locality_intersect_polygon( + p_polygon_geometry geometry +) +RETURNS integer AS +$$ + + SELECT suburb_locality_id + FROM buildings_reference.suburb_locality + WHERE shape && ST_Expand(p_polygon_geometry, 1000) + ORDER BY + ST_Area(ST_Intersection(p_polygon_geometry, shape)) / ST_Area(shape) DESC + , ST_Distance(p_polygon_geometry, shape) ASC + LIMIT 1; + +$$ +LANGUAGE sql VOLATILE; + +COMMENT ON FUNCTION buildings_reference.suburb_locality_intersect_polygon(geometry) IS +'Return id of suburb/locality with most overlap'; + +-- update suburb_table_functions + +-- suburb_locality_delete_removed_areas (delete suburbs that are no longer is admin_bdys) + -- params: + -- return: integer list of outlines deleted + +CREATE OR REPLACE FUNCTION buildings_reference.suburb_locality_delete_removed_areas() +RETURNS integer[] AS +$$ + + WITH delete_suburb AS ( + DELETE FROM buildings_reference.suburb_locality + WHERE external_suburb_locality_id NOT IN ( + SELECT id + FROM admin_bdys.nz_locality + ) + RETURNING * + ) + SELECT ARRAY( + SELECT suburb_locality_id + FROM delete_suburb + ); + +$$ +LANGUAGE sql VOLATILE; + +COMMENT ON FUNCTION buildings_reference.suburb_locality_delete_removed_areas() IS +'Function to delete from the buildings_reference suburb locality table the areas that have been removed in the admin_bdys schema'; + +-- suburb_locality_insert_new_areas (insert new areas from admin_bdys) + -- params: + -- return: integer list of areas inserted + +CREATE OR REPLACE FUNCTION buildings_reference.suburb_locality_insert_new_areas() +RETURNS integer[] AS +$$ + + WITH insert_suburb AS ( + INSERT INTO buildings_reference.suburb_locality ( + external_suburb_locality_id + , suburb_4th + , suburb_3rd + , suburb_2nd + , suburb_1st + , shape + ) + SELECT + id + , suburb_4th + , suburb_3rd + , suburb_2nd + , suburb_1st + , ST_SetSRID(ST_Transform(shape, 2193), 2193) + FROM admin_bdys.nz_locality + WHERE type in ('ISLAND','LOCALITY','PARK_RESERVE','SUBURB') + AND id NOT IN ( + SELECT external_suburb_locality_id + FROM buildings_reference.suburb_locality + ) + RETURNING * + ) + SELECT ARRAY( + SELECT suburb_locality_id + FROM insert_suburb + ); + +$$ +LANGUAGE sql VOLATILE; + +COMMENT ON FUNCTION buildings_reference.suburb_locality_insert_new_areas() IS +'Function to insert from the admin_bdys schema new areas not in the buildings_reference suburb locality table'; + +-- suburb_locality_update_suburb_locality (update geometries based on those in admin_bdys) + -- params: + -- return: integer list of areas updated + +CREATE OR REPLACE FUNCTION buildings_reference.suburb_locality_update_suburb_locality() +RETURNS integer[] AS +$$ + + WITH update_suburb AS ( + UPDATE buildings_reference.suburb_locality bsl + SET + suburb_4th = nzl.suburb_4th + , suburb_3rd = nzl.suburb_3rd + , suburb_2nd = nzl.suburb_2nd + , suburb_1st = nzl.suburb_1st + , shape = ST_SetSRID(ST_Transform(nzl.shape, 2193), 2193) + FROM admin_bdys.nz_locality nzl + WHERE bsl.external_suburb_locality_id = nzl.id + AND ( NOT ST_Equals(ST_SetSRID(ST_Transform(nzl.shape, 2193), 2193), bsl.shape) + OR nzl.suburb_4th != bsl.suburb_4th + OR nzl.suburb_3rd != bsl.suburb_3rd + OR nzl.suburb_2nd != bsl.suburb_2nd + OR nzl.suburb_1st != bsl.suburb_1st + ) + RETURNING * + ) + SELECT ARRAY(SELECT suburb_locality_id FROM update_suburb); + +$$ +LANGUAGE sql VOLATILE; + +COMMENT ON FUNCTION buildings_reference.suburb_locality_update_suburb_locality() IS +'Function to update the attributes in the buildings_reference suburb locality table from the admin_bdys schema'; + +COMMIT; diff --git a/db/sql/revert/buildings_reference/functions/territorial_authority.sql b/db/sql/revert/buildings_reference/functions/territorial_authority.sql index 8f5789a7..1420817c 100644 --- a/db/sql/revert/buildings_reference/functions/territorial_authority.sql +++ b/db/sql/revert/buildings_reference/functions/territorial_authority.sql @@ -2,6 +2,14 @@ BEGIN; +DROP FUNCTION IF EXISTS buildings_reference.territorial_authority_delete_by_external_id(integer); + +DROP FUNCTION IF EXISTS buildings_reference.territorial_authority_insert(integer, varchar, varchar); + +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[]); + ---------------------------------------------------------------------------------------------- -- buildings_reference.territorial_authority && buildings_reference.territorial_authority_grid @@ -150,13 +158,9 @@ $$ name = ata.name , shape = ST_SetSRID(ST_Transform(ata.shape, 2193), 2193) FROM admin_bdys.territorial_authority ata - WHERE bta.external_territorial_authority_id IN ( - SELECT ogc_fid - FROM admin_bdys.territorial_authority ata - JOIN buildings_reference.territorial_authority bta ON ogc_fid = external_territorial_authority_id - WHERE ( NOT ST_Equals(bta.shape, ST_SetSRID(ST_Transform(ata.shape, 2193), 2193)) - OR bta.name != ata.name) - ) + WHERE bta.external_territorial_authority_id = ata.ogc_fid + AND (NOT ST_Equals(bta.shape, ST_SetSRID(ST_Transform(ata.shape, 2193), 2193)) + OR bta.name != ata.name) RETURNING * ) SELECT ARRAY ( diff --git a/db/sql/revert/buildings_reference/functions/territorial_authority@v4.0.0-dev1.sql b/db/sql/revert/buildings_reference/functions/territorial_authority@v4.0.0-dev1.sql new file mode 100644 index 00000000..8f5789a7 --- /dev/null +++ b/db/sql/revert/buildings_reference/functions/territorial_authority@v4.0.0-dev1.sql @@ -0,0 +1,173 @@ +-- Deploy nz-buildings:buildings_reference/functions/territorial_authority to pg + +BEGIN; + +---------------------------------------------------------------------------------------------- +-- buildings_reference.territorial_authority && buildings_reference.territorial_authority_grid + +-- Functions + +-- territorial_authority_grid_intersect_polygon (id of the TA that has the most overlap) + -- params: p_polygon_geometry, geometry + -- return: integer territorial_authority_id + +-- territorial_authority_intersect_polygon (id of the TA that has the most overlap) + -- params: p_polygon_geometry geometry + -- return: integer territorial_authority_id + +-- territorial_auth_delete_areas(delete areas no long in admin_bdys) + -- params: + -- return: integer list of TAs deleted + +-- territorial_auth_insert_areas(insert new areas from admin_bdys) + -- params: + -- return: integer list of new areas added + +-- territorial_auth_update_areas(update geometries based on admin_bdys) + -- params: + -- return: integer list of areas updated + +---------------------------------------------------------------------------------------------- + +-- Functions + +-- territorial_authority_grid_intersect_polygon (id of the TA that has the most overlap) + -- params: p_polygon_geometry, geometry + -- return: integer territorial_authority_id + +CREATE OR REPLACE FUNCTION buildings_reference.territorial_authority_grid_intersect_polygon( + p_polygon_geometry geometry +) +RETURNS integer AS +$$ + + SELECT territorial_authority_id + FROM buildings_reference.territorial_authority_grid + WHERE ST_DWithin(p_polygon_geometry, shape, 1000) + ORDER BY + ST_Area(ST_Intersection(p_polygon_geometry, shape)) / ST_Area(shape) DESC + , ST_Distance(p_polygon_geometry, shape) ASC + LIMIT 1; + +$$ +LANGUAGE sql VOLATILE; + +COMMENT ON FUNCTION buildings_reference.territorial_authority_grid_intersect_polygon(geometry) IS +'Returns id of the TA Grid that has the most overlap'; + +-- territorial_authority_intersect_polygon (id of the TA that has the most overlap) + -- params: p_polygon_geometry geometry + -- return: integer territorial_authority_id + +CREATE OR REPLACE FUNCTION buildings_reference.territorial_authority_intersect_polygon( + p_polygon_geometry geometry +) +RETURNS integer AS +$$ + + SELECT territorial_authority_id + FROM buildings_reference.territorial_authority + WHERE shape && ST_Expand(p_polygon_geometry, 1000) + ORDER BY + ST_Area(ST_Intersection(p_polygon_geometry, shape)) / ST_Area(shape) DESC + , ST_Distance(p_polygon_geometry, shape) ASC + LIMIT 1; + +$$ +LANGUAGE sql VOLATILE; + +COMMENT ON FUNCTION buildings_reference.territorial_authority_intersect_polygon(geometry) IS +'Return id of territorial authority with most overlap'; + +-- Update Territorial Authority table: + +-- territorial_auth_delete_areas(delete areas no long in admin_bdys) + -- params: + -- return: integer list of TAs deleted + +CREATE OR REPLACE FUNCTION buildings_reference.territorial_auth_delete_areas() +RETURNS integer[] AS +$$ + + WITH delete_ta AS ( + DELETE FROM buildings_reference.territorial_authority + WHERE external_territorial_authority_id NOT IN (SELECT DISTINCT + ogc_fid + FROM admin_bdys.territorial_authority) + RETURNING * + ) + SELECT ARRAY(SELECT territorial_authority_id FROM delete_ta); + +$$ +LANGUAGE sql VOLATILE; + +COMMENT ON FUNCTION buildings_reference.territorial_auth_delete_areas() IS +'Function to delete the attributes in the buildings_reference territorial_authority table that are not in the admin_bdys schema.'; + +-- territorial_auth_insert_areas(insert new areas from admin_bdys) + -- params: + -- return: integer list of new areas added + +CREATE OR REPLACE FUNCTION buildings_reference.territorial_auth_insert_areas() +RETURNS integer[] AS +$$ + + WITH insert_ta AS ( + INSERT INTO buildings_reference.territorial_authority (external_territorial_authority_id, name, shape) + SELECT + ogc_fid + , name + , ST_SetSRID(ST_Transform(shape, 2193), 2193) + FROM admin_bdys.territorial_authority + WHERE ogc_fid NOT IN ( + SELECT external_territorial_authority_id + FROM buildings_reference.territorial_authority + ) + RETURNING * + ) + SELECT ARRAY( + SELECT territorial_authority_id + FROM insert_ta + ); + +$$ +LANGUAGE sql VOLATILE; + +COMMENT ON FUNCTION buildings_reference.territorial_auth_insert_areas() IS +'Function to insert new territorial authority areas into the buildings_reference.territorial_authority table.'; + +-- territorial_auth_update_areas(update geometries based on admin_bdys) + -- params: + -- return: integer list of areas updated + +CREATE OR REPLACE FUNCTION buildings_reference.territorial_auth_update_areas() +RETURNS integer[] AS +$$ + + WITH update_ta AS ( + UPDATE buildings_reference.territorial_authority bta + SET + name = ata.name + , shape = ST_SetSRID(ST_Transform(ata.shape, 2193), 2193) + FROM admin_bdys.territorial_authority ata + WHERE bta.external_territorial_authority_id IN ( + SELECT ogc_fid + FROM admin_bdys.territorial_authority ata + JOIN buildings_reference.territorial_authority bta ON ogc_fid = external_territorial_authority_id + WHERE ( NOT ST_Equals(bta.shape, ST_SetSRID(ST_Transform(ata.shape, 2193), 2193)) + OR bta.name != ata.name) + ) + RETURNING * + ) + SELECT ARRAY ( + SELECT territorial_authority_id + FROM update_ta + ); + +$$ +LANGUAGE sql VOLATILE; + +COMMENT ON FUNCTION buildings_reference.territorial_auth_update_areas() IS +'Function to update territorial_authority areas that have either name or geometry changes'; + +COMMIT; diff --git a/db/sql/sqitch.plan b/db/sql/sqitch.plan index d9c5413f..bfd35605 100644 --- a/db/sql/sqitch.plan +++ b/db/sql/sqitch.plan @@ -108,3 +108,5 @@ buildings_reference/functions/town_city [buildings_reference/functions/town_city buildings_reference/functions/reference_update_log [buildings_reference/functions/reference_update_log@v4.0.0-dev1] 2024-08-14T04:38:22Z Yingting Chen # Remove town_city in reference_update_log update function. buildings_reference/remove_suburb_locality_old_name_column 2024-08-14T04:40:22Z Yingting Chen # Remove suburb_locality old name columns from FENZ buildings_reference/drop_town_city 2024-08-14T04:45:02Z Yingting Chen # Drop table town_city as it has been merged into suburb_locality. +buildings_reference/functions/suburb_locality [buildings_reference/functions/suburb_locality@v4.0.0-dev1] 2024-08-30T02:54:25Z Yingting Chen # Add new suburb_locality functions for the reference update process. +buildings_reference/functions/territorial_authority [buildings_reference/functions/territorial_authority@v4.0.0-dev1] 2024-09-10T05:51:01Z Yingting Chen # Add new territorial_authority functions for the reference update process. diff --git a/db/sql/verify/buildings_reference/functions/reference_update_log.sql b/db/sql/verify/buildings_reference/functions/reference_update_log.sql index dbd3c2e1..35c053b8 100644 --- a/db/sql/verify/buildings_reference/functions/reference_update_log.sql +++ b/db/sql/verify/buildings_reference/functions/reference_update_log.sql @@ -15,6 +15,17 @@ BEGIN RAISE EXCEPTION 'town_city found, should have been removed.'; END IF; + PERFORM proname, proargnames, prosrc + FROM pg_proc + WHERE proname = 'reference_update_log_insert_log' + AND prosrc LIKE '%hut_points%' + AND prosrc LIKE '%shelter_points%' + AND prosrc LIKE '%bivouac_points%' + AND prosrc LIKE '%protected_areas_polygons%'; + IF NOT FOUND THEN + RAISE EXCEPTION 'dataset keywords not found, should have been added.'; + END IF; + END $$; ROLLBACK; diff --git a/db/sql/verify/buildings_reference/functions/suburb_locality.sql b/db/sql/verify/buildings_reference/functions/suburb_locality.sql index a0f552ad..02829e04 100644 --- a/db/sql/verify/buildings_reference/functions/suburb_locality.sql +++ b/db/sql/verify/buildings_reference/functions/suburb_locality.sql @@ -4,18 +4,12 @@ BEGIN; SELECT has_function_privilege('buildings_reference.suburb_locality_intersect_polygon(geometry)', 'execute'); -DO $$ -BEGIN +SELECT has_function_privilege('buildings_reference.suburb_locality_delete_by_external_id(integer)', 'execute'); - PERFORM proname, proargnames, prosrc - FROM pg_proc - WHERE proname = 'suburb_locality_intersect_polygon' - AND prosrc LIKE '%ST_Area(shape)%'; +SELECT has_function_privilege('buildings_reference.suburb_locality_insert(integer, varchar, varchar, varchar)', 'execute'); - IF FOUND THEN - RAISE EXCEPTION 'ST_Area(shape) Found.'; - END IF; +SELECT has_function_privilege('buildings_reference.suburb_locality_update_by_external_id(integer, varchar, varchar, varchar)', 'execute'); -END $$; +SELECT has_function_privilege('buildings_reference.suburb_locality_update_building_outlines(integer[], integer[])', 'execute'); ROLLBACK; diff --git a/db/sql/verify/buildings_reference/functions/suburb_locality@v4.0.0-dev1.sql b/db/sql/verify/buildings_reference/functions/suburb_locality@v4.0.0-dev1.sql new file mode 100644 index 00000000..a0f552ad --- /dev/null +++ b/db/sql/verify/buildings_reference/functions/suburb_locality@v4.0.0-dev1.sql @@ -0,0 +1,21 @@ +-- Verify nz-buildings:buildings_reference/functions/suburb_locality on pg + +BEGIN; + +SELECT has_function_privilege('buildings_reference.suburb_locality_intersect_polygon(geometry)', 'execute'); + +DO $$ +BEGIN + + PERFORM proname, proargnames, prosrc + FROM pg_proc + WHERE proname = 'suburb_locality_intersect_polygon' + AND prosrc LIKE '%ST_Area(shape)%'; + + IF FOUND THEN + RAISE EXCEPTION 'ST_Area(shape) Found.'; + END IF; + +END $$; + +ROLLBACK; diff --git a/db/sql/verify/buildings_reference/functions/territorial_authority.sql b/db/sql/verify/buildings_reference/functions/territorial_authority.sql index c8b4ae0f..b2789c36 100644 --- a/db/sql/verify/buildings_reference/functions/territorial_authority.sql +++ b/db/sql/verify/buildings_reference/functions/territorial_authority.sql @@ -6,23 +6,45 @@ SELECT has_function_privilege('buildings_reference.territorial_authority_grid_in SELECT has_function_privilege('buildings_reference.territorial_authority_intersect_polygon(geometry)', 'execute'); -SELECT has_function_privilege('buildings_reference.territorial_auth_delete_areas()', 'execute'); +SELECT has_function_privilege('buildings_reference.territorial_authority_delete_by_external_id(integer)', 'execute'); -SELECT has_function_privilege('buildings_reference.territorial_auth_insert_areas()', 'execute'); +SELECT has_function_privilege('buildings_reference.territorial_authority_insert(integer, varchar, varchar)', 'execute'); -SELECT has_function_privilege('buildings_reference.territorial_auth_update_areas()', 'execute'); +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'); DO $$ BEGIN + PERFORM * + FROM pg_proc + WHERE proname = 'territorial_auth_delete_areas' + AND pronargs = 0; + IF FOUND THEN + RAISE EXCEPTION 'Dropped function found.'; + END IF; +END $$; - PERFORM proname, proargnames, prosrc +DO $$ +BEGIN + PERFORM * FROM pg_proc - WHERE proname = 'territorial_auth_update_areas' - AND prosrc LIKE '%JOIN%'; + WHERE proname = 'territorial_auth_insert_areas' + AND pronargs = 0; IF FOUND THEN - RAISE EXCEPTION 'JOIN found.'; + RAISE EXCEPTION 'Dropped function found.'; END IF; +END $$; +DO $$ +BEGIN + PERFORM * + FROM pg_proc + WHERE proname = 'territorial_auth_update_areas' + AND pronargs = 0; + IF FOUND THEN + RAISE EXCEPTION 'Dropped function found.'; + END IF; END $$; ROLLBACK; diff --git a/db/sql/verify/buildings_reference/functions/territorial_authority@v4.0.0-dev1.sql b/db/sql/verify/buildings_reference/functions/territorial_authority@v4.0.0-dev1.sql new file mode 100644 index 00000000..c8b4ae0f --- /dev/null +++ b/db/sql/verify/buildings_reference/functions/territorial_authority@v4.0.0-dev1.sql @@ -0,0 +1,28 @@ +-- Verify nz-buildings:buildings_reference/functions/territorial_authority on pg + +BEGIN; + +SELECT has_function_privilege('buildings_reference.territorial_authority_grid_intersect_polygon(geometry)', 'execute'); + +SELECT has_function_privilege('buildings_reference.territorial_authority_intersect_polygon(geometry)', 'execute'); + +SELECT has_function_privilege('buildings_reference.territorial_auth_delete_areas()', 'execute'); + +SELECT has_function_privilege('buildings_reference.territorial_auth_insert_areas()', 'execute'); + +SELECT has_function_privilege('buildings_reference.territorial_auth_update_areas()', 'execute'); + +DO $$ +BEGIN + + PERFORM proname, proargnames, prosrc + FROM pg_proc + WHERE proname = 'territorial_auth_update_areas' + AND prosrc LIKE '%JOIN%'; + IF FOUND THEN + RAISE EXCEPTION 'JOIN found.'; + END IF; + +END $$; + +ROLLBACK;