Set columns to null instead of dropping to avoid pg_deadlock during updates (#1710)
This PR addresses a pg_deadlock error that would cause an update to fail if a `select getmvt` was queried during update. The deadlock occurred due to an ALTER TABLE DROP COLUMN operation on temporary columns ( `new_source_ids` and `old_source_ids`) in some linestring tables. **Changes:** * instead of adding/dropping the columns during update, they are now updated and set to NULL. * Added new indexes on the source_ids columns to speed up the UPDATE. * Will refresh `osm_park_polygon_dissolve_z4` concurrently in `park_polygon.refresh()` to avoid blocking. Co-authored-by: Patrik Sylve <patrik.sylve@t-kartor.com>
This commit is contained in:
@@ -41,6 +41,8 @@ CREATE TABLE IF NOT EXISTS osm_transportation_name_linestring(
|
||||
source integer,
|
||||
geometry geometry('LineString'),
|
||||
source_ids bigint[],
|
||||
new_source_ids bigint[],
|
||||
old_source_ids bigint[],
|
||||
tags hstore,
|
||||
ref text,
|
||||
highway varchar,
|
||||
@@ -62,6 +64,15 @@ CREATE TABLE IF NOT EXISTS osm_transportation_name_linestring(
|
||||
);
|
||||
|
||||
ALTER TABLE osm_transportation_name_linestring ADD COLUMN IF NOT EXISTS source_ids bigint[];
|
||||
-- Create temporary Merged-LineString to Source-LineStrings-ID columns to store relations before they have been
|
||||
-- intersected.
|
||||
ALTER TABLE osm_transportation_name_linestring ADD COLUMN IF NOT EXISTS new_source_ids BIGINT[];
|
||||
ALTER TABLE osm_transportation_name_linestring ADD COLUMN IF NOT EXISTS old_source_ids BIGINT[];
|
||||
|
||||
CREATE INDEX IF NOT EXISTS osm_transportation_name_linestring_n_source_ids_not_null_idx
|
||||
ON osm_transportation_name_linestring ((new_source_ids IS NOT NULL));
|
||||
CREATE INDEX IF NOT EXISTS osm_transportation_name_linestring_o_source_ids_not_null_idx
|
||||
ON osm_transportation_name_linestring ((old_source_ids IS NOT NULL));
|
||||
|
||||
-- Create OneToMany-Relation-Table storing relations of a Merged-LineString in table
|
||||
-- osm_transportation_name_linestring to Source-LineStrings from tables osm_transportation_name_network,
|
||||
@@ -1102,11 +1113,6 @@ BEGIN
|
||||
CREATE INDEX ON clustered_linestrings_to_merge (cluster_group, cluster);
|
||||
ANALYZE clustered_linestrings_to_merge;
|
||||
|
||||
-- Create temporary Merged-LineString to Source-LineStrings-ID columns to store relations before they have been
|
||||
-- intersected
|
||||
ALTER TABLE osm_transportation_name_linestring ADD COLUMN IF NOT EXISTS new_source_ids BIGINT[];
|
||||
ALTER TABLE osm_transportation_name_linestring ADD COLUMN IF NOT EXISTS old_source_ids BIGINT[];
|
||||
|
||||
|
||||
WITH inserted_linestrings AS (
|
||||
-- Merge LineStrings of each cluster and insert them
|
||||
@@ -1154,9 +1160,9 @@ BEGIN
|
||||
-- Cleanup remaining table
|
||||
DROP TABLE clustered_linestrings_to_merge;
|
||||
|
||||
-- Drop temporary Merged-LineString to Source-LineStrings-ID columns
|
||||
ALTER TABLE osm_transportation_name_linestring DROP COLUMN IF EXISTS new_source_ids;
|
||||
ALTER TABLE osm_transportation_name_linestring DROP COLUMN IF EXISTS old_source_ids;
|
||||
-- Restore temporary Merged-LineString to Source-LineStrings-ID columns
|
||||
UPDATE osm_transportation_name_linestring SET new_source_ids = NULL WHERE new_source_ids IS NOT NULL;
|
||||
UPDATE osm_transportation_name_linestring SET old_source_ids = NULL WHERE old_source_ids IS NOT NULL;
|
||||
|
||||
-- noinspection SqlWithoutWhere
|
||||
DELETE FROM transportation_name.name_changes;
|
||||
@@ -1290,10 +1296,6 @@ BEGIN
|
||||
CREATE INDEX ON clustered_linestrings_to_merge (cluster_group, cluster);
|
||||
ANALYZE clustered_linestrings_to_merge;
|
||||
|
||||
-- Create temporary Merged-LineString to Source-LineStrings-ID columns to store relations before they have been
|
||||
-- intersected
|
||||
ALTER TABLE osm_transportation_name_linestring ADD COLUMN IF NOT EXISTS new_source_ids BIGINT[];
|
||||
ALTER TABLE osm_transportation_name_linestring ADD COLUMN IF NOT EXISTS old_source_ids BIGINT[];
|
||||
|
||||
WITH inserted_linestrings AS (
|
||||
-- Merge LineStrings of each cluster and insert them
|
||||
@@ -1336,9 +1338,9 @@ BEGIN
|
||||
-- Cleanup remaining table
|
||||
DROP TABLE clustered_linestrings_to_merge;
|
||||
|
||||
-- Drop temporary Merged-LineString to Source-LineStrings-ID columns
|
||||
ALTER TABLE osm_transportation_name_linestring DROP COLUMN IF EXISTS new_source_ids;
|
||||
ALTER TABLE osm_transportation_name_linestring DROP COLUMN IF EXISTS old_source_ids;
|
||||
-- Restore temporary Merged-LineString to Source-LineStrings-ID columns
|
||||
UPDATE osm_transportation_name_linestring SET new_source_ids = NULL WHERE new_source_ids IS NOT NULL;
|
||||
UPDATE osm_transportation_name_linestring SET old_source_ids = NULL WHERE old_source_ids IS NOT NULL;
|
||||
|
||||
-- noinspection SqlWithoutWhere
|
||||
DELETE FROM transportation_name.shipway_changes;
|
||||
@@ -1472,10 +1474,6 @@ BEGIN
|
||||
CREATE INDEX ON clustered_linestrings_to_merge (cluster_group, cluster);
|
||||
ANALYZE clustered_linestrings_to_merge;
|
||||
|
||||
-- Create temporary Merged-LineString to Source-LineStrings-ID columns to store relations before they have been
|
||||
-- intersected
|
||||
ALTER TABLE osm_transportation_name_linestring ADD COLUMN IF NOT EXISTS new_source_ids BIGINT[];
|
||||
ALTER TABLE osm_transportation_name_linestring ADD COLUMN IF NOT EXISTS old_source_ids BIGINT[];
|
||||
|
||||
WITH inserted_linestrings AS (
|
||||
-- Merge LineStrings of each cluster and insert them
|
||||
@@ -1518,9 +1516,9 @@ BEGIN
|
||||
-- Cleanup remaining table
|
||||
DROP TABLE clustered_linestrings_to_merge;
|
||||
|
||||
-- Drop temporary Merged-LineString to Source-LineStrings-ID columns
|
||||
ALTER TABLE osm_transportation_name_linestring DROP COLUMN IF EXISTS new_source_ids;
|
||||
ALTER TABLE osm_transportation_name_linestring DROP COLUMN IF EXISTS old_source_ids;
|
||||
-- Restore temporary Merged-LineString to Source-LineStrings-ID columns
|
||||
UPDATE osm_transportation_name_linestring SET new_source_ids = NULL WHERE new_source_ids IS NOT NULL;
|
||||
UPDATE osm_transportation_name_linestring SET old_source_ids = NULL WHERE old_source_ids IS NOT NULL;
|
||||
|
||||
-- noinspection SqlWithoutWhere
|
||||
DELETE FROM transportation_name.aerialway_changes;
|
||||
|
||||
Reference in New Issue
Block a user