mirror of
https://github.com/stashapp/stash.git
synced 2025-12-17 20:34:37 +03:00
File storage rewrite (#2676)
* Restructure data layer part 2 (#2599) * Refactor and separate image model * Refactor image query builder * Handle relationships in image query builder * Remove relationship management methods * Refactor gallery model/query builder * Add scenes to gallery model * Convert scene model * Refactor scene models * Remove unused methods * Add unit tests for gallery * Add image tests * Add scene tests * Convert unnecessary scene value pointers to values * Convert unnecessary pointer values to values * Refactor scene partial * Add scene partial tests * Refactor ImagePartial * Add image partial tests * Refactor gallery partial update * Add partial gallery update tests * Use zero/null package for null values * Add files and scan system * Add sqlite implementation for files/folders * Add unit tests for files/folders * Image refactors * Update image data layer * Refactor gallery model and creation * Refactor scene model * Refactor scenes * Don't set title from filename * Allow galleries to freely add/remove images * Add multiple scene file support to graphql and UI * Add multiple file support for images in graphql/UI * Add multiple file for galleries in graphql/UI * Remove use of some deprecated fields * Remove scene path usage * Remove gallery path usage * Remove path from image * Move funscript to video file * Refactor caption detection * Migrate existing data * Add post commit/rollback hook system * Lint. Comment out import/export tests * Add WithDatabase read only wrapper * Prepend tasks to list * Add 32 pre-migration * Add warnings in release and migration notes
This commit is contained in:
676
pkg/sqlite/migrations/32_files.up.sql
Normal file
676
pkg/sqlite/migrations/32_files.up.sql
Normal file
@@ -0,0 +1,676 @@
|
||||
-- folders may be deleted independently. Don't cascade
|
||||
CREATE TABLE `folders` (
|
||||
`id` integer not null primary key autoincrement,
|
||||
`path` varchar(255) NOT NULL,
|
||||
`parent_folder_id` integer,
|
||||
`mod_time` datetime not null,
|
||||
`created_at` datetime not null,
|
||||
`updated_at` datetime not null,
|
||||
foreign key(`parent_folder_id`) references `folders`(`id`) on delete SET NULL
|
||||
);
|
||||
|
||||
CREATE INDEX `index_folders_on_parent_folder_id` on `folders` (`parent_folder_id`);
|
||||
|
||||
-- require reference folders/zip files to be deleted manually first
|
||||
CREATE TABLE `files` (
|
||||
`id` integer not null primary key autoincrement,
|
||||
`basename` varchar(255) NOT NULL,
|
||||
`zip_file_id` integer,
|
||||
`parent_folder_id` integer not null,
|
||||
`size` integer NOT NULL,
|
||||
`mod_time` datetime not null,
|
||||
`created_at` datetime not null,
|
||||
`updated_at` datetime not null,
|
||||
foreign key(`parent_folder_id`) references `folders`(`id`),
|
||||
foreign key(`zip_file_id`) references `files`(`id`),
|
||||
CHECK (`basename` != '')
|
||||
);
|
||||
|
||||
CREATE UNIQUE INDEX `index_files_zip_basename_unique` ON `files` (`zip_file_id`, `parent_folder_id`, `basename`);
|
||||
CREATE INDEX `index_files_on_parent_folder_id_basename` on `files` (`parent_folder_id`, `basename`);
|
||||
CREATE INDEX `index_files_on_basename` on `files` (`basename`);
|
||||
|
||||
ALTER TABLE `folders` ADD COLUMN `zip_file_id` integer REFERENCES `files`(`id`);
|
||||
CREATE UNIQUE INDEX `index_folders_path_unique` on `folders` (`zip_file_id`, `path`);
|
||||
|
||||
CREATE TABLE `files_fingerprints` (
|
||||
`file_id` integer NOT NULL,
|
||||
`type` varchar(255) NOT NULL,
|
||||
`fingerprint` blob NOT NULL,
|
||||
foreign key(`file_id`) references `files`(`id`) on delete CASCADE,
|
||||
PRIMARY KEY (`file_id`, `type`, `fingerprint`)
|
||||
);
|
||||
|
||||
CREATE INDEX `index_fingerprint_type_fingerprint` ON `files_fingerprints` (`type`, `fingerprint`);
|
||||
|
||||
CREATE TABLE `video_files` (
|
||||
`file_id` integer NOT NULL primary key,
|
||||
`duration` float NOT NULL,
|
||||
`video_codec` varchar(255) NOT NULL,
|
||||
`format` varchar(255) NOT NULL,
|
||||
`audio_codec` varchar(255) NOT NULL,
|
||||
`width` tinyint NOT NULL,
|
||||
`height` tinyint NOT NULL,
|
||||
`frame_rate` float NOT NULL,
|
||||
`bit_rate` integer NOT NULL,
|
||||
`interactive` boolean not null default '0',
|
||||
`interactive_speed` int,
|
||||
foreign key(`file_id`) references `files`(`id`) on delete CASCADE
|
||||
);
|
||||
|
||||
CREATE TABLE `video_captions` (
|
||||
`file_id` integer NOT NULL,
|
||||
`language_code` varchar(255) NOT NULL,
|
||||
`filename` varchar(255) NOT NULL,
|
||||
`caption_type` varchar(255) NOT NULL,
|
||||
primary key (`file_id`, `language_code`, `caption_type`),
|
||||
foreign key(`file_id`) references `video_files`(`file_id`) on delete CASCADE
|
||||
);
|
||||
|
||||
CREATE TABLE `image_files` (
|
||||
`file_id` integer NOT NULL primary key,
|
||||
`format` varchar(255) NOT NULL,
|
||||
`width` tinyint NOT NULL,
|
||||
`height` tinyint NOT NULL,
|
||||
foreign key(`file_id`) references `files`(`id`) on delete CASCADE
|
||||
);
|
||||
|
||||
CREATE TABLE `images_files` (
|
||||
`image_id` integer NOT NULL,
|
||||
`file_id` integer NOT NULL,
|
||||
`primary` boolean NOT NULL,
|
||||
foreign key(`image_id`) references `images`(`id`) on delete CASCADE,
|
||||
foreign key(`file_id`) references `files`(`id`) on delete CASCADE,
|
||||
PRIMARY KEY(`image_id`, `file_id`)
|
||||
);
|
||||
|
||||
CREATE INDEX `index_images_files_file_id` ON `images_files` (`file_id`);
|
||||
|
||||
CREATE TABLE `galleries_files` (
|
||||
`gallery_id` integer NOT NULL,
|
||||
`file_id` integer NOT NULL,
|
||||
`primary` boolean NOT NULL,
|
||||
foreign key(`gallery_id`) references `galleries`(`id`) on delete CASCADE,
|
||||
foreign key(`file_id`) references `files`(`id`) on delete CASCADE,
|
||||
PRIMARY KEY(`gallery_id`, `file_id`)
|
||||
);
|
||||
|
||||
CREATE INDEX `index_galleries_files_file_id` ON `galleries_files` (`file_id`);
|
||||
|
||||
CREATE TABLE `scenes_files` (
|
||||
`scene_id` integer NOT NULL,
|
||||
`file_id` integer NOT NULL,
|
||||
`primary` boolean NOT NULL,
|
||||
foreign key(`scene_id`) references `scenes`(`id`) on delete CASCADE,
|
||||
foreign key(`file_id`) references `files`(`id`) on delete CASCADE,
|
||||
PRIMARY KEY(`scene_id`, `file_id`)
|
||||
);
|
||||
|
||||
CREATE INDEX `index_scenes_files_file_id` ON `scenes_files` (`file_id`);
|
||||
|
||||
PRAGMA foreign_keys=OFF;
|
||||
|
||||
CREATE TABLE `images_new` (
|
||||
`id` integer not null primary key autoincrement,
|
||||
-- REMOVED: `path` varchar(510) not null,
|
||||
-- REMOVED: `checksum` varchar(255) not null,
|
||||
`title` varchar(255),
|
||||
`rating` tinyint,
|
||||
-- REMOVED: `size` integer,
|
||||
-- REMOVED: `width` tinyint,
|
||||
-- REMOVED: `height` tinyint,
|
||||
`studio_id` integer,
|
||||
`o_counter` tinyint not null default 0,
|
||||
`organized` boolean not null default '0',
|
||||
-- REMOVED: `file_mod_time` datetime,
|
||||
`created_at` datetime not null,
|
||||
`updated_at` datetime not null,
|
||||
foreign key(`studio_id`) references `studios`(`id`) on delete SET NULL
|
||||
);
|
||||
|
||||
INSERT INTO `images_new`
|
||||
(
|
||||
`id`,
|
||||
`title`,
|
||||
`rating`,
|
||||
`studio_id`,
|
||||
`o_counter`,
|
||||
`organized`,
|
||||
`created_at`,
|
||||
`updated_at`
|
||||
)
|
||||
SELECT
|
||||
`id`,
|
||||
`title`,
|
||||
`rating`,
|
||||
`studio_id`,
|
||||
`o_counter`,
|
||||
`organized`,
|
||||
`created_at`,
|
||||
`updated_at`
|
||||
FROM `images`;
|
||||
|
||||
-- create temporary placeholder folder
|
||||
INSERT INTO `folders` (`path`, `mod_time`, `created_at`, `updated_at`) VALUES ('', '1970-01-01 00:00:00', '1970-01-01 00:00:00', '1970-01-01 00:00:00');
|
||||
|
||||
-- insert image files - we will fix these up in the post-migration
|
||||
INSERT INTO `files`
|
||||
(
|
||||
`basename`,
|
||||
`parent_folder_id`,
|
||||
`size`,
|
||||
`mod_time`,
|
||||
`created_at`,
|
||||
`updated_at`
|
||||
)
|
||||
SELECT
|
||||
`path`,
|
||||
1,
|
||||
COALESCE(`size`, 0),
|
||||
-- set mod time to epoch so that it the format/size is calculated on scan
|
||||
'1970-01-01 00:00:00',
|
||||
`created_at`,
|
||||
`updated_at`
|
||||
FROM `images`;
|
||||
|
||||
INSERT INTO `image_files`
|
||||
(
|
||||
`file_id`,
|
||||
`format`,
|
||||
`width`,
|
||||
`height`
|
||||
)
|
||||
SELECT
|
||||
`files`.`id`,
|
||||
'',
|
||||
COALESCE(`images`.`width`, 0),
|
||||
COALESCE(`images`.`height`, 0)
|
||||
FROM `images` INNER JOIN `files` ON `images`.`path` = `files`.`basename` AND `files`.`parent_folder_id` = 1;
|
||||
|
||||
INSERT INTO `images_files`
|
||||
(
|
||||
`image_id`,
|
||||
`file_id`,
|
||||
`primary`
|
||||
)
|
||||
SELECT
|
||||
`images`.`id`,
|
||||
`files`.`id`,
|
||||
1
|
||||
FROM `images` INNER JOIN `files` ON `images`.`path` = `files`.`basename` AND `files`.`parent_folder_id` = 1;
|
||||
|
||||
INSERT INTO `files_fingerprints`
|
||||
(
|
||||
`file_id`,
|
||||
`type`,
|
||||
`fingerprint`
|
||||
)
|
||||
SELECT
|
||||
`files`.`id`,
|
||||
'md5',
|
||||
`images`.`checksum`
|
||||
FROM `images` INNER JOIN `files` ON `images`.`path` = `files`.`basename` AND `files`.`parent_folder_id` = 1;
|
||||
|
||||
DROP TABLE `images`;
|
||||
ALTER TABLE `images_new` rename to `images`;
|
||||
|
||||
CREATE INDEX `index_images_on_studio_id` on `images` (`studio_id`);
|
||||
|
||||
|
||||
CREATE TABLE `galleries_new` (
|
||||
`id` integer not null primary key autoincrement,
|
||||
-- REMOVED: `path` varchar(510),
|
||||
-- REMOVED: `checksum` varchar(255) not null,
|
||||
-- REMOVED: `zip` boolean not null default '0',
|
||||
`folder_id` integer,
|
||||
`title` varchar(255),
|
||||
`url` varchar(255),
|
||||
`date` date,
|
||||
`details` text,
|
||||
`studio_id` integer,
|
||||
`rating` tinyint,
|
||||
-- REMOVED: `file_mod_time` datetime,
|
||||
`organized` boolean not null default '0',
|
||||
`created_at` datetime not null,
|
||||
`updated_at` datetime not null,
|
||||
foreign key(`studio_id`) references `studios`(`id`) on delete SET NULL,
|
||||
foreign key(`folder_id`) references `folders`(`id`) on delete SET NULL
|
||||
);
|
||||
|
||||
INSERT INTO `galleries_new`
|
||||
(
|
||||
`id`,
|
||||
`title`,
|
||||
`url`,
|
||||
`date`,
|
||||
`details`,
|
||||
`studio_id`,
|
||||
`rating`,
|
||||
`organized`,
|
||||
`created_at`,
|
||||
`updated_at`
|
||||
)
|
||||
SELECT
|
||||
`id`,
|
||||
`title`,
|
||||
`url`,
|
||||
`date`,
|
||||
`details`,
|
||||
`studio_id`,
|
||||
`rating`,
|
||||
`organized`,
|
||||
`created_at`,
|
||||
`updated_at`
|
||||
FROM `galleries`;
|
||||
|
||||
-- insert gallery files - we will fix these up in the post-migration
|
||||
INSERT INTO `files`
|
||||
(
|
||||
`basename`,
|
||||
`parent_folder_id`,
|
||||
`size`,
|
||||
`mod_time`,
|
||||
`created_at`,
|
||||
`updated_at`
|
||||
)
|
||||
SELECT
|
||||
`path`,
|
||||
1,
|
||||
0,
|
||||
'1970-01-01 00:00:00', -- set to placeholder so that size is updated
|
||||
`created_at`,
|
||||
`updated_at`
|
||||
FROM `galleries`
|
||||
WHERE `galleries`.`path` IS NOT NULL AND `galleries`.`zip` = '1';
|
||||
|
||||
-- insert gallery zip folders - we will fix these up in the post-migration
|
||||
INSERT INTO `folders`
|
||||
(
|
||||
`path`,
|
||||
`zip_file_id`,
|
||||
`mod_time`,
|
||||
`created_at`,
|
||||
`updated_at`
|
||||
)
|
||||
SELECT
|
||||
`galleries`.`path`,
|
||||
`files`.`id`,
|
||||
'1970-01-01 00:00:00',
|
||||
`galleries`.`created_at`,
|
||||
`galleries`.`updated_at`
|
||||
FROM `galleries`
|
||||
INNER JOIN `files` ON `galleries`.`path` = `files`.`basename` AND `files`.`parent_folder_id` = 1
|
||||
WHERE `galleries`.`path` IS NOT NULL AND `galleries`.`zip` = '1';
|
||||
|
||||
-- set the zip file id of the zip folders
|
||||
UPDATE `folders` SET `zip_file_id` = (SELECT `files`.`id` FROM `files` WHERE `folders`.`path` = `files`.`basename`);
|
||||
|
||||
-- insert gallery folders - we will fix these up in the post-migration
|
||||
INSERT INTO `folders`
|
||||
(
|
||||
`path`,
|
||||
`mod_time`,
|
||||
`created_at`,
|
||||
`updated_at`
|
||||
)
|
||||
SELECT
|
||||
`path`,
|
||||
'1970-01-01 00:00:00',
|
||||
`created_at`,
|
||||
`updated_at`
|
||||
FROM `galleries`
|
||||
WHERE `galleries`.`path` IS NOT NULL AND `galleries`.`zip` = '0';
|
||||
|
||||
UPDATE `galleries_new` SET `folder_id` = (
|
||||
SELECT `folders`.`id` FROM `folders` INNER JOIN `galleries` ON `galleries_new`.`id` = `galleries`.`id` WHERE `folders`.`path` = `galleries`.`path` AND `galleries`.`zip` = '0'
|
||||
);
|
||||
|
||||
INSERT INTO `galleries_files`
|
||||
(
|
||||
`gallery_id`,
|
||||
`file_id`,
|
||||
`primary`
|
||||
)
|
||||
SELECT
|
||||
`galleries`.`id`,
|
||||
`files`.`id`,
|
||||
1
|
||||
FROM `galleries` INNER JOIN `files` ON `galleries`.`path` = `files`.`basename` AND `files`.`parent_folder_id` = 1;
|
||||
|
||||
INSERT INTO `files_fingerprints`
|
||||
(
|
||||
`file_id`,
|
||||
`type`,
|
||||
`fingerprint`
|
||||
)
|
||||
SELECT
|
||||
`files`.`id`,
|
||||
'md5',
|
||||
`galleries`.`checksum`
|
||||
FROM `galleries` INNER JOIN `files` ON `galleries`.`path` = `files`.`basename` AND `files`.`parent_folder_id` = 1;
|
||||
|
||||
DROP TABLE `galleries`;
|
||||
ALTER TABLE `galleries_new` rename to `galleries`;
|
||||
|
||||
CREATE INDEX `index_galleries_on_studio_id` on `galleries` (`studio_id`);
|
||||
-- should only be possible to create a single gallery per folder
|
||||
CREATE UNIQUE INDEX `index_galleries_on_folder_id_unique` on `galleries` (`folder_id`);
|
||||
|
||||
CREATE TABLE `scenes_new` (
|
||||
`id` integer not null primary key autoincrement,
|
||||
-- REMOVED: `path` varchar(510) not null,
|
||||
-- REMOVED: `checksum` varchar(255),
|
||||
-- REMOVED: `oshash` varchar(255),
|
||||
`title` varchar(255),
|
||||
`details` text,
|
||||
`url` varchar(255),
|
||||
`date` date,
|
||||
`rating` tinyint,
|
||||
-- REMOVED: `size` varchar(255),
|
||||
-- REMOVED: `duration` float,
|
||||
-- REMOVED: `video_codec` varchar(255),
|
||||
-- REMOVED: `audio_codec` varchar(255),
|
||||
-- REMOVED: `width` tinyint,
|
||||
-- REMOVED: `height` tinyint,
|
||||
-- REMOVED: `framerate` float,
|
||||
-- REMOVED: `bitrate` integer,
|
||||
`studio_id` integer,
|
||||
`o_counter` tinyint not null default 0,
|
||||
-- REMOVED: `format` varchar(255),
|
||||
`organized` boolean not null default '0',
|
||||
-- REMOVED: `interactive` boolean not null default '0',
|
||||
-- REMOVED: `interactive_speed` int,
|
||||
`created_at` datetime not null,
|
||||
`updated_at` datetime not null,
|
||||
-- REMOVED: `file_mod_time` datetime,
|
||||
-- REMOVED: `phash` blob,
|
||||
foreign key(`studio_id`) references `studios`(`id`) on delete SET NULL
|
||||
-- REMOVED: CHECK (`checksum` is not null or `oshash` is not null)
|
||||
);
|
||||
|
||||
INSERT INTO `scenes_new`
|
||||
(
|
||||
`id`,
|
||||
`title`,
|
||||
`details`,
|
||||
`url`,
|
||||
`date`,
|
||||
`rating`,
|
||||
`studio_id`,
|
||||
`o_counter`,
|
||||
`organized`,
|
||||
`created_at`,
|
||||
`updated_at`
|
||||
)
|
||||
SELECT
|
||||
`id`,
|
||||
`title`,
|
||||
`details`,
|
||||
`url`,
|
||||
`date`,
|
||||
`rating`,
|
||||
`studio_id`,
|
||||
`o_counter`,
|
||||
`organized`,
|
||||
`created_at`,
|
||||
`updated_at`
|
||||
FROM `scenes`;
|
||||
|
||||
-- insert scene files - we will fix these up in the post-migration
|
||||
INSERT INTO `files`
|
||||
(
|
||||
`basename`,
|
||||
`parent_folder_id`,
|
||||
`size`,
|
||||
`mod_time`,
|
||||
`created_at`,
|
||||
`updated_at`
|
||||
)
|
||||
SELECT
|
||||
`path`,
|
||||
1,
|
||||
COALESCE(`size`, 0),
|
||||
-- set mod time to epoch so that it the format/size is calculated on scan
|
||||
'1970-01-01 00:00:00',
|
||||
`created_at`,
|
||||
`updated_at`
|
||||
FROM `scenes`;
|
||||
|
||||
INSERT INTO `video_files`
|
||||
(
|
||||
`file_id`,
|
||||
`duration`,
|
||||
`video_codec`,
|
||||
`format`,
|
||||
`audio_codec`,
|
||||
`width`,
|
||||
`height`,
|
||||
`frame_rate`,
|
||||
`bit_rate`,
|
||||
`interactive`,
|
||||
`interactive_speed`
|
||||
)
|
||||
SELECT
|
||||
`files`.`id`,
|
||||
`scenes`.`duration`,
|
||||
COALESCE(`scenes`.`video_codec`, ''),
|
||||
COALESCE(`scenes`.`format`, ''),
|
||||
COALESCE(`scenes`.`audio_codec`, ''),
|
||||
COALESCE(`scenes`.`width`, 0),
|
||||
COALESCE(`scenes`.`height`, 0),
|
||||
COALESCE(`scenes`.`framerate`, 0),
|
||||
COALESCE(`scenes`.`bitrate`, 0),
|
||||
`scenes`.`interactive`,
|
||||
`scenes`.`interactive_speed`
|
||||
FROM `scenes` INNER JOIN `files` ON `scenes`.`path` = `files`.`basename` AND `files`.`parent_folder_id` = 1;
|
||||
|
||||
INSERT INTO `scenes_files`
|
||||
(
|
||||
`scene_id`,
|
||||
`file_id`,
|
||||
`primary`
|
||||
)
|
||||
SELECT
|
||||
`scenes`.`id`,
|
||||
`files`.`id`,
|
||||
1
|
||||
FROM `scenes` INNER JOIN `files` ON `scenes`.`path` = `files`.`basename` AND `files`.`parent_folder_id` = 1;
|
||||
|
||||
INSERT INTO `files_fingerprints`
|
||||
(
|
||||
`file_id`,
|
||||
`type`,
|
||||
`fingerprint`
|
||||
)
|
||||
SELECT
|
||||
`files`.`id`,
|
||||
'md5',
|
||||
`scenes`.`checksum`
|
||||
FROM `scenes` INNER JOIN `files` ON `scenes`.`path` = `files`.`basename` AND `files`.`parent_folder_id` = 1
|
||||
WHERE `scenes`.`checksum` is not null;
|
||||
|
||||
INSERT INTO `files_fingerprints`
|
||||
(
|
||||
`file_id`,
|
||||
`type`,
|
||||
`fingerprint`
|
||||
)
|
||||
SELECT
|
||||
`files`.`id`,
|
||||
'oshash',
|
||||
`scenes`.`oshash`
|
||||
FROM `scenes` INNER JOIN `files` ON `scenes`.`path` = `files`.`basename` AND `files`.`parent_folder_id` = 1
|
||||
WHERE `scenes`.`oshash` is not null;
|
||||
|
||||
INSERT INTO `files_fingerprints`
|
||||
(
|
||||
`file_id`,
|
||||
`type`,
|
||||
`fingerprint`
|
||||
)
|
||||
SELECT
|
||||
`files`.`id`,
|
||||
'phash',
|
||||
`scenes`.`phash`
|
||||
FROM `scenes` INNER JOIN `files` ON `scenes`.`path` = `files`.`basename` AND `files`.`parent_folder_id` = 1
|
||||
WHERE `scenes`.`phash` is not null;
|
||||
|
||||
INSERT INTO `video_captions`
|
||||
(
|
||||
`file_id`,
|
||||
`language_code`,
|
||||
`filename`,
|
||||
`caption_type`
|
||||
)
|
||||
SELECT
|
||||
`files`.`id`,
|
||||
`scene_captions`.`language_code`,
|
||||
`scene_captions`.`filename`,
|
||||
`scene_captions`.`caption_type`
|
||||
FROM `scene_captions`
|
||||
INNER JOIN `scenes` ON `scene_captions`.`scene_id` = `scenes`.`id`
|
||||
INNER JOIN `files` ON `scenes`.`path` = `files`.`basename` AND `files`.`parent_folder_id` = 1;
|
||||
|
||||
DROP TABLE `scenes`;
|
||||
DROP TABLE `scene_captions`;
|
||||
|
||||
ALTER TABLE `scenes_new` rename to `scenes`;
|
||||
CREATE INDEX `index_scenes_on_studio_id` on `scenes` (`studio_id`);
|
||||
|
||||
PRAGMA foreign_keys=ON;
|
||||
|
||||
-- create views to simplify queries
|
||||
|
||||
CREATE VIEW `images_query` AS
|
||||
SELECT
|
||||
`images`.`id`,
|
||||
`images`.`title`,
|
||||
`images`.`rating`,
|
||||
`images`.`organized`,
|
||||
`images`.`o_counter`,
|
||||
`images`.`studio_id`,
|
||||
`images`.`created_at`,
|
||||
`images`.`updated_at`,
|
||||
`galleries_images`.`gallery_id`,
|
||||
`images_tags`.`tag_id`,
|
||||
`performers_images`.`performer_id`,
|
||||
`image_files`.`format` as `image_format`,
|
||||
`image_files`.`width` as `image_width`,
|
||||
`image_files`.`height` as `image_height`,
|
||||
`files`.`id` as `file_id`,
|
||||
`files`.`basename`,
|
||||
`files`.`size`,
|
||||
`files`.`mod_time`,
|
||||
`files`.`zip_file_id`,
|
||||
`folders`.`id` as `parent_folder_id`,
|
||||
`folders`.`path` as `parent_folder_path`,
|
||||
`zip_files`.`basename` as `zip_basename`,
|
||||
`zip_files_folders`.`path` as `zip_folder_path`,
|
||||
`files_fingerprints`.`type` as `fingerprint_type`,
|
||||
`files_fingerprints`.`fingerprint`
|
||||
FROM `images`
|
||||
LEFT JOIN `performers_images` ON (`images`.`id` = `performers_images`.`image_id`)
|
||||
LEFT JOIN `galleries_images` ON (`images`.`id` = `galleries_images`.`image_id`)
|
||||
LEFT JOIN `images_tags` ON (`images`.`id` = `images_tags`.`image_id`)
|
||||
LEFT JOIN `images_files` ON (`images`.`id` = `images_files`.`image_id`)
|
||||
LEFT JOIN `image_files` ON (`images_files`.`file_id` = `image_files`.`file_id`)
|
||||
LEFT JOIN `files` ON (`images_files`.`file_id` = `files`.`id`)
|
||||
LEFT JOIN `folders` ON (`files`.`parent_folder_id` = `folders`.`id`)
|
||||
LEFT JOIN `files` AS `zip_files` ON (`files`.`zip_file_id` = `zip_files`.`id`)
|
||||
LEFT JOIN `folders` AS `zip_files_folders` ON (`zip_files`.`parent_folder_id` = `zip_files_folders`.`id`)
|
||||
LEFT JOIN `files_fingerprints` ON (`images_files`.`file_id` = `files_fingerprints`.`file_id`);
|
||||
|
||||
CREATE VIEW `galleries_query` AS
|
||||
SELECT
|
||||
`galleries`.`id`,
|
||||
`galleries`.`title`,
|
||||
`galleries`.`url`,
|
||||
`galleries`.`date`,
|
||||
`galleries`.`details`,
|
||||
`galleries`.`rating`,
|
||||
`galleries`.`organized`,
|
||||
`galleries`.`studio_id`,
|
||||
`galleries`.`created_at`,
|
||||
`galleries`.`updated_at`,
|
||||
`galleries_tags`.`tag_id`,
|
||||
`scenes_galleries`.`scene_id`,
|
||||
`performers_galleries`.`performer_id`,
|
||||
`galleries_folders`.`id` as `folder_id`,
|
||||
`galleries_folders`.`path` as `folder_path`,
|
||||
`files`.`id` as `file_id`,
|
||||
`files`.`basename`,
|
||||
`files`.`size`,
|
||||
`files`.`mod_time`,
|
||||
`files`.`zip_file_id`,
|
||||
`parent_folders`.`id` as `parent_folder_id`,
|
||||
`parent_folders`.`path` as `parent_folder_path`,
|
||||
`zip_files`.`basename` as `zip_basename`,
|
||||
`zip_files_folders`.`path` as `zip_folder_path`,
|
||||
`files_fingerprints`.`type` as `fingerprint_type`,
|
||||
`files_fingerprints`.`fingerprint`
|
||||
FROM `galleries`
|
||||
LEFT JOIN `performers_galleries` ON (`galleries`.`id` = `performers_galleries`.`gallery_id`)
|
||||
LEFT JOIN `galleries_tags` ON (`galleries`.`id` = `galleries_tags`.`gallery_id`)
|
||||
LEFT JOIN `scenes_galleries` ON (`galleries`.`id` = `scenes_galleries`.`gallery_id`)
|
||||
LEFT JOIN `folders` AS `galleries_folders` ON (`galleries`.`folder_id` = `galleries_folders`.`id`)
|
||||
LEFT JOIN `galleries_files` ON (`galleries`.`id` = `galleries_files`.`gallery_id`)
|
||||
LEFT JOIN `files` ON (`galleries_files`.`file_id` = `files`.`id`)
|
||||
LEFT JOIN `folders` AS `parent_folders` ON (`files`.`parent_folder_id` = `parent_folders`.`id`)
|
||||
LEFT JOIN `files` AS `zip_files` ON (`files`.`zip_file_id` = `zip_files`.`id`)
|
||||
LEFT JOIN `folders` AS `zip_files_folders` ON (`zip_files`.`parent_folder_id` = `zip_files_folders`.`id`)
|
||||
LEFT JOIN `files_fingerprints` ON (`galleries_files`.`file_id` = `files_fingerprints`.`file_id`);
|
||||
|
||||
CREATE VIEW `scenes_query` AS
|
||||
SELECT
|
||||
`scenes`.`id`,
|
||||
`scenes`.`title`,
|
||||
`scenes`.`details`,
|
||||
`scenes`.`url`,
|
||||
`scenes`.`date`,
|
||||
`scenes`.`rating`,
|
||||
`scenes`.`studio_id`,
|
||||
`scenes`.`o_counter`,
|
||||
`scenes`.`organized`,
|
||||
`scenes`.`created_at`,
|
||||
`scenes`.`updated_at`,
|
||||
`scenes_tags`.`tag_id`,
|
||||
`scenes_galleries`.`gallery_id`,
|
||||
`performers_scenes`.`performer_id`,
|
||||
`movies_scenes`.`movie_id`,
|
||||
`movies_scenes`.`scene_index`,
|
||||
`scene_stash_ids`.`stash_id`,
|
||||
`scene_stash_ids`.`endpoint`,
|
||||
`video_files`.`format` as `video_format`,
|
||||
`video_files`.`width` as `video_width`,
|
||||
`video_files`.`height` as `video_height`,
|
||||
`video_files`.`duration`,
|
||||
`video_files`.`video_codec`,
|
||||
`video_files`.`audio_codec`,
|
||||
`video_files`.`frame_rate`,
|
||||
`video_files`.`bit_rate`,
|
||||
`video_files`.`interactive`,
|
||||
`video_files`.`interactive_speed`,
|
||||
`files`.`id` as `file_id`,
|
||||
`files`.`basename`,
|
||||
`files`.`size`,
|
||||
`files`.`mod_time`,
|
||||
`files`.`zip_file_id`,
|
||||
`folders`.`id` as `parent_folder_id`,
|
||||
`folders`.`path` as `parent_folder_path`,
|
||||
`zip_files`.`basename` as `zip_basename`,
|
||||
`zip_files_folders`.`path` as `zip_folder_path`,
|
||||
`files_fingerprints`.`type` as `fingerprint_type`,
|
||||
`files_fingerprints`.`fingerprint`
|
||||
FROM `scenes`
|
||||
LEFT JOIN `performers_scenes` ON (`scenes`.`id` = `performers_scenes`.`scene_id`)
|
||||
LEFT JOIN `scenes_tags` ON (`scenes`.`id` = `scenes_tags`.`scene_id`)
|
||||
LEFT JOIN `movies_scenes` ON (`scenes`.`id` = `movies_scenes`.`scene_id`)
|
||||
LEFT JOIN `scene_stash_ids` ON (`scenes`.`id` = `scene_stash_ids`.`scene_id`)
|
||||
LEFT JOIN `scenes_galleries` ON (`scenes`.`id` = `scenes_galleries`.`scene_id`)
|
||||
LEFT JOIN `scenes_files` ON (`scenes`.`id` = `scenes_files`.`scene_id`)
|
||||
LEFT JOIN `video_files` ON (`scenes_files`.`file_id` = `video_files`.`file_id`)
|
||||
LEFT JOIN `files` ON (`scenes_files`.`file_id` = `files`.`id`)
|
||||
LEFT JOIN `folders` ON (`files`.`parent_folder_id` = `folders`.`id`)
|
||||
LEFT JOIN `files` AS `zip_files` ON (`files`.`zip_file_id` = `zip_files`.`id`)
|
||||
LEFT JOIN `folders` AS `zip_files_folders` ON (`zip_files`.`parent_folder_id` = `zip_files_folders`.`id`)
|
||||
LEFT JOIN `files_fingerprints` ON (`scenes_files`.`file_id` = `files_fingerprints`.`file_id`);
|
||||
313
pkg/sqlite/migrations/32_postmigrate.go
Normal file
313
pkg/sqlite/migrations/32_postmigrate.go
Normal file
@@ -0,0 +1,313 @@
|
||||
package migrations
|
||||
|
||||
import (
|
||||
"context"
|
||||
"database/sql"
|
||||
"fmt"
|
||||
"path"
|
||||
"path/filepath"
|
||||
"strings"
|
||||
"time"
|
||||
|
||||
"github.com/jmoiron/sqlx"
|
||||
"github.com/stashapp/stash/pkg/logger"
|
||||
"github.com/stashapp/stash/pkg/sqlite"
|
||||
"gopkg.in/guregu/null.v4"
|
||||
)
|
||||
|
||||
const legacyZipSeparator = "\x00"
|
||||
|
||||
func post32(ctx context.Context, db *sqlx.DB) error {
|
||||
logger.Info("Running post-migration for schema version 32")
|
||||
|
||||
m := schema32Migrator{
|
||||
migrator: migrator{
|
||||
db: db,
|
||||
},
|
||||
folderCache: make(map[string]folderInfo),
|
||||
}
|
||||
|
||||
if err := m.migrateFolders(ctx); err != nil {
|
||||
return fmt.Errorf("migrating folders: %w", err)
|
||||
}
|
||||
|
||||
if err := m.migrateFiles(ctx); err != nil {
|
||||
return fmt.Errorf("migrating files: %w", err)
|
||||
}
|
||||
|
||||
if err := m.deletePlaceholderFolder(ctx); err != nil {
|
||||
return fmt.Errorf("deleting placeholder folder: %w", err)
|
||||
}
|
||||
|
||||
return nil
|
||||
}
|
||||
|
||||
type folderInfo struct {
|
||||
id int
|
||||
zipID sql.NullInt64
|
||||
}
|
||||
|
||||
type schema32Migrator struct {
|
||||
migrator
|
||||
folderCache map[string]folderInfo
|
||||
}
|
||||
|
||||
func (m *schema32Migrator) migrateFolderSlashes(ctx context.Context) error {
|
||||
logger.Infof("Migrating folder slashes")
|
||||
const query = "SELECT `folders`.`id`, `folders`.`path` FROM `folders`"
|
||||
|
||||
rows, err := m.db.Query(query)
|
||||
if err != nil {
|
||||
return err
|
||||
}
|
||||
defer rows.Close()
|
||||
|
||||
for rows.Next() {
|
||||
var id int
|
||||
var p string
|
||||
|
||||
err := rows.Scan(&id, &p)
|
||||
if err != nil {
|
||||
return err
|
||||
}
|
||||
|
||||
convertedPath := filepath.ToSlash(p)
|
||||
|
||||
_, err = m.db.Exec("UPDATE `folders` SET `path` = ? WHERE `id` = ?", convertedPath, id)
|
||||
if err != nil {
|
||||
return err
|
||||
}
|
||||
}
|
||||
|
||||
if err := rows.Err(); err != nil {
|
||||
return err
|
||||
}
|
||||
|
||||
return nil
|
||||
}
|
||||
|
||||
func (m *schema32Migrator) migrateFolders(ctx context.Context) error {
|
||||
if err := m.migrateFolderSlashes(ctx); err != nil {
|
||||
return err
|
||||
}
|
||||
|
||||
logger.Infof("Migrating folders")
|
||||
|
||||
const query = "SELECT `folders`.`id`, `folders`.`path` FROM `folders` INNER JOIN `galleries` ON `galleries`.`folder_id` = `folders`.`id`"
|
||||
|
||||
rows, err := m.db.Query(query)
|
||||
if err != nil {
|
||||
return err
|
||||
}
|
||||
defer rows.Close()
|
||||
|
||||
for rows.Next() {
|
||||
var id int
|
||||
var p string
|
||||
|
||||
err := rows.Scan(&id, &p)
|
||||
if err != nil {
|
||||
return err
|
||||
}
|
||||
|
||||
parent := path.Dir(p)
|
||||
parentID, zipFileID, err := m.createFolderHierarchy(parent)
|
||||
if err != nil {
|
||||
return err
|
||||
}
|
||||
|
||||
_, err = m.db.Exec("UPDATE `folders` SET `parent_folder_id` = ?, `zip_file_id` = ? WHERE `id` = ?", parentID, zipFileID, id)
|
||||
if err != nil {
|
||||
return err
|
||||
}
|
||||
}
|
||||
|
||||
if err := rows.Err(); err != nil {
|
||||
return err
|
||||
}
|
||||
|
||||
return nil
|
||||
}
|
||||
|
||||
func (m *schema32Migrator) migrateFiles(ctx context.Context) error {
|
||||
const (
|
||||
limit = 1000
|
||||
logEvery = 10000
|
||||
)
|
||||
offset := 0
|
||||
|
||||
result := struct {
|
||||
Count int `db:"count"`
|
||||
}{0}
|
||||
|
||||
if err := m.db.Get(&result, "SELECT COUNT(*) AS count FROM `files`"); err != nil {
|
||||
return err
|
||||
}
|
||||
|
||||
logger.Infof("Migrating %d files...", result.Count)
|
||||
|
||||
for {
|
||||
gotSome := false
|
||||
|
||||
query := fmt.Sprintf("SELECT `id`, `basename` FROM `files` ORDER BY `id` LIMIT %d OFFSET %d", limit, offset)
|
||||
|
||||
if err := m.withTxn(ctx, func(tx *sqlx.Tx) error {
|
||||
rows, err := m.db.Query(query)
|
||||
if err != nil {
|
||||
return err
|
||||
}
|
||||
defer rows.Close()
|
||||
|
||||
for rows.Next() {
|
||||
gotSome = true
|
||||
|
||||
var id int
|
||||
var p string
|
||||
|
||||
err := rows.Scan(&id, &p)
|
||||
if err != nil {
|
||||
return err
|
||||
}
|
||||
|
||||
if strings.Contains(p, legacyZipSeparator) {
|
||||
// remove any null characters from the path
|
||||
p = strings.ReplaceAll(p, legacyZipSeparator, string(filepath.Separator))
|
||||
}
|
||||
|
||||
convertedPath := filepath.ToSlash(p)
|
||||
parent := path.Dir(convertedPath)
|
||||
basename := path.Base(convertedPath)
|
||||
if parent != "." {
|
||||
parentID, zipFileID, err := m.createFolderHierarchy(parent)
|
||||
if err != nil {
|
||||
return err
|
||||
}
|
||||
|
||||
_, err = m.db.Exec("UPDATE `files` SET `parent_folder_id` = ?, `zip_file_id` = ?, `basename` = ? WHERE `id` = ?", parentID, zipFileID, basename, id)
|
||||
if err != nil {
|
||||
return err
|
||||
}
|
||||
}
|
||||
}
|
||||
|
||||
return rows.Err()
|
||||
}); err != nil {
|
||||
return err
|
||||
}
|
||||
|
||||
if !gotSome {
|
||||
break
|
||||
}
|
||||
|
||||
offset += limit
|
||||
|
||||
if offset%logEvery == 0 {
|
||||
logger.Infof("Migrated %d files", offset)
|
||||
}
|
||||
}
|
||||
|
||||
logger.Infof("Finished migrating files")
|
||||
|
||||
return nil
|
||||
}
|
||||
|
||||
func (m *schema32Migrator) deletePlaceholderFolder(ctx context.Context) error {
|
||||
// only delete the placeholder folder if no files/folders are attached to it
|
||||
result := struct {
|
||||
Count int `db:"count"`
|
||||
}{0}
|
||||
|
||||
if err := m.db.Get(&result, "SELECT COUNT(*) AS count FROM `files` WHERE `parent_folder_id` = 1"); err != nil {
|
||||
return err
|
||||
}
|
||||
|
||||
if result.Count > 0 {
|
||||
return fmt.Errorf("not deleting placeholder folder because it has %d files", result.Count)
|
||||
}
|
||||
|
||||
result.Count = 0
|
||||
|
||||
if err := m.db.Get(&result, "SELECT COUNT(*) AS count FROM `folders` WHERE `parent_folder_id` = 1"); err != nil {
|
||||
return err
|
||||
}
|
||||
|
||||
if result.Count > 0 {
|
||||
return fmt.Errorf("not deleting placeholder folder because it has %d folders", result.Count)
|
||||
}
|
||||
|
||||
_, err := m.db.Exec("DELETE FROM `folders` WHERE `id` = 1")
|
||||
return err
|
||||
}
|
||||
|
||||
func (m *schema32Migrator) createFolderHierarchy(p string) (*int, sql.NullInt64, error) {
|
||||
parent := path.Dir(p)
|
||||
|
||||
if parent == "." || parent == "/" {
|
||||
// get or create this folder
|
||||
return m.getOrCreateFolder(p, nil, sql.NullInt64{})
|
||||
}
|
||||
|
||||
parentID, zipFileID, err := m.createFolderHierarchy(parent)
|
||||
if err != nil {
|
||||
return nil, sql.NullInt64{}, err
|
||||
}
|
||||
|
||||
return m.getOrCreateFolder(p, parentID, zipFileID)
|
||||
}
|
||||
|
||||
func (m *schema32Migrator) getOrCreateFolder(path string, parentID *int, zipFileID sql.NullInt64) (*int, sql.NullInt64, error) {
|
||||
foundEntry, ok := m.folderCache[path]
|
||||
if ok {
|
||||
return &foundEntry.id, foundEntry.zipID, nil
|
||||
}
|
||||
|
||||
const query = "SELECT `id`, `zip_file_id` FROM `folders` WHERE `path` = ?"
|
||||
rows, err := m.db.Query(query, path)
|
||||
if err != nil {
|
||||
return nil, sql.NullInt64{}, err
|
||||
}
|
||||
defer rows.Close()
|
||||
|
||||
if rows.Next() {
|
||||
var id int
|
||||
var zfid sql.NullInt64
|
||||
err := rows.Scan(&id, &zfid)
|
||||
if err != nil {
|
||||
return nil, sql.NullInt64{}, err
|
||||
}
|
||||
|
||||
return &id, zfid, nil
|
||||
}
|
||||
|
||||
if err := rows.Err(); err != nil {
|
||||
return nil, sql.NullInt64{}, err
|
||||
}
|
||||
|
||||
const insertSQL = "INSERT INTO `folders` (`path`,`parent_folder_id`,`zip_file_id`,`mod_time`,`created_at`,`updated_at`) VALUES (?,?,?,?,?,?)"
|
||||
|
||||
var parentFolderID null.Int
|
||||
if parentID != nil {
|
||||
parentFolderID = null.IntFrom(int64(*parentID))
|
||||
}
|
||||
|
||||
now := time.Now()
|
||||
result, err := m.db.Exec(insertSQL, path, parentFolderID, zipFileID, time.Time{}, now, now)
|
||||
if err != nil {
|
||||
return nil, sql.NullInt64{}, err
|
||||
}
|
||||
|
||||
id, err := result.LastInsertId()
|
||||
if err != nil {
|
||||
return nil, sql.NullInt64{}, err
|
||||
}
|
||||
|
||||
idInt := int(id)
|
||||
|
||||
m.folderCache[path] = folderInfo{id: idInt, zipID: zipFileID}
|
||||
|
||||
return &idInt, zipFileID, nil
|
||||
}
|
||||
|
||||
func init() {
|
||||
sqlite.RegisterPostMigration(32, post32)
|
||||
}
|
||||
97
pkg/sqlite/migrations/32_premigrate.go
Normal file
97
pkg/sqlite/migrations/32_premigrate.go
Normal file
@@ -0,0 +1,97 @@
|
||||
package migrations
|
||||
|
||||
import (
|
||||
"context"
|
||||
"os"
|
||||
|
||||
"github.com/jmoiron/sqlx"
|
||||
"github.com/stashapp/stash/pkg/logger"
|
||||
"github.com/stashapp/stash/pkg/sqlite"
|
||||
)
|
||||
|
||||
func pre32(ctx context.Context, db *sqlx.DB) error {
|
||||
// verify that folder-based galleries (those with zip = 0 and path is not null) are
|
||||
// not zip-based. If they are zip based then set zip to 1
|
||||
// we could still miss some if the path does not exist, but this is the best we can do
|
||||
|
||||
logger.Info("Running pre-migration for schema version 32")
|
||||
|
||||
mm := schema32PreMigrator{
|
||||
migrator: migrator{
|
||||
db: db,
|
||||
},
|
||||
}
|
||||
|
||||
return mm.migrate(ctx)
|
||||
}
|
||||
|
||||
type schema32PreMigrator struct {
|
||||
migrator
|
||||
}
|
||||
|
||||
func (m *schema32PreMigrator) migrate(ctx context.Context) error {
|
||||
// query for galleries with zip = 0 and path not null
|
||||
result := struct {
|
||||
Count int `db:"count"`
|
||||
}{0}
|
||||
|
||||
if err := m.db.Get(&result, "SELECT COUNT(*) AS count FROM `galleries` WHERE `zip` = '0' AND `path` IS NOT NULL"); err != nil {
|
||||
return err
|
||||
}
|
||||
|
||||
if result.Count == 0 {
|
||||
return nil
|
||||
}
|
||||
|
||||
logger.Infof("Checking %d galleries for incorrect zip value...", result.Count)
|
||||
|
||||
if err := m.withTxn(ctx, func(tx *sqlx.Tx) error {
|
||||
const query = "SELECT `id`, `path` FROM `galleries` WHERE `zip` = '0' AND `path` IS NOT NULL ORDER BY `id`"
|
||||
rows, err := m.db.Query(query)
|
||||
if err != nil {
|
||||
return err
|
||||
}
|
||||
defer rows.Close()
|
||||
|
||||
for rows.Next() {
|
||||
var id int
|
||||
var p string
|
||||
|
||||
err := rows.Scan(&id, &p)
|
||||
if err != nil {
|
||||
return err
|
||||
}
|
||||
|
||||
// if path does not exist, assume that it is a file and not a folder
|
||||
// if it does exist and is a folder, then we ignore it
|
||||
// otherwise set zip to 1
|
||||
info, err := os.Stat(p)
|
||||
if err != nil {
|
||||
logger.Warnf("unable to verify if %q is a folder due to error %v. Not migrating.", p, err)
|
||||
continue
|
||||
}
|
||||
|
||||
if info.IsDir() {
|
||||
// ignore it
|
||||
continue
|
||||
}
|
||||
|
||||
logger.Infof("Correcting %q gallery to be zip-based.", p)
|
||||
|
||||
_, err = m.db.Exec("UPDATE `galleries` SET `zip` = '1' WHERE `id` = ?", id)
|
||||
if err != nil {
|
||||
return err
|
||||
}
|
||||
}
|
||||
|
||||
return rows.Err()
|
||||
}); err != nil {
|
||||
return err
|
||||
}
|
||||
|
||||
return nil
|
||||
}
|
||||
|
||||
func init() {
|
||||
sqlite.RegisterPreMigration(32, pre32)
|
||||
}
|
||||
38
pkg/sqlite/migrations/custom_migration.go
Normal file
38
pkg/sqlite/migrations/custom_migration.go
Normal file
@@ -0,0 +1,38 @@
|
||||
package migrations
|
||||
|
||||
import (
|
||||
"context"
|
||||
"fmt"
|
||||
|
||||
"github.com/jmoiron/sqlx"
|
||||
)
|
||||
|
||||
type migrator struct {
|
||||
db *sqlx.DB
|
||||
}
|
||||
|
||||
func (m *migrator) withTxn(ctx context.Context, fn func(tx *sqlx.Tx) error) error {
|
||||
tx, err := m.db.BeginTxx(ctx, nil)
|
||||
if err != nil {
|
||||
return fmt.Errorf("beginning transaction: %w", err)
|
||||
}
|
||||
|
||||
defer func() {
|
||||
if p := recover(); p != nil {
|
||||
// a panic occurred, rollback and repanic
|
||||
_ = tx.Rollback()
|
||||
panic(p)
|
||||
}
|
||||
|
||||
if err != nil {
|
||||
// something went wrong, rollback
|
||||
_ = tx.Rollback()
|
||||
} else {
|
||||
// all good, commit
|
||||
err = tx.Commit()
|
||||
}
|
||||
}()
|
||||
|
||||
err = fn(tx)
|
||||
return err
|
||||
}
|
||||
Reference in New Issue
Block a user