summaryrefslogtreecommitdiff
path: root/synapse/storage/databases/main/schema/delta/57/rooms_version_column_3.sql.postgres
blob: 92aaadde0d99a7a79d24adbbfb55fc7297d1549f (plain)
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
/* Copyright 2020 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.
 */

-- When we first added the room_version column to the rooms table, it was populated from
-- the current_state_events table. However, there was an issue causing a background
-- update to clean up the current_state_events table for rooms where the server is no
-- longer participating, before that column could be populated. Therefore, some rooms had
-- a NULL room_version.

-- The rooms_version_column_2.sql.* delta files were introduced to make the populating
-- synchronous instead of running it in a background update, which fixed this issue.
-- However, all of the instances of Synapse installed or updated in the meantime got
-- their rooms table corrupted with NULL room_versions.

-- This query fishes out the room versions from the create event using the state_events
-- table instead of the current_state_events one, as the former still have all of the
-- create events.

UPDATE rooms SET room_version=(
    SELECT COALESCE(json::json->'content'->>'room_version','1')
    FROM state_events se INNER JOIN event_json ej USING (event_id)
    WHERE se.room_id=rooms.room_id AND se.type='m.room.create' AND se.state_key=''
    LIMIT 1
) WHERE rooms.room_version IS NULL;

-- see also rooms_version_column_3.sql.sqlite which has a copy of the above query, using
-- sqlite syntax for the json extraction.