mirror of https://github.com/stashapp/stash.git
Add schema migration to fix view_date format (#4992)
Also adds index on scene_id and adds a not null constraint to scene_id
This commit is contained in:
parent
a8fca47a8c
commit
6775a28ec7
|
@ -30,7 +30,7 @@ const (
|
|||
dbConnTimeout = 30
|
||||
)
|
||||
|
||||
var appSchemaVersion uint = 63
|
||||
var appSchemaVersion uint = 64
|
||||
|
||||
//go:embed migrations/*.sql
|
||||
var migrationsBox embed.FS
|
||||
|
|
|
@ -0,0 +1,49 @@
|
|||
PRAGMA foreign_keys=OFF;
|
||||
|
||||
-- recreate scenes_view_dates adding not null to scene_id and adding indexes
|
||||
CREATE TABLE `scenes_view_dates_new` (
|
||||
`scene_id` integer not null,
|
||||
`view_date` datetime not null,
|
||||
foreign key(`scene_id`) references `scenes`(`id`) on delete CASCADE
|
||||
);
|
||||
|
||||
INSERT INTO `scenes_view_dates_new`
|
||||
(
|
||||
`scene_id`,
|
||||
`view_date`
|
||||
)
|
||||
SELECT
|
||||
`scene_id`,
|
||||
`view_date`
|
||||
FROM `scenes_view_dates`
|
||||
WHERE `scenes_view_dates`.`scene_id` IS NOT NULL;
|
||||
|
||||
DROP INDEX IF EXISTS `index_scenes_view_dates`;
|
||||
DROP TABLE `scenes_view_dates`;
|
||||
ALTER TABLE `scenes_view_dates_new` rename to `scenes_view_dates`;
|
||||
CREATE INDEX `index_scenes_view_dates` ON `scenes_view_dates` (`scene_id`);
|
||||
|
||||
-- recreate scenes_o_dates adding not null to scene_id and adding indexes
|
||||
CREATE TABLE `scenes_o_dates_new` (
|
||||
`scene_id` integer not null,
|
||||
`o_date` datetime not null,
|
||||
foreign key(`scene_id`) references `scenes`(`id`) on delete CASCADE
|
||||
);
|
||||
|
||||
INSERT INTO `scenes_o_dates_new`
|
||||
(
|
||||
`scene_id`,
|
||||
`o_date`
|
||||
)
|
||||
SELECT
|
||||
`scene_id`,
|
||||
`o_date`
|
||||
FROM `scenes_o_dates`
|
||||
WHERE `scenes_o_dates`.`scene_id` IS NOT NULL;
|
||||
|
||||
DROP INDEX IF EXISTS `index_scenes_o_dates`;
|
||||
DROP TABLE `scenes_o_dates`;
|
||||
ALTER TABLE `scenes_o_dates_new` rename to `scenes_o_dates`;
|
||||
CREATE INDEX `index_scenes_o_dates` ON `scenes_o_dates` (`scene_id`);
|
||||
|
||||
PRAGMA foreign_keys=ON;
|
|
@ -0,0 +1,92 @@
|
|||
package migrations
|
||||
|
||||
import (
|
||||
"context"
|
||||
"fmt"
|
||||
"time"
|
||||
|
||||
"github.com/jmoiron/sqlx"
|
||||
"github.com/stashapp/stash/pkg/logger"
|
||||
"github.com/stashapp/stash/pkg/sqlite"
|
||||
)
|
||||
|
||||
// this is a copy of the 55 post migration
|
||||
// some non-UTC dates were missed, so we need to correct them
|
||||
|
||||
type schema64Migrator struct {
|
||||
migrator
|
||||
}
|
||||
|
||||
func post64(ctx context.Context, db *sqlx.DB) error {
|
||||
logger.Info("Running post-migration for schema version 64")
|
||||
|
||||
m := schema64Migrator{
|
||||
migrator: migrator{
|
||||
db: db,
|
||||
},
|
||||
}
|
||||
|
||||
return m.migrate(ctx)
|
||||
}
|
||||
|
||||
func (m *schema64Migrator) migrate(ctx context.Context) error {
|
||||
// the last_played_at column was storing in a different format than the rest of the timestamps
|
||||
// convert the play history date to the correct format
|
||||
if err := m.withTxn(ctx, func(tx *sqlx.Tx) error {
|
||||
query := "SELECT DISTINCT `scene_id`, `view_date` FROM `scenes_view_dates`"
|
||||
|
||||
rows, err := m.db.Query(query)
|
||||
if err != nil {
|
||||
return err
|
||||
}
|
||||
defer rows.Close()
|
||||
|
||||
for rows.Next() {
|
||||
var (
|
||||
id int
|
||||
viewDate sqlite.Timestamp
|
||||
)
|
||||
|
||||
err := rows.Scan(&id, &viewDate)
|
||||
if err != nil {
|
||||
return err
|
||||
}
|
||||
|
||||
// skip if already in the correct format
|
||||
if viewDate.Timestamp.Location() == time.UTC {
|
||||
logger.Debugf("view date %s is already in the correct format", viewDate.Timestamp)
|
||||
continue
|
||||
}
|
||||
|
||||
utcTimestamp := sqlite.UTCTimestamp{
|
||||
Timestamp: viewDate,
|
||||
}
|
||||
|
||||
// convert the timestamp to the correct format
|
||||
logger.Debugf("correcting view date %q to UTC date %q for scene %d", viewDate.Timestamp, viewDate.Timestamp.UTC(), id)
|
||||
r, err := m.db.Exec("UPDATE scenes_view_dates SET view_date = ? WHERE view_date = ? OR view_date = ?", utcTimestamp, viewDate.Timestamp, viewDate)
|
||||
if err != nil {
|
||||
return fmt.Errorf("error correcting view date %s to %s: %w", viewDate.Timestamp, viewDate, err)
|
||||
}
|
||||
|
||||
rowsAffected, err := r.RowsAffected()
|
||||
if err != nil {
|
||||
return err
|
||||
}
|
||||
|
||||
if rowsAffected == 0 {
|
||||
return fmt.Errorf("no rows affected when updating view date %s to %s for scene %d", viewDate.Timestamp, viewDate.Timestamp.UTC(), id)
|
||||
}
|
||||
}
|
||||
|
||||
return rows.Err()
|
||||
}); err != nil {
|
||||
return err
|
||||
}
|
||||
|
||||
return nil
|
||||
}
|
||||
|
||||
func init() {
|
||||
sqlite.RegisterPostMigration(64, post64)
|
||||
}
|
Loading…
Reference in New Issue