|
| 1 | +-- SPDX-FileCopyrightText: Copyright (C) 2018-2025 Uwe Klotz <uwedotklotzatgmaildotcom> et al. |
| 2 | +-- SPDX-License-Identifier: AGPL-3.0-or-later |
| 3 | + |
| 4 | +-- Rename and re-create the table as proposed here: https://www.sqlite.org/lang_altertable.html |
| 5 | + |
| 6 | +-- !!!This pragma is a no-op within a transaction!!! |
| 7 | +-- Migrations are usually run within a transaction. |
| 8 | +PRAGMA foreign_keys = OFF; |
| 9 | + |
| 10 | +CREATE TABLE IF NOT EXISTS playlist_migrate ( |
| 11 | + -- row header (immutable) |
| 12 | + row_id INTEGER PRIMARY KEY, |
| 13 | + row_created_ms INTEGER NOT NULL, |
| 14 | + -- row header (mutable) |
| 15 | + row_updated_ms INTEGER NOT NULL, |
| 16 | + -- entity header (immutable) |
| 17 | + entity_uid TEXT NOT NULL, -- ULID |
| 18 | + -- entity header (mutable) |
| 19 | + entity_rev INTEGER NOT NULL, -- RevisionNumber |
| 20 | + -- relations (immutable) |
| 21 | + collection_id INTEGER, |
| 22 | + -- properties (mutable) |
| 23 | + title TEXT NOT NULL, |
| 24 | + kind TEXT, |
| 25 | + notes TEXT, |
| 26 | + color_rgb INTEGER, -- 0xRRGGBB (hex) |
| 27 | + color_idx INTEGER, -- palette index |
| 28 | + flags INTEGER NOT NULL, -- bitmask of flags, e.g. locking to prevent unintended modifications |
| 29 | + -- |
| 30 | + FOREIGN KEY(collection_id) REFERENCES collection(row_id) ON DELETE CASCADE |
| 31 | +) STRICT; |
| 32 | +INSERT INTO playlist_migrate SELECT * FROM playlist; |
| 33 | +DROP TABLE playlist; |
| 34 | +ALTER TABLE playlist_migrate RENAME TO playlist; |
| 35 | + |
| 36 | +-- Verify that all foreign key constraints are still valid. |
| 37 | +PRAGMA foreign_key_check; |
| 38 | + |
| 39 | +-- !!!This pragma is a no-op within a transaction!!! |
| 40 | +-- Migrations are usually run within a transaction. |
| 41 | +PRAGMA foreign_keys = ON; |
| 42 | + |
| 43 | +-- Only the last revision is stored. |
| 44 | +CREATE UNIQUE INDEX udx_playlist_entity_uid ON collection ( |
| 45 | + entity_uid |
| 46 | +); |
| 47 | + |
| 48 | +-- NULL values are considered as distinct for UNIQUE indexes. |
| 49 | +-- |
| 50 | +-- See also: |
| 51 | +-- - https://www.sqlite.org/nulls.html |
| 52 | +-- - https://www.sqlite.org/partialindex.html |
| 53 | +CREATE UNIQUE INDEX udx_playlist_collection_id_title_where_kind_null ON playlist ( |
| 54 | + collection_id, |
| 55 | + title |
| 56 | +) WHERE kind IS NULL; |
| 57 | +CREATE UNIQUE INDEX udx_playlist_collection_id_title_kind ON playlist ( |
| 58 | + collection_id, |
| 59 | + title, |
| 60 | + kind |
| 61 | +) WHERE kind IS NOT NULL; |
| 62 | + |
| 63 | +CREATE INDEX idx_playlist_row_created_ms_desc ON playlist ( |
| 64 | + row_created_ms DESC |
| 65 | +); |
| 66 | + |
| 67 | +CREATE INDEX idx_playlist_row_updated_ms_desc ON playlist ( |
| 68 | + row_updated_ms DESC |
| 69 | +); |
| 70 | + |
| 71 | +CREATE INDEX idx_playlist_kind_title ON playlist ( |
| 72 | + kind, |
| 73 | + title |
| 74 | +) WHERE kind IS NOT NULL; |
| 75 | + |
| 76 | +CREATE INDEX idx_playlist_title ON playlist ( |
| 77 | + title |
| 78 | +); |
0 commit comments