kopia lustrzana https://github.com/openmaptiles/openmaptiles
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>pull/1718/head
rodzic
e6a1000155
commit
f70ae783b2
|
@ -149,7 +149,7 @@ BEGIN
|
|||
|
||||
-- Analyze tracking and source tables before performing update
|
||||
ANALYZE osm_park_polygon_gen_z4;
|
||||
REFRESH MATERIALIZED VIEW osm_park_polygon_dissolve_z4;
|
||||
REFRESH MATERIALIZED VIEW CONCURRENTLY osm_park_polygon_dissolve_z4;
|
||||
|
||||
-- noinspection SqlWithoutWhere
|
||||
DELETE FROM park_polygon.updates;
|
||||
|
|
|
@ -144,6 +144,8 @@ CREATE TABLE IF NOT EXISTS osm_transportation_merge_linestring_gen_z11(
|
|||
id SERIAL,
|
||||
osm_id bigint,
|
||||
source_ids bigint[],
|
||||
new_source_ids bigint[],
|
||||
old_source_ids bigint[],
|
||||
highway character varying,
|
||||
network character varying,
|
||||
construction character varying,
|
||||
|
@ -163,6 +165,13 @@ CREATE TABLE IF NOT EXISTS osm_transportation_merge_linestring_gen_z11(
|
|||
);
|
||||
|
||||
ALTER TABLE osm_transportation_merge_linestring_gen_z11 ADD COLUMN IF NOT EXISTS source_ids bigint[];
|
||||
ALTER TABLE osm_transportation_merge_linestring_gen_z11 ADD COLUMN IF NOT EXISTS new_source_ids BIGINT[];
|
||||
ALTER TABLE osm_transportation_merge_linestring_gen_z11 ADD COLUMN IF NOT EXISTS old_source_ids BIGINT[];
|
||||
|
||||
CREATE INDEX IF NOT EXISTS osm_transportation_merge_linestring_gen_z11_n_source_ids_not_null_idx
|
||||
ON osm_transportation_merge_linestring_gen_z11 ((new_source_ids IS NOT NULL));
|
||||
CREATE INDEX IF NOT EXISTS osm_transportation_merge_linestring_gen_z11_o_source_ids_not_null_idx
|
||||
ON osm_transportation_merge_linestring_gen_z11 ((old_source_ids IS NOT NULL));
|
||||
|
||||
-- Create osm_transportation_merge_linestring_gen_z10 as a copy of osm_transportation_merge_linestring_gen_z11 but
|
||||
-- drop the "source_ids" column. This can be done because z10 and z9 tables are only simplified and not merged,
|
||||
|
@ -170,6 +179,8 @@ ALTER TABLE osm_transportation_merge_linestring_gen_z11 ADD COLUMN IF NOT EXISTS
|
|||
CREATE TABLE IF NOT EXISTS osm_transportation_merge_linestring_gen_z10
|
||||
(LIKE osm_transportation_merge_linestring_gen_z11);
|
||||
ALTER TABLE osm_transportation_merge_linestring_gen_z10 DROP COLUMN IF EXISTS source_ids;
|
||||
ALTER TABLE osm_transportation_merge_linestring_gen_z10 DROP COLUMN IF EXISTS new_source_ids;
|
||||
ALTER TABLE osm_transportation_merge_linestring_gen_z10 DROP COLUMN IF EXISTS old_source_ids;
|
||||
|
||||
-- Create osm_transportation_merge_linestring_gen_z9 as a copy of osm_transportation_merge_linestring_gen_z10
|
||||
CREATE TABLE IF NOT EXISTS osm_transportation_merge_linestring_gen_z9
|
||||
|
@ -469,6 +480,8 @@ CREATE TABLE IF NOT EXISTS osm_transportation_merge_linestring_gen_z8(
|
|||
id SERIAL,
|
||||
osm_id bigint,
|
||||
source_ids int[],
|
||||
new_source_ids bigint[],
|
||||
old_source_ids bigint[],
|
||||
highway character varying,
|
||||
network character varying,
|
||||
construction character varying,
|
||||
|
@ -480,6 +493,13 @@ CREATE TABLE IF NOT EXISTS osm_transportation_merge_linestring_gen_z8(
|
|||
);
|
||||
|
||||
ALTER TABLE osm_transportation_merge_linestring_gen_z8 ADD COLUMN IF NOT EXISTS source_ids bigint[];
|
||||
ALTER TABLE osm_transportation_merge_linestring_gen_z8 ADD COLUMN IF NOT EXISTS new_source_ids bigint[];
|
||||
ALTER TABLE osm_transportation_merge_linestring_gen_z8 ADD COLUMN IF NOT EXISTS old_source_ids bigint[];
|
||||
|
||||
CREATE INDEX IF NOT EXISTS osm_transportation_merge_linestring_gen_z8_n_source_ids_not_null_idx
|
||||
ON osm_transportation_merge_linestring_gen_z8 ((new_source_ids IS NOT NULL));
|
||||
CREATE INDEX IF NOT EXISTS osm_transportation_merge_linestring_gen_z8_o_source_ids_not_null_idx
|
||||
ON osm_transportation_merge_linestring_gen_z8 ((old_source_ids IS NOT NULL));
|
||||
|
||||
-- Create osm_transportation_merge_linestring_gen_z7 as a copy of osm_transportation_merge_linestring_gen_z8 but
|
||||
-- drop the "source_ids" column. This can be done because z7 to z5 tables are only simplified and not merged,
|
||||
|
@ -487,6 +507,8 @@ ALTER TABLE osm_transportation_merge_linestring_gen_z8 ADD COLUMN IF NOT EXISTS
|
|||
CREATE TABLE IF NOT EXISTS osm_transportation_merge_linestring_gen_z7
|
||||
(LIKE osm_transportation_merge_linestring_gen_z8);
|
||||
ALTER TABLE osm_transportation_merge_linestring_gen_z7 DROP COLUMN IF EXISTS source_ids;
|
||||
ALTER TABLE osm_transportation_merge_linestring_gen_z7 DROP COLUMN IF EXISTS new_source_ids;
|
||||
ALTER TABLE osm_transportation_merge_linestring_gen_z7 DROP COLUMN IF EXISTS old_source_ids;
|
||||
|
||||
-- Create osm_transportation_merge_linestring_gen_z6 as a copy of osm_transportation_merge_linestring_gen_z7
|
||||
CREATE TABLE IF NOT EXISTS osm_transportation_merge_linestring_gen_z6
|
||||
|
@ -1116,11 +1138,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_merge_linestring_gen_z11 ADD COLUMN IF NOT EXISTS new_source_ids BIGINT[];
|
||||
ALTER TABLE osm_transportation_merge_linestring_gen_z11 ADD COLUMN IF NOT EXISTS old_source_ids BIGINT[];
|
||||
|
||||
WITH inserted_linestrings AS (
|
||||
-- Merge LineStrings of each cluster and insert them
|
||||
INSERT INTO osm_transportation_merge_linestring_gen_z11(geometry, new_source_ids, old_source_ids, highway,
|
||||
|
@ -1180,9 +1197,9 @@ BEGIN
|
|||
-- Cleanup remaining table
|
||||
DROP TABLE clustered_linestrings_to_merge;
|
||||
|
||||
-- Drop temporary Merged-LineString to Source-LineStrings-ID columns
|
||||
ALTER TABLE osm_transportation_merge_linestring_gen_z11 DROP COLUMN IF EXISTS new_source_ids;
|
||||
ALTER TABLE osm_transportation_merge_linestring_gen_z11 DROP COLUMN IF EXISTS old_source_ids;
|
||||
-- Restore temporary Merged-LineString to Source-LineStrings-ID columns
|
||||
UPDATE osm_transportation_merge_linestring_gen_z11 SET new_source_ids = NULL WHERE new_source_ids IS NOT NULL;
|
||||
UPDATE osm_transportation_merge_linestring_gen_z11 SET old_source_ids = NULL WHERE old_source_ids IS NOT NULL;
|
||||
|
||||
-- noinspection SqlWithoutWhere
|
||||
DELETE FROM transportation.changes_z11;
|
||||
|
@ -1414,9 +1431,6 @@ BEGIN
|
|||
|
||||
-- Create temporary Merged-LineString to Source-LineStrings-ID columns to store relations before they have been
|
||||
-- intersected
|
||||
ALTER TABLE osm_transportation_merge_linestring_gen_z8 ADD COLUMN IF NOT EXISTS new_source_ids INT[];
|
||||
ALTER TABLE osm_transportation_merge_linestring_gen_z8 ADD COLUMN IF NOT EXISTS old_source_ids INT[];
|
||||
|
||||
WITH inserted_linestrings AS (
|
||||
-- Merge LineStrings of each cluster and insert them
|
||||
INSERT INTO osm_transportation_merge_linestring_gen_z8(geometry, new_source_ids, old_source_ids, highway,
|
||||
|
@ -1466,10 +1480,10 @@ BEGIN
|
|||
-- Cleanup
|
||||
DROP TABLE clustered_linestrings_to_merge;
|
||||
|
||||
-- Drop temporary Merged-LineString to Source-LineStrings-ID columns
|
||||
ALTER TABLE osm_transportation_merge_linestring_gen_z8 DROP COLUMN IF EXISTS new_source_ids;
|
||||
ALTER TABLE osm_transportation_merge_linestring_gen_z8 DROP COLUMN IF EXISTS old_source_ids;
|
||||
-- Restore temporary Merged-LineString to Source-LineStrings-ID columns
|
||||
|
||||
UPDATE osm_transportation_merge_linestring_gen_z8 SET new_source_ids = NULL WHERE new_source_ids IS NOT NULL;
|
||||
UPDATE osm_transportation_merge_linestring_gen_z8 SET old_source_ids = NULL WHERE old_source_ids IS NOT NULL;
|
||||
-- noinspection SqlWithoutWhere
|
||||
DELETE FROM transportation.changes_z9;
|
||||
-- noinspection SqlWithoutWhere
|
||||
|
|
|
@ -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;
|
||||
|
|
|
@ -21,6 +21,8 @@ CREATE TABLE IF NOT EXISTS osm_important_waterway_linestring (
|
|||
id SERIAL,
|
||||
geometry geometry('LineString'),
|
||||
source_ids bigint[],
|
||||
new_source_ids bigint[],
|
||||
old_source_ids bigint[],
|
||||
name varchar,
|
||||
name_en varchar,
|
||||
name_de varchar,
|
||||
|
@ -28,6 +30,15 @@ CREATE TABLE IF NOT EXISTS osm_important_waterway_linestring (
|
|||
);
|
||||
|
||||
ALTER TABLE osm_important_waterway_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_important_waterway_linestring ADD COLUMN IF NOT EXISTS new_source_ids BIGINT[];
|
||||
ALTER TABLE osm_important_waterway_linestring ADD COLUMN IF NOT EXISTS old_source_ids BIGINT[];
|
||||
|
||||
CREATE INDEX IF NOT EXISTS osm_important_waterway_linestring_n_source_ids_not_null_idx
|
||||
ON osm_important_waterway_linestring ((new_source_ids IS NOT NULL));
|
||||
CREATE INDEX IF NOT EXISTS osm_important_waterway_linestring_o_source_ids_not_null_idx
|
||||
ON osm_important_waterway_linestring ((old_source_ids IS NOT NULL));
|
||||
|
||||
-- Create osm_important_waterway_linestring_gen_z11 as a copy of osm_important_waterway_linestring but drop the
|
||||
-- "source_ids" column. This can be done because z10 and z9 tables are only simplified and not merged, therefore
|
||||
|
@ -35,6 +46,8 @@ ALTER TABLE osm_important_waterway_linestring ADD COLUMN IF NOT EXISTS source_id
|
|||
CREATE TABLE IF NOT EXISTS osm_important_waterway_linestring_gen_z11
|
||||
(LIKE osm_important_waterway_linestring);
|
||||
ALTER TABLE osm_important_waterway_linestring_gen_z11 DROP COLUMN IF EXISTS source_ids;
|
||||
ALTER TABLE osm_important_waterway_linestring_gen_z11 DROP COLUMN IF EXISTS new_source_ids;
|
||||
ALTER TABLE osm_important_waterway_linestring_gen_z11 DROP COLUMN IF EXISTS old_source_ids;
|
||||
|
||||
-- Create osm_important_waterway_linestring_gen_z10 as a copy of osm_important_waterway_linestring_gen_z11
|
||||
CREATE TABLE IF NOT EXISTS osm_important_waterway_linestring_gen_z10
|
||||
|
@ -478,10 +491,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_important_waterway_linestring ADD COLUMN IF NOT EXISTS new_source_ids BIGINT[];
|
||||
ALTER TABLE osm_important_waterway_linestring ADD COLUMN IF NOT EXISTS old_source_ids BIGINT[];
|
||||
|
||||
WITH inserted_linestrings AS (
|
||||
-- Merge LineStrings of each cluster and insert them
|
||||
|
@ -527,9 +536,9 @@ BEGIN
|
|||
-- Cleanup remaining table
|
||||
DROP TABLE clustered_linestrings_to_merge;
|
||||
|
||||
-- Drop temporary Merged-LineString to Source-LineStrings-ID columns
|
||||
ALTER TABLE osm_important_waterway_linestring DROP COLUMN IF EXISTS new_source_ids;
|
||||
ALTER TABLE osm_important_waterway_linestring DROP COLUMN IF EXISTS old_source_ids;
|
||||
-- Restore temporary Merged-LineString to Source-LineStrings-ID columns
|
||||
UPDATE osm_important_waterway_linestring SET new_source_ids = NULL WHERE new_source_ids IS NOT NULL;
|
||||
UPDATE osm_important_waterway_linestring SET old_source_ids = NULL WHERE old_source_ids IS NOT NULL;
|
||||
|
||||
-- noinspection SqlWithoutWhere
|
||||
DELETE FROM waterway_important.changes;
|
||||
|
|
Ładowanie…
Reference in New Issue