This repository has been archived by the owner on Apr 26, 2024. It is now read-only.
-
-
Notifications
You must be signed in to change notification settings - Fork 2.1k
Add a Postgres REPLICA IDENTITY
to tables that do not have an implicit one. This should allow use of Postgres logical replication.
#16456
Merged
Merged
Changes from all commits
Commits
Show all changes
12 commits
Select commit
Hold shift + click to select a range
d49dbb6
Add Postgres replica identities to tables that don't have an implicit…
reivilibre 6fcc720
Newsfile
reivilibre b725e34
Merge branch 'develop' into rei/replica_identities
reivilibre 2316a02
Move the delta to version 83 as we missed the boat for 82
reivilibre 89ebcd6
Add a test that all tables have a REPLICA IDENTITY
reivilibre 462f51b
Extend the test to include when indices are deleted
reivilibre 6b62ae4
isort
reivilibre 33cd8f8
black
reivilibre 1dff4fe
Fully qualify `oid` as it is a 'hidden attribute' in Postgres 11
reivilibre 7266814
Update tests/storage/test_database.py
reivilibre 0613b1e
Merge branch 'develop' into rei/replica_identities
reivilibre 46338e5
Add missed tables
reivilibre File filter
Filter by extension
Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1 @@ | ||
Add a Postgres `REPLICA IDENTITY` to tables that do not have an implicit one. This should allow use of Postgres logical replication. |
88 changes: 88 additions & 0 deletions
88
synapse/storage/schema/main/delta/83/04_replica_identities.sql.postgres
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,88 @@ | ||
/* Copyright 2023 The Matrix.org Foundation C.I.C | ||
* | ||
* Licensed under the Apache License, Version 2.0 (the "License"); | ||
* you may not use this file except in compliance with the License. | ||
* You may obtain a copy of the License at | ||
* | ||
* http://www.apache.org/licenses/LICENSE-2.0 | ||
* | ||
* Unless required by applicable law or agreed to in writing, software | ||
* distributed under the License is distributed on an "AS IS" BASIS, | ||
* WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. | ||
* See the License for the specific language governing permissions and | ||
* limitations under the License. | ||
*/ | ||
|
||
-- Annotate some tables in Postgres with a REPLICA IDENTITY. | ||
-- Any table that doesn't have a primary key should be annotated explicitly with | ||
-- a REPLICA IDENTITY so that logical replication can be used. | ||
-- If this is not done, then UPDATE and DELETE statements on those tables | ||
-- will fail if logical replication is in use. | ||
|
||
|
||
-- Where possible, re-use unique indices already defined on tables as a replica | ||
-- identity. | ||
ALTER TABLE appservice_room_list REPLICA IDENTITY USING INDEX appservice_room_list_idx; | ||
ALTER TABLE batch_events REPLICA IDENTITY USING INDEX chunk_events_event_id; | ||
ALTER TABLE blocked_rooms REPLICA IDENTITY USING INDEX blocked_rooms_idx; | ||
ALTER TABLE cache_invalidation_stream_by_instance REPLICA IDENTITY USING INDEX cache_invalidation_stream_by_instance_id; | ||
ALTER TABLE device_lists_changes_in_room REPLICA IDENTITY USING INDEX device_lists_changes_in_stream_id; | ||
ALTER TABLE device_lists_outbound_last_success REPLICA IDENTITY USING INDEX device_lists_outbound_last_success_unique_idx; | ||
ALTER TABLE device_lists_remote_cache REPLICA IDENTITY USING INDEX device_lists_remote_cache_unique_id; | ||
ALTER TABLE device_lists_remote_extremeties REPLICA IDENTITY USING INDEX device_lists_remote_extremeties_unique_idx; | ||
ALTER TABLE device_lists_remote_resync REPLICA IDENTITY USING INDEX device_lists_remote_resync_idx; | ||
ALTER TABLE e2e_cross_signing_keys REPLICA IDENTITY USING INDEX e2e_cross_signing_keys_stream_idx; | ||
ALTER TABLE e2e_room_keys REPLICA IDENTITY USING INDEX e2e_room_keys_with_version_idx; | ||
ALTER TABLE e2e_room_keys_versions REPLICA IDENTITY USING INDEX e2e_room_keys_versions_idx; | ||
ALTER TABLE erased_users REPLICA IDENTITY USING INDEX erased_users_user; | ||
ALTER TABLE event_relations REPLICA IDENTITY USING INDEX event_relations_id; | ||
ALTER TABLE federation_inbound_events_staging REPLICA IDENTITY USING INDEX federation_inbound_events_staging_instance_event; | ||
ALTER TABLE federation_stream_position REPLICA IDENTITY USING INDEX federation_stream_position_instance; | ||
ALTER TABLE ignored_users REPLICA IDENTITY USING INDEX ignored_users_uniqueness; | ||
ALTER TABLE insertion_events REPLICA IDENTITY USING INDEX insertion_events_event_id; | ||
ALTER TABLE insertion_event_extremities REPLICA IDENTITY USING INDEX insertion_event_extremities_event_id; | ||
ALTER TABLE monthly_active_users REPLICA IDENTITY USING INDEX monthly_active_users_users; | ||
ALTER TABLE ratelimit_override REPLICA IDENTITY USING INDEX ratelimit_override_idx; | ||
ALTER TABLE room_stats_earliest_token REPLICA IDENTITY USING INDEX room_stats_earliest_token_idx; | ||
ALTER TABLE room_stats_state REPLICA IDENTITY USING INDEX room_stats_state_room; | ||
ALTER TABLE stream_positions REPLICA IDENTITY USING INDEX stream_positions_idx; | ||
ALTER TABLE user_directory REPLICA IDENTITY USING INDEX user_directory_user_idx; | ||
ALTER TABLE user_directory_search REPLICA IDENTITY USING INDEX user_directory_search_user_idx; | ||
ALTER TABLE user_ips REPLICA IDENTITY USING INDEX user_ips_user_token_ip_unique_index; | ||
ALTER TABLE user_signature_stream REPLICA IDENTITY USING INDEX user_signature_stream_idx; | ||
ALTER TABLE users_in_public_rooms REPLICA IDENTITY USING INDEX users_in_public_rooms_u_idx; | ||
ALTER TABLE users_who_share_private_rooms REPLICA IDENTITY USING INDEX users_who_share_private_rooms_u_idx; | ||
ALTER TABLE user_threepid_id_server REPLICA IDENTITY USING INDEX user_threepid_id_server_idx; | ||
ALTER TABLE worker_locks REPLICA IDENTITY USING INDEX worker_locks_key; | ||
|
||
|
||
-- Where there are no unique indices, use the entire rows as replica identities. | ||
ALTER TABLE current_state_delta_stream REPLICA IDENTITY FULL; | ||
ALTER TABLE deleted_pushers REPLICA IDENTITY FULL; | ||
ALTER TABLE device_auth_providers REPLICA IDENTITY FULL; | ||
ALTER TABLE device_federation_inbox REPLICA IDENTITY FULL; | ||
ALTER TABLE device_federation_outbox REPLICA IDENTITY FULL; | ||
ALTER TABLE device_inbox REPLICA IDENTITY FULL; | ||
ALTER TABLE device_lists_outbound_pokes REPLICA IDENTITY FULL; | ||
ALTER TABLE device_lists_stream REPLICA IDENTITY FULL; | ||
ALTER TABLE e2e_cross_signing_signatures REPLICA IDENTITY FULL; | ||
ALTER TABLE event_auth_chain_links REPLICA IDENTITY FULL; | ||
ALTER TABLE event_auth REPLICA IDENTITY FULL; | ||
ALTER TABLE event_push_actions_staging REPLICA IDENTITY FULL; | ||
ALTER TABLE insertion_event_edges REPLICA IDENTITY FULL; | ||
ALTER TABLE local_media_repository_url_cache REPLICA IDENTITY FULL; | ||
ALTER TABLE presence_stream REPLICA IDENTITY FULL; | ||
ALTER TABLE push_rules_stream REPLICA IDENTITY FULL; | ||
ALTER TABLE room_alias_servers REPLICA IDENTITY FULL; | ||
ALTER TABLE stream_ordering_to_exterm REPLICA IDENTITY FULL; | ||
ALTER TABLE timeline_gaps REPLICA IDENTITY FULL; | ||
ALTER TABLE user_daily_visits REPLICA IDENTITY FULL; | ||
ALTER TABLE users_pending_deactivation REPLICA IDENTITY FULL; | ||
|
||
-- special cases: unique indices on nullable columns can't be used | ||
ALTER TABLE event_push_summary REPLICA IDENTITY FULL; | ||
ALTER TABLE event_search REPLICA IDENTITY FULL; | ||
ALTER TABLE local_media_repository_thumbnails REPLICA IDENTITY FULL; | ||
ALTER TABLE remote_media_cache_thumbnails REPLICA IDENTITY FULL; | ||
ALTER TABLE threepid_guest_access_tokens REPLICA IDENTITY FULL; | ||
ALTER TABLE user_filters REPLICA IDENTITY FULL; -- sadly the `CHECK` constraint is not enough here |
30 changes: 30 additions & 0 deletions
30
synapse/storage/schema/state/delta/83/05_replica_identities_in_state_db.sql.postgres
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,30 @@ | ||
/* Copyright 2023 The Matrix.org Foundation C.I.C | ||
* | ||
* Licensed under the Apache License, Version 2.0 (the "License"); | ||
* you may not use this file except in compliance with the License. | ||
* You may obtain a copy of the License at | ||
* | ||
* http://www.apache.org/licenses/LICENSE-2.0 | ||
* | ||
* Unless required by applicable law or agreed to in writing, software | ||
* distributed under the License is distributed on an "AS IS" BASIS, | ||
* WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. | ||
* See the License for the specific language governing permissions and | ||
* limitations under the License. | ||
*/ | ||
|
||
-- Annotate some tables in Postgres with a REPLICA IDENTITY. | ||
-- Any table that doesn't have a primary key should be annotated explicitly with | ||
-- a REPLICA IDENTITY so that logical replication can be used. | ||
-- If this is not done, then UPDATE and DELETE statements on those tables | ||
-- will fail if logical replication is in use. | ||
-- See also: 82/04_replica_identities.sql.postgres on the main database | ||
|
||
|
||
-- Where possible, re-use unique indices already defined on tables as a replica | ||
-- identity. | ||
ALTER TABLE state_group_edges REPLICA IDENTITY USING INDEX state_group_edges_unique_idx; | ||
|
||
|
||
-- Where there are no unique indices, use the entire rows as replica identities. | ||
ALTER TABLE state_groups_state REPLICA IDENTITY FULL; |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Oops, something went wrong.
Add this suggestion to a batch that can be applied as a single commit.
This suggestion is invalid because no changes were made to the code.
Suggestions cannot be applied while the pull request is closed.
Suggestions cannot be applied while viewing a subset of changes.
Only one suggestion per line can be applied in a batch.
Add this suggestion to a batch that can be applied as a single commit.
Applying suggestions on deleted lines is not supported.
You must change the existing code in this line in order to create a valid suggestion.
Outdated suggestions cannot be applied.
This suggestion has been applied or marked resolved.
Suggestions cannot be applied from pending reviews.
Suggestions cannot be applied on multi-line comments.
Suggestions cannot be applied while the pull request is queued to merge.
Suggestion cannot be applied right now. Please check back later.
There was a problem hiding this comment.
Choose a reason for hiding this comment
The reason will be displayed to describe this comment to others. Learn more.
Ah I think these will all go away in #16522, but no reason not to have it be correct for now.
There was a problem hiding this comment.
Choose a reason for hiding this comment
The reason will be displayed to describe this comment to others. Learn more.
ohhhh that's why these were there a while ago, went away and now came back