Skip to content

Commit

Permalink
Merge #527: Fix DB migration for SQLite. Backup secondary tables to a…
Browse files Browse the repository at this point in the history
…void losing data

094ab8a fix: linter errors (Jose Celano)
bd935b3 fix: [#526] DB migration for SQLite. Backup secondary tables (Jose Celano)

Pull request description:

  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`.

ACKs for top commit:
  josecelano:
    ACK 094ab8a

Tree-SHA512: 631a40ac3645c67430831a681e04d91c0dc4a62efe9bb65036abb3bf992c1bb289b7af7ca3ca417c4cec0911a64c778b0e0fffedfe7dbf9f5ba1c8af28933f23
  • Loading branch information
josecelano committed Mar 8, 2024
2 parents 0cc2663 + 094ab8a commit d535f79
Show file tree
Hide file tree
Showing 5 changed files with 101 additions and 18 deletions.
Original file line number Diff line number Diff line change
@@ -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,
Expand All @@ -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,
Expand Down Expand Up @@ -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;
-- 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;
8 changes: 4 additions & 4 deletions src/config.rs
Original file line number Diff line number Diff line change
Expand Up @@ -430,10 +430,10 @@ impl TorrustIndex {
}

pub fn remove_secrets(&mut self) {
self.tracker.token = "***".to_owned();
self.database.connect_url = "***".to_owned();
self.mail.password = "***".to_owned();
self.auth.secret_key = "***".to_owned();
"***".clone_into(&mut self.tracker.token);
"***".clone_into(&mut self.database.connect_url);
"***".clone_into(&mut self.mail.password);
"***".clone_into(&mut self.auth.secret_key);
}
}

Expand Down
2 changes: 1 addition & 1 deletion src/models/torrent_file.rs
Original file line number Diff line number Diff line change
Expand Up @@ -291,7 +291,7 @@ impl TorrentInfoDictionary {
.first()
.expect("vector `torrent_files` should have at least one element");

info_dict.md5sum = torrent_file.md5sum.clone();
info_dict.md5sum.clone_from(&torrent_file.md5sum); // DevSkim: ignore DS126858

info_dict.length = Some(torrent_file.length);

Expand Down
8 changes: 4 additions & 4 deletions tests/e2e/environment.rs
Original file line number Diff line number Diff line change
Expand Up @@ -90,10 +90,10 @@ impl TestEnv {
pub fn server_settings_masking_secrets(&self) -> Option<Settings> {
match self.starting_settings.clone() {
Some(mut settings) => {
settings.tracker.token = "***".to_owned();
settings.database.connect_url = "***".to_owned();
settings.mail.password = "***".to_owned();
settings.auth.secret_key = "***".to_owned();
"***".clone_into(&mut settings.tracker.token);
"***".clone_into(&mut settings.database.connect_url);
"***".clone_into(&mut settings.mail.password);
"***".clone_into(&mut settings.auth.secret_key);
Some(settings)
}
None => None,
Expand Down
4 changes: 2 additions & 2 deletions tests/e2e/web/api/v1/contexts/torrent/contract.rs
Original file line number Diff line number Diff line change
Expand Up @@ -238,7 +238,7 @@ mod for_guests {

// Upload the first torrent
let mut first_torrent = TestTorrent::with_custom_info_dict_field(id, &file_contents, "custom 01");
first_torrent.index_info.title = title.clone();
first_torrent.index_info.title.clone_from(&title);

let first_torrent_canonical_info_hash = upload_test_torrent(&client, &first_torrent)
.await
Expand Down Expand Up @@ -376,7 +376,7 @@ mod for_guests {

// Upload the first torrent
let mut first_torrent = TestTorrent::with_custom_info_dict_field(id, &file_contents, "custom 01");
first_torrent.index_info.title = title.clone();
first_torrent.index_info.title.clone_from(&title);

let first_torrent_canonical_info_hash = upload_test_torrent(&client, &first_torrent)
.await
Expand Down

0 comments on commit d535f79

Please sign in to comment.