From bd935b337c2e7a583cda626840e5bdb2e2bd3e86 Mon Sep 17 00:00:00 2001 From: Jose Celano Date: Fri, 8 Mar 2024 15:03:22 +0000 Subject: [PATCH] fix: [#526] DB migration for SQLite. Backup secondary tables The table `torrust_torrents` has 8 secondary tables that reference it with a foreign key: ```sql FOREIGN KEY("torrent_id") REFERENCES "torrust_torrents"("torrent_id") ON DELETE CASCADE, ``` The migration fixed in this commit creates a new table in order to alter it and drops the old one. However, when you drop the old table, SQLite uses an implicit DELETE query for the `torrust_torrents` table which triggers a DELETE ON CASCADE, deleting all the related records in secondary tables. The secondary tables are: - torrust_torrent_files - torrust_torrent_announce_urls - torrust_torrent_info - torrust_torrent_tracker_stats - torrust_torrent_tag_links - torrust_torrent_info_hashes - torrust_torrent_http_seeds - torrust_torrent_nodes These tables store the torrent file fiel together with the master `torrust_torrents`. --- ...orrust_add_independent_root_hash_field.sql | 97 +++++++++++++++++-- 1 file changed, 90 insertions(+), 7 deletions(-) diff --git a/migrations/sqlite3/20240305120015_torrust_add_independent_root_hash_field.sql b/migrations/sqlite3/20240305120015_torrust_add_independent_root_hash_field.sql index 0bec861f..b792d0f4 100644 --- a/migrations/sqlite3/20240305120015_torrust_add_independent_root_hash_field.sql +++ b/migrations/sqlite3/20240305120015_torrust_add_independent_root_hash_field.sql @@ -1,6 +1,68 @@ --- add field `root_hash` and make `pieces` nullable +PRAGMA foreign_keys = off; + +-- Step 1: backup secondary tables. They will be truncated because of the DELETE ON CASCADE +CREATE TEMPORARY TABLE IF NOT EXISTS "torrust_torrent_files_backup" ( + "file_id" INTEGER NOT NULL, + "torrent_id" INTEGER NOT NULL, + "md5sum" TEXT DEFAULT NULL, + "length" BIGINT NOT NULL, + "path" TEXT DEFAULT NULL +); +INSERT INTO torrust_torrent_files_backup SELECT * FROM torrust_torrent_files; + +CREATE TEMPORARY TABLE IF NOT EXISTS "torrust_torrent_announce_urls_backup" ( + "announce_url_id" INTEGER NOT NULL, + "torrent_id" INTEGER NOT NULL, + "tracker_url" TEXT NOT NULL +); +INSERT INTO torrust_torrent_announce_urls_backup SELECT * FROM torrust_torrent_announce_urls; + +CREATE TEMPORARY TABLE IF NOT EXISTS "torrust_torrent_info_backup" ( + "torrent_id" INTEGER NOT NULL, + "title" VARCHAR(256) NOT NULL UNIQUE, + "description" TEXT DEFAULT NULL +); +INSERT INTO torrust_torrent_info_backup SELECT * FROM torrust_torrent_info; + +CREATE TEMPORARY TABLE IF NOT EXISTS "torrust_torrent_tracker_stats_backup" ( + "torrent_id" INTEGER NOT NULL, + "tracker_url" VARCHAR(256) NOT NULL, + "seeders" INTEGER NOT NULL DEFAULT 0, + "leechers" INTEGER NOT NULL DEFAULT 0 +); +INSERT INTO torrust_torrent_tracker_stats_backup SELECT * FROM torrust_torrent_tracker_stats; + +CREATE TEMPORARY TABLE IF NOT EXISTS "torrust_torrent_tag_links_backup" ( + "torrent_id" INTEGER NOT NULL, + "tag_id" INTEGER NOT NULL +); +INSERT INTO torrust_torrent_tag_links_backup SELECT * FROM torrust_torrent_tag_links; + +CREATE TEMPORARY TABLE IF NOT EXISTS "torrust_torrent_info_hashes_backup" ( + "info_hash" TEXT NOT NULL, + "canonical_info_hash" TEXT NOT NULL, + "original_is_known" BOOLEAN NOT NULL +); +INSERT INTO torrust_torrent_info_hashes_backup SELECT * FROM torrust_torrent_info_hashes; + +CREATE TEMPORARY TABLE IF NOT EXISTS "torrust_torrent_http_seeds_backup" ( + "http_seed_id" INTEGER NOT NULL, + "torrent_id" INTEGER NOT NULL, + "seed_url" TEXT NOT NULL +); +INSERT INTO torrust_torrent_http_seeds_backup SELECT * FROM torrust_torrent_http_seeds; + +CREATE TEMPORARY TABLE IF NOT EXISTS "torrust_torrent_nodes_backup" ( + "node_id" INTEGER NOT NULL, + "torrent_id" INTEGER NOT NULL, + "node_ip" TEXT NOT NULL, + "node_port" INTEGER NOT NULL +); +INSERT INTO torrust_torrent_nodes_backup SELECT * FROM torrust_torrent_nodes; + +-- Step 2: Add field `root_hash` and make `pieces` nullable CREATE TABLE - "torrust_torrents_new" ( + IF NOT EXISTS "torrust_torrents_new" ( "torrent_id" INTEGER NOT NULL, "uploader_id" INTEGER NOT NULL, "category_id" INTEGER, @@ -23,7 +85,7 @@ CREATE TABLE PRIMARY KEY ("torrent_id" AUTOINCREMENT) ); --- Step 2: Copy data from the old table to the new table +-- Step 3: Copy data from the old table to the new table INSERT INTO torrust_torrents_new ( torrent_id, @@ -69,9 +131,30 @@ SELECT FROM torrust_torrents; --- Step 3: Drop the old table +-- Step 4: Drop the old table DROP TABLE torrust_torrents; --- Step 4: Rename the new table to the original name -ALTER TABLE torrust_torrents_new -RENAME TO torrust_torrents; \ No newline at end of file +-- Step 5: Rename the new table to the original name +ALTER TABLE torrust_torrents_new RENAME TO torrust_torrents; + +-- Step 6: Repopulate secondary tables from backup tables +INSERT INTO torrust_torrent_files SELECT * FROM torrust_torrent_files_backup; +INSERT INTO torrust_torrent_announce_urls SELECT * FROM torrust_torrent_announce_urls_backup; +INSERT INTO torrust_torrent_info SELECT * FROM torrust_torrent_info_backup; +INSERT INTO torrust_torrent_tracker_stats SELECT * FROM torrust_torrent_tracker_stats_backup; +INSERT INTO torrust_torrent_tag_links SELECT * FROM torrust_torrent_tag_links_backup; +INSERT INTO torrust_torrent_info_hashes SELECT * FROM torrust_torrent_info_hashes_backup; +INSERT INTO torrust_torrent_http_seeds SELECT * FROM torrust_torrent_http_seeds_backup; +INSERT INTO torrust_torrent_nodes SELECT * FROM torrust_torrent_nodes_backup; + +-- Step 7: Drop temporary secondary table backups +DROP TABLE torrust_torrent_files_backup; +DROP TABLE torrust_torrent_announce_urls_backup; +DROP TABLE torrust_torrent_info_backup; +DROP TABLE torrust_torrent_tracker_stats_backup; +DROP TABLE torrust_torrent_tag_links_backup; +DROP TABLE torrust_torrent_info_hashes_backup; +DROP TABLE torrust_torrent_http_seeds_backup; +DROP TABLE torrust_torrent_nodes_backup; + +PRAGMA foreign_keys = on; \ No newline at end of file