Merge pull request #1 from jgkawell/postgres-support

Postgres support
This commit is contained in:
Jack Kawell 2024-01-03 20:40:47 -06:00 committed by GitHub
commit e5d2e17cfd
No known key found for this signature in database
GPG Key ID: 4AEE18F83AFDEB23
51 changed files with 262 additions and 122 deletions

View File

@ -25,6 +25,7 @@ type configOptions struct {
DataFolder string
CacheFolder string
DbPath string
DbDriver string
LogLevel string
ScanInterval time.Duration
ScanSchedule string
@ -180,6 +181,13 @@ func Load() {
Server.ConfigFile = viper.GetViper().ConfigFileUsed()
if Server.DbPath == "" {
Server.DbPath = filepath.Join(Server.DataFolder, consts.DefaultDbPath)
Server.DbDriver = "sqlite3"
}
if strings.HasPrefix(Server.DbPath, "postgres://") {
Server.DbDriver = "pgx"
} else if Server.DbPath == ":memory:" {
Server.DbPath = "file::memory:?cache=shared&_foreign_keys=on"
Server.DbDriver = "sqlite3"
}
log.SetLevelString(Server.LogLevel)

View File

@ -5,6 +5,7 @@ import (
"embed"
"fmt"
_ "github.com/jackc/pgx/v5/stdlib"
_ "github.com/mattn/go-sqlite3"
"github.com/navidrome/navidrome/conf"
_ "github.com/navidrome/navidrome/db/migration"
@ -26,10 +27,10 @@ const migrationsFolder = "migration"
func Db() *sql.DB {
return singleton.GetInstance(func() *sql.DB {
Path = conf.Server.DbPath
if Path == ":memory:" {
Path = "file::memory:?cache=shared&_foreign_keys=on"
conf.Server.DbPath = Path
if conf.Server.DbDriver != "" {
Driver = conf.Server.DbDriver
}
conf.Server.DbDriver = Driver
log.Debug("Opening DataBase", "dbPath", Path, "driver", Driver)
instance, err := sql.Open(Driver, Path)
if err != nil {
@ -47,23 +48,25 @@ func Close() error {
func Init() {
db := Db()
// Disable foreign_keys to allow re-creating tables in migrations
_, err := db.Exec("PRAGMA foreign_keys=off")
defer func() {
_, err := db.Exec("PRAGMA foreign_keys=on")
// Disable foreign_keys to allow re-creating tables in migrations (sqlite only)
if Driver == "sqlite3" {
_, err := db.Exec("PRAGMA foreign_keys=off")
defer func() {
_, err := db.Exec("PRAGMA foreign_keys=on")
if err != nil {
log.Error("Error re-enabling foreign_keys", err)
}
}()
if err != nil {
log.Error("Error re-enabling foreign_keys", err)
log.Error("Error disabling foreign_keys", err)
}
}()
if err != nil {
log.Error("Error disabling foreign_keys", err)
}
gooseLogger := &logAdapter{silent: isSchemaEmpty(db)}
goose.SetLogger(gooseLogger)
goose.SetBaseFS(embedMigrations)
err = goose.SetDialect(Driver)
err := goose.SetDialect(Driver)
if err != nil {
log.Fatal("Invalid DB driver", "driver", Driver, err)
}
@ -74,12 +77,26 @@ func Init() {
}
func isSchemaEmpty(db *sql.DB) bool {
rows, err := db.Query("SELECT name FROM sqlite_master WHERE type='table' AND name='goose_db_version';") // nolint:rowserrcheck
if err != nil {
log.Fatal("Database could not be opened!", err)
empty := true
switch Driver {
case "sqlite3":
rows, err := db.Query("SELECT name FROM sqlite_master WHERE type='table' AND name='goose_db_version';") // nolint:rowserrcheck
if err != nil {
log.Fatal("Database could not be opened!", err)
}
defer rows.Close()
empty = !rows.Next()
case "pgx":
rows, err := db.Query("SELECT table_name FROM information_schema.tables WHERE table_schema = 'public' AND table_name = 'goose_db_version';") // nolint:rowserrcheck
if err != nil {
log.Fatal("Database could not be opened!", err)
}
defer rows.Close()
empty = !rows.Next()
default:
log.Fatal("Invalid DB driver", "driver", Driver)
}
defer rows.Close()
return !rows.Next()
return empty
}
type logAdapter struct {

View File

@ -30,8 +30,8 @@ create table if not exists album
song_count integer default 0 not null,
duration integer default 0 not null,
genre varchar(255) default '' not null,
created_at datetime,
updated_at datetime
created_at timestamp,
updated_at timestamp
);
create index if not exists album_artist
@ -57,10 +57,10 @@ create table if not exists annotation
item_id varchar(255) default '' not null,
item_type varchar(255) default '' not null,
play_count integer,
play_date datetime,
play_date timestamp,
rating integer,
starred bool default FALSE not null,
starred_at datetime,
starred_at timestamp,
unique (user_id, item_id, item_type)
);
@ -108,8 +108,8 @@ create table if not exists media_file
bit_rate integer default 0 not null,
genre varchar(255) default '' not null,
compilation bool default FALSE not null,
created_at datetime,
updated_at datetime
created_at timestamp,
updated_at timestamp
);
create index if not exists media_file_album_id
@ -160,7 +160,7 @@ create index if not exists search_full_text
create index if not exists search_table
on search ("table");
create table if not exists user
create table if not exists "user"
(
id varchar(255) not null
primary key,
@ -171,10 +171,10 @@ create table if not exists user
unique,
password varchar(255) default '' not null,
is_admin bool default FALSE not null,
last_login_at datetime,
last_access_at datetime,
created_at datetime not null,
updated_at datetime not null
last_login_at timestamp,
last_access_at timestamp,
created_at timestamp not null,
updated_at timestamp not null
);`)
return err
}

View File

@ -23,10 +23,10 @@ create table annotation_dg_tmp
item_id varchar(255) default '' not null,
item_type varchar(255) default '' not null,
play_count integer default 0,
play_date datetime,
play_date timestamp,
rating integer default 0,
starred bool default FALSE not null,
starred_at datetime,
starred_at timestamp,
unique (user_id, item_id, item_type)
);

View File

@ -35,8 +35,8 @@ create table media_file_dg_tmp
bit_rate integer default 0 not null,
genre varchar(255) default '' not null,
compilation bool default FALSE not null,
created_at datetime,
updated_at datetime
created_at timestamp,
updated_at timestamp
);
insert into media_file_dg_tmp(id, path, title, album, artist, artist_id, album_artist, album_id, has_cover_art, track_number, disc_number, year, size, suffix, duration, bit_rate, genre, compilation, created_at, updated_at) select id, path, title, album, artist, artist_id, album_artist, album_id, has_cover_art, track_number, disc_number, year, size, suffix, duration, bit_rate, genre, compilation, created_at, updated_at from media_file;
@ -72,8 +72,8 @@ create table album_dg_tmp
song_count integer default 0 not null,
duration real default 0 not null,
genre varchar(255) default '' not null,
created_at datetime,
updated_at datetime
created_at timestamp,
updated_at timestamp
);
insert into album_dg_tmp(id, name, artist_id, cover_art_path, cover_art_id, artist, album_artist, year, compilation, song_count, duration, genre, created_at, updated_at) select id, name, artist_id, cover_art_path, cover_art_id, artist, album_artist, year, compilation, song_count, duration, genre, created_at, updated_at from album;

View File

@ -29,8 +29,8 @@ create table album_dg_tmp
song_count integer default 0 not null,
duration real default 0 not null,
genre varchar(255) default '' not null,
created_at datetime,
updated_at datetime,
created_at timestamp,
updated_at timestamp,
full_text varchar(255) default '',
album_artist_id varchar(255) default ''
);

View File

@ -4,6 +4,7 @@ import (
"context"
"database/sql"
"github.com/navidrome/navidrome/conf"
"github.com/pressly/goose/v3"
)
@ -14,12 +15,18 @@ func init() {
func Up20200411164603(_ context.Context, tx *sql.Tx) error {
_, err := tx.Exec(`
alter table playlist
add created_at datetime;
add created_at timestamp;
alter table playlist
add updated_at datetime;
update playlist
set created_at = datetime('now'), updated_at = datetime('now');
add updated_at timestamp;
`)
switch conf.Server.DbDriver {
case "sqlite3":
_, err = tx.Exec(`update playlist set created_at = datetime('now'), updated_at = datetime('now');`)
case "pgx":
_, err = tx.Exec(`update playlist set created_at = now(), updated_at = now();`)
}
return err
}

View File

@ -4,6 +4,7 @@ import (
"context"
"database/sql"
"github.com/navidrome/navidrome/conf"
"github.com/pressly/goose/v3"
)
@ -12,6 +13,19 @@ func init() {
}
func Up20200423204116(_ context.Context, tx *sql.Tx) error {
if conf.Server.DbDriver == "pgx" {
_, err := tx.Exec(`
create collation nocase (
provider = icu,
locale = 'und-u-ks-level2',
deterministic = false
);
`)
if err != nil {
return err
}
}
_, err := tx.Exec(`
alter table artist
add order_artist_name varchar(255) collate nocase;
@ -62,5 +76,14 @@ create index if not exists media_file_order_artist_name
}
func Down20200423204116(_ context.Context, tx *sql.Tx) error {
if conf.Server.DbDriver == "pgx" {
_, err := tx.Exec(`
drop collation nocase;
`)
if err != nil {
return err
}
}
return nil
}

View File

@ -60,8 +60,8 @@ create table playlist_dg_tmp
song_count integer default 0 not null,
owner varchar(255) default '' not null,
public bool default FALSE not null,
created_at datetime,
updated_at datetime
created_at timestamp,
updated_at timestamp
);
insert into playlist_dg_tmp(id, name, comment, duration, owner, public, created_at, updated_at)

View File

@ -14,14 +14,14 @@ func init() {
func Up20200608153717(_ context.Context, tx *sql.Tx) error {
// First delete dangling players
_, err := tx.Exec(`
delete from player where user_name not in (select user_name from user)`)
delete from player where user_name not in (select user_name from "user")`)
if err != nil {
return err
}
// Also delete dangling players
_, err = tx.Exec(`
delete from playlist where owner not in (select user_name from user)`)
delete from playlist where owner not in (select user_name from "user")`)
if err != nil {
return err
}
@ -59,7 +59,7 @@ create table player_dg_tmp
unique,
type varchar,
user_name varchar not null
references user (user_name)
references "user" (user_name)
on update cascade on delete cascade,
client varchar not null,
ip_address varchar,
@ -89,11 +89,11 @@ create table playlist_dg_tmp
song_count integer default 0 not null,
owner varchar(255) default '' not null
constraint playlist_user_user_name_fk
references user (user_name)
references "user" (user_name)
on update cascade on delete cascade,
public bool default FALSE not null,
created_at datetime,
updated_at datetime
created_at timestamp,
updated_at timestamp
);
insert into playlist_dg_tmp(id, name, comment, duration, song_count, owner, public, created_at, updated_at) select id, name, comment, duration, song_count, owner, public, created_at, updated_at from playlist;

View File

@ -24,7 +24,7 @@ func upAddDefaultTranscodings(_ context.Context, tx *sql.Tx) error {
return nil
}
stmt, err := tx.Prepare("insert into transcoding (id, name, target_format, default_bit_rate, command) values (?, ?, ?, ?, ?)")
stmt, err := tx.Prepare("insert into transcoding (id, name, target_format, default_bit_rate, command) values ($1, $2, $3, $4, $5)")
if err != nil {
return err
}

View File

@ -14,7 +14,7 @@ func init() {
func upAddPlaylistPath(_ context.Context, tx *sql.Tx) error {
_, err := tx.Exec(`
alter table playlist
add path string default '' not null;
add path text default '' not null;
alter table playlist
add sync bool default false not null;

View File

@ -17,15 +17,15 @@ create table playqueue
(
id varchar(255) not null primary key,
user_id varchar(255) not null
references user (id)
references "user" (id)
on update cascade on delete cascade,
comment varchar(255),
current varchar(255) not null,
position integer,
changed_by varchar(255),
items varchar(255),
created_at datetime,
updated_at datetime
created_at timestamp,
updated_at timestamp
);
`)

View File

@ -16,15 +16,15 @@ func upCreateBookmarkTable(_ context.Context, tx *sql.Tx) error {
create table bookmark
(
user_id varchar(255) not null
references user
references "user"
on update cascade on delete cascade,
item_id varchar(255) not null,
item_type varchar(255) not null,
comment varchar(255),
position integer,
changed_by varchar(255),
created_at datetime,
updated_at datetime,
created_at timestamp,
updated_at timestamp,
constraint bookmark_pk
unique (user_id, item_id, item_type)
);
@ -33,14 +33,14 @@ create table playqueue_dg_tmp
(
id varchar(255) not null,
user_id varchar(255) not null
references user
references "user"
on update cascade on delete cascade,
current varchar(255),
position real,
changed_by varchar(255),
items varchar(255),
created_at datetime,
updated_at datetime
created_at timestamp,
updated_at timestamp
);
drop table playqueue;
alter table playqueue_dg_tmp rename to playqueue;

View File

@ -4,6 +4,7 @@ import (
"context"
"database/sql"
"github.com/navidrome/navidrome/conf"
"github.com/pressly/goose/v3"
)
@ -12,7 +13,10 @@ func init() {
}
func upDropEmailUniqueConstraint(_ context.Context, tx *sql.Tx) error {
_, err := tx.Exec(`
var err error
switch conf.Server.DbDriver {
case "sqlite3":
_, err = tx.Exec(`
create table user_dg_tmp
(
id varchar(255) not null
@ -35,6 +39,12 @@ drop table user;
alter table user_dg_tmp rename to user;
`)
case "pgx":
_, err = tx.Exec(`
alter table "user" DROP CONSTRAINT IF EXISTS "user_email_key";
`)
}
return err
}

View File

@ -18,12 +18,12 @@ alter table album
create index if not exists album_size
on album(size);
update album set size = ifnull((
update album set size = coalesce((
select sum(f.size)
from media_file f
where f.album_id = album.id
), 0)
where id not null;`)
where id is not null;`)
return err
}

View File

@ -18,19 +18,19 @@ alter table artist
create index if not exists artist_size
on artist(size);
update artist set size = ifnull((
update artist set size = coalesce((
select sum(f.size)
from album f
where f.album_artist_id = artist.id
), 0)
where id not null;
where id is not null;
alter table playlist
add size integer default 0 not null;
create index if not exists playlist_size
on playlist(size);
update playlist set size = ifnull((
update playlist set size = coalesce((
select sum(size)
from media_file f
left join playlist_tracks pt on f.id = pt.media_file_id

View File

@ -26,7 +26,7 @@ alter table artist
alter table artist
add external_url varchar(255) default '' not null;
alter table artist
add external_info_updated_at datetime;
add external_info_updated_at timestamp;
`)
return err
}

View File

@ -30,7 +30,7 @@ create index if not exists album_all_artist_ids
func updateAlbums20201213124814(tx *sql.Tx) error {
rows, err := tx.Query(`
select a.id, a.name, a.artist_id, a.album_artist_id, group_concat(mf.artist_id, ' ')
select a.id, a.name, a.artist_id, a.album_artist_id, string_agg(mf.artist_id, ' ')
from album a left join media_file mf on a.id = mf.album_id group by a.id
`)
if err != nil {
@ -38,8 +38,13 @@ select a.id, a.name, a.artist_id, a.album_artist_id, group_concat(mf.artist_id,
}
defer rows.Close()
stmt, err := tx.Prepare("update album set all_artist_ids = ? where id = ?")
stmt, err := tx.Prepare(`
update album
set all_artist_ids = $1
where id = $2
`)
if err != nil {
log.Error("failed here: ", err)
return err
}

View File

@ -17,14 +17,14 @@ func init() {
func upFixAlbumComments(_ context.Context, tx *sql.Tx) error {
//nolint:gosec
rows, err := tx.Query(`
SELECT album.id, group_concat(media_file.comment, '` + consts.Zwsp + `') FROM album, media_file WHERE media_file.album_id = album.id GROUP BY album.id;
SELECT album.id, string_agg(media_file.comment, '` + consts.Zwsp + `') FROM album, media_file WHERE media_file.album_id = album.id GROUP BY album.id;
`)
if err != nil {
return err
}
defer rows.Close()
stmt, err := tx.Prepare("UPDATE album SET comment = ? WHERE id = ?")
stmt, err := tx.Prepare("UPDATE album SET comment = $1 WHERE id = $2")
if err != nil {
return err
}

View File

@ -18,9 +18,9 @@ create table share
id varchar(255) not null primary key,
name varchar(255) not null unique,
description varchar(255),
expires datetime,
created datetime,
last_visited datetime,
expires timestamp,
created timestamp,
last_visited timestamp,
resource_ids varchar not null,
resource_type varchar(255) not null,
visit_count integer default 0

View File

@ -16,13 +16,13 @@ func init() {
}
func upEncodeAllPasswords(ctx context.Context, tx *sql.Tx) error {
rows, err := tx.Query(`SELECT id, user_name, password from user;`)
rows, err := tx.Query(`SELECT id, user_name, password from "user";`)
if err != nil {
return err
}
defer rows.Close()
stmt, err := tx.Prepare("UPDATE user SET password = ? WHERE id = ?")
stmt, err := tx.Prepare(`UPDATE "user" SET password = $1 WHERE id = $2`)
if err != nil {
return err
}

View File

@ -20,7 +20,7 @@ create table player_dg_tmp
name varchar not null,
user_agent varchar,
user_name varchar not null
references user (user_name)
references "user" (user_name)
on update cascade on delete cascade,
client varchar not null,
ip_address varchar,

View File

@ -4,6 +4,7 @@ import (
"context"
"database/sql"
"github.com/navidrome/navidrome/conf"
"github.com/pressly/goose/v3"
)
@ -12,7 +13,10 @@ func init() {
}
func upAddReferentialIntegrityToUserProps(_ context.Context, tx *sql.Tx) error {
_, err := tx.Exec(`
var err error
switch conf.Server.DbDriver {
case "sqlite3":
_, err = tx.Exec(`
create table user_props_dg_tmp
(
user_id varchar not null
@ -31,6 +35,15 @@ drop table user_props;
alter table user_props_dg_tmp rename to user_props;
`)
case "pgx":
_, err = tx.Exec(`
alter table user_props
add constraint user_props_user_id_fk
foreign key (user_id) references "user" (id)
on update cascade on delete cascade;
`)
}
return err
}

View File

@ -17,17 +17,17 @@ create table if not exists scrobble_buffer
(
user_id varchar not null
constraint scrobble_buffer_user_id_fk
references user
references "user"
on update cascade on delete cascade,
service varchar not null,
media_file_id varchar not null
constraint scrobble_buffer_media_file_id_fk
references media_file
on update cascade on delete cascade,
play_time datetime not null,
enqueue_time datetime not null default current_timestamp,
play_time timestamp not null,
enqueue_time timestamp not null default current_timestamp,
constraint scrobble_buffer_pk
unique (user_id, service, media_file_id, play_time, user_id)
unique (user_id, service, media_file_id, play_time)
);
`)

View File

@ -16,7 +16,7 @@ func upAddSmartPlaylist(_ context.Context, tx *sql.Tx) error {
alter table playlist
add column rules varchar null;
alter table playlist
add column evaluated_at datetime null;
add column evaluated_at timestamp null;
create index if not exists playlist_evaluated_at
on playlist(evaluated_at);

View File

@ -16,7 +16,7 @@ func init() {
func upAddOrderTitleToMediaFile(_ context.Context, tx *sql.Tx) error {
_, err := tx.Exec(`
alter table main.media_file
alter table media_file
add order_title varchar null collate NOCASE;
create index if not exists media_file_order_title
on media_file (order_title);
@ -36,7 +36,7 @@ func upAddOrderTitleToMediaFile_populateOrderTitle(tx *sql.Tx) error {
}
defer rows.Close()
stmt, err := tx.Prepare("update media_file set order_title = ? where id = ?")
stmt, err := tx.Prepare("update media_file set order_title = $1 where id = $2")
if err != nil {
return err
}

View File

@ -20,7 +20,7 @@ func upUnescapeLyricsAndComments(_ context.Context, tx *sql.Tx) error {
}
defer rows.Close()
stmt, err := tx.Prepare("update media_file set comment = ?, lyrics = ? where id = ?")
stmt, err := tx.Prepare("update media_file set comment = $1, lyrics = $2 where id = $3")
if err != nil {
return err
}

View File

@ -4,6 +4,7 @@ import (
"context"
"database/sql"
"github.com/navidrome/navidrome/conf"
"github.com/pressly/goose/v3"
)
@ -12,7 +13,10 @@ func init() {
}
func upAddUseridToPlaylist(_ context.Context, tx *sql.Tx) error {
_, err := tx.Exec(`
var err error
switch conf.Server.DbDriver {
case "sqlite3":
_, err = tx.Exec(`
create table playlist_dg_tmp
(
id varchar(255) not null
@ -51,8 +55,19 @@ create index playlist_size
on playlist (size);
create index playlist_updated_at
on playlist (updated_at);
`)
case "pgx":
_, err = tx.Exec(`
alter table playlist add column owner_id varchar(255) not null default '';
update playlist set owner_id = (select id from "user" where user_name = owner);
alter table playlist drop column owner;
alter table playlist add constraint playlist_user_user_id_fk foreign key (owner_id) references "user" (id) on update cascade on delete cascade;
`)
}
return err
}

View File

@ -13,7 +13,7 @@ func init() {
func upAddAlbumImagePaths(_ context.Context, tx *sql.Tx) error {
_, err := tx.Exec(`
alter table main.album add image_files varchar;
alter table album add image_files varchar;
`)
if err != nil {
return err

View File

@ -24,13 +24,13 @@ func upAddAlbumPaths(_ context.Context, tx *sql.Tx) error {
//nolint:gosec
rows, err := tx.Query(`
select album_id, group_concat(path, '` + consts.Zwsp + `') from media_file group by album_id
select album_id, string_agg(path, '` + consts.Zwsp + `') from media_file group by album_id
`)
if err != nil {
return err
}
stmt, err := tx.Prepare("update album set paths = ? where id = ?")
stmt, err := tx.Prepare("update album set paths = $1 where id = $2")
if err != nil {
return err
}

View File

@ -4,6 +4,7 @@ import (
"context"
"database/sql"
"github.com/navidrome/navidrome/conf"
"github.com/pressly/goose/v3"
)
@ -12,7 +13,14 @@ func init() {
}
func upTouchPlaylists(_ context.Context, tx *sql.Tx) error {
_, err := tx.Exec(`update playlist set updated_at = datetime('now');`)
var err error
switch conf.Server.DbDriver {
case "sqlite3":
_, err = tx.Exec(`update playlist set updated_at = datetime('now');`)
case "pgx":
_, err = tx.Exec(`update playlist set updated_at = now();`)
}
return err
}

View File

@ -19,8 +19,8 @@ create table if not exists radio
name varchar not null unique,
stream_url varchar not null,
home_page_url varchar default '' not null,
created_at datetime,
updated_at datetime
created_at timestamp,
updated_at timestamp
);
`)
return err

View File

@ -24,7 +24,7 @@ alter table album
alter table album
add external_url varchar(255) default '' not null;
alter table album
add external_info_updated_at datetime;
add external_info_updated_at timestamp;
`)
return err
}

View File

@ -19,19 +19,19 @@ create table share
id varchar(255) not null
primary key,
description varchar(255),
expires_at datetime,
last_visited_at datetime,
expires_at timestamp,
last_visited_at timestamp,
resource_ids varchar not null,
resource_type varchar(255) not null,
contents varchar,
format varchar,
max_bit_rate integer,
visit_count integer default 0,
created_at datetime,
updated_at datetime,
created_at timestamp,
updated_at timestamp,
user_id varchar(255) not null
constraint share_user_id_fk
references user
references "user"
);
`)
return err

View File

@ -19,13 +19,13 @@ func init() {
func upChangePathListSeparator(_ context.Context, tx *sql.Tx) error {
//nolint:gosec
rows, err := tx.Query(`
select album_id, group_concat(path, '` + consts.Zwsp + `') from media_file group by album_id
select album_id, string_agg(path, '` + consts.Zwsp + `') from media_file group by album_id
`)
if err != nil {
return err
}
stmt, err := tx.Prepare("update album set paths = ? where id = ?")
stmt, err := tx.Prepare("update album set paths = $1 where id = $2")
if err != nil {
return err
}

View File

@ -22,7 +22,7 @@ func upChangeImageFilesListSeparator(_ context.Context, tx *sql.Tx) error {
return err
}
stmt, err := tx.Prepare("update album set image_files = ? where id = ?")
stmt, err := tx.Prepare("update album set image_files = $1 where id = $2")
if err != nil {
return err
}

View File

@ -4,6 +4,7 @@ import (
"context"
"database/sql"
"github.com/navidrome/navidrome/conf"
"github.com/pressly/goose/v3"
)
@ -16,17 +17,34 @@ func upAddDiscToAlbum(ctx context.Context, tx *sql.Tx) error {
if err != nil {
return err
}
_, err = tx.ExecContext(ctx, `
switch conf.Server.DbDriver {
case "sqlite3":
_, err = tx.ExecContext(ctx, `
update album set discs = t.discs
from (select album_id, json_group_object(disc_number, disc_subtitle) as discs
from (select distinct album_id, disc_number, disc_subtitle
from media_file
where disc_number > 0
order by album_id, disc_number)
group by album_id
having discs <> '{"1":""}') as t
where album.id = t.album_id;
`)
case "pgx":
_, err = tx.ExecContext(ctx, `
update album set discs = t.discs
from (select album_id, json_object_agg(disc_number, disc_subtitle) as discs
from (select distinct album_id, disc_number, disc_subtitle
from media_file
where disc_number > 0
order by album_id, disc_number)
order by album_id, disc_number) as files
group by album_id
having discs <> '{"1":""}') as t
having to_jsonb(json_object_agg(disc_number, disc_subtitle)) <> '{"1":""}') as t
where album.id = t.album_id;
`)
}
return err
}

View File

@ -24,7 +24,7 @@ func upAlterLyricColumn(ctx context.Context, tx *sql.Tx) error {
return err
}
stmt, err := tx.Prepare(`update media_file SET lyrics = ? where id = ?`)
stmt, err := tx.Prepare(`update media_file SET lyrics = $1 where id = $2`)
if err != nil {
return err
}

View File

@ -36,7 +36,7 @@ var (
func isDBInitialized(tx *sql.Tx) bool {
once.Do(func() {
rows, err := tx.Query("select count(*) from property where id=?", consts.InitialSetupFlagKey)
rows, err := tx.Query("select count(*) from property where id=$1", consts.InitialSetupFlagKey)
checkErr(err)
initialized = checkCount(rows) > 0
})

3
go.mod
View File

@ -24,6 +24,7 @@ require (
github.com/google/uuid v1.5.0
github.com/google/wire v0.5.0
github.com/hashicorp/go-multierror v1.1.1
github.com/jackc/pgx/v5 v5.4.3
github.com/kr/pretty v0.3.1
github.com/lestrrat-go/jwx/v2 v2.0.18
github.com/matoous/go-nanoid/v2 v2.0.0
@ -68,6 +69,8 @@ require (
github.com/hashicorp/errwrap v1.0.0 // indirect
github.com/hashicorp/hcl v1.0.0 // indirect
github.com/inconshreveable/mousetrap v1.1.0 // indirect
github.com/jackc/pgpassfile v1.0.0 // indirect
github.com/jackc/pgservicefile v0.0.0-20221227161230-091c0ba34f0a // indirect
github.com/kr/text v0.2.0 // indirect
github.com/lann/builder v0.0.0-20180802200727-47ae307949d0 // indirect
github.com/lann/ps v0.0.0-20150810152359-62de8c46ede0 // indirect

7
go.sum
View File

@ -201,6 +201,12 @@ github.com/ianlancetaylor/demangle v0.0.0-20181102032728-5e5cf60278f6/go.mod h1:
github.com/ianlancetaylor/demangle v0.0.0-20200824232613-28f6c0f3b639/go.mod h1:aSSvb/t6k1mPoxDqO4vJh6VOCGPwU4O0C2/Eqndh1Sc=
github.com/inconshreveable/mousetrap v1.1.0 h1:wN+x4NVGpMsO7ErUn/mUI3vEoE6Jt13X2s0bqwp9tc8=
github.com/inconshreveable/mousetrap v1.1.0/go.mod h1:vpF70FUmC8bwa3OWnCshd2FqLfsEA9PFc4w1p2J65bw=
github.com/jackc/pgpassfile v1.0.0 h1:/6Hmqy13Ss2zCq62VdNG8tM1wchn8zjSGOBJ6icpsIM=
github.com/jackc/pgpassfile v1.0.0/go.mod h1:CEx0iS5ambNFdcRtxPj5JhEz+xB6uRky5eyVu/W2HEg=
github.com/jackc/pgservicefile v0.0.0-20221227161230-091c0ba34f0a h1:bbPeKD0xmW/Y25WS6cokEszi5g+S0QxI/d45PkRi7Nk=
github.com/jackc/pgservicefile v0.0.0-20221227161230-091c0ba34f0a/go.mod h1:5TJZWKEWniPve33vlWYSoGYefn3gLQRzjfDlhSJ9ZKM=
github.com/jackc/pgx/v5 v5.4.3 h1:cxFyXhxlvAifxnkKKdlxv8XqUf59tDlYjnV5YYfsJJY=
github.com/jackc/pgx/v5 v5.4.3/go.mod h1:Ig06C2Vu0t5qXC60W8sqIthScaEnFvojjj9dSljmHRA=
github.com/jstemmer/go-junit-report v0.0.0-20190106144839-af01ea7f8024/go.mod h1:6v2b51hI/fHJwM22ozAgKL4VKDeJcHhJFhtBdhmNjmU=
github.com/jstemmer/go-junit-report v0.9.1/go.mod h1:Brl9GWCQeLvo8nXZwPNNblvFj/XSXhF0NWZEnDohbsk=
github.com/jtolds/gls v4.20.0+incompatible h1:xdiiI2gbIgH/gLH7ADydsJ1uDOEzR8yvV7C0MuV77Wo=
@ -313,6 +319,7 @@ github.com/stretchr/objx v0.4.0/go.mod h1:YvHI0jy2hoMjB+UWwv71VJQ9isScKT/TqJzVSS
github.com/stretchr/objx v0.5.0 h1:1zr/of2m5FGMsad5YfcqgdqdWrIhu+EBEJRhR1U7z/c=
github.com/stretchr/objx v0.5.0/go.mod h1:Yh+to48EsGEfYuaHDzXPcE3xhTkx73EhmCGUpEOglKo=
github.com/stretchr/testify v1.2.2/go.mod h1:a8OnRcib4nhh0OaRAV+Yts87kKdq0PP7pXfy6kDkUVs=
github.com/stretchr/testify v1.3.0/go.mod h1:M5WIy9Dh21IEIfnGCwXGc5bZfKNJtfHm1UVUgZn+9EI=
github.com/stretchr/testify v1.4.0/go.mod h1:j7eGeouHqKxXV5pUuKE4zz7dFj8WfuZ+81PSLYec5m4=
github.com/stretchr/testify v1.5.1/go.mod h1:5W2xD1RspED5o8YsWQXVCued0rvSQ+mT+I5cxcmMvtA=
github.com/stretchr/testify v1.6.1/go.mod h1:6Fq8oRcR53rry900zMqJjRRixrwX3KX962/h/Wwjteg=

View File

@ -22,6 +22,12 @@ type User struct {
CurrentPassword string `structs:"current_password,omitempty" json:"currentPassword,omitempty"`
}
// TableName overrides the table name used by User to '"user"' instead of 'user'. This is to support Postgres
// which has 'user' as a reserved word.
func (User) TableName() string {
return `"user"`
}
type Users []User
type UserRepository interface {

View File

@ -79,7 +79,7 @@ func NewArtistRepository(ctx context.Context, db dbx.Builder) model.ArtistReposi
func (r *artistRepository) selectArtist(options ...model.QueryOptions) SelectBuilder {
sql := r.newSelectWithAnnotation("artist.id", options...).Columns("artist.*")
return r.withGenres(sql).GroupBy("artist.id")
return r.withGenres(sql)
}
func (r *artistRepository) CountAll(options ...model.QueryOptions) (int64, error) {

View File

@ -141,8 +141,8 @@ func (r *mediaFileRepository) FindAllByPath(path string) (model.MediaFiles, erro
pathLen := utf8.RuneCountInString(path)
sel0 := r.newSelect().Columns("media_file.*", fmt.Sprintf("substr(path, %d) AS item", pathLen+2)).
Where(pathStartsWith(path))
sel := r.newSelect().Columns("*", "item NOT GLOB '*"+string(os.PathSeparator)+"*' AS isLast").
Where(Eq{"isLast": 1}).FromSelect(sel0, "sel0")
sel := r.newSelect().Columns("*").
Where(Eq{"item NOT LIKE '*" + string(os.PathSeparator) + "*'": true}).FromSelect(sel0, "sel0")
res := model.MediaFiles{}
err := r.queryAll(sel, &res)

View File

@ -189,8 +189,8 @@ func (r *playlistRepository) GetAll(options ...model.QueryOptions) (model.Playli
}
func (r *playlistRepository) selectPlaylist(options ...model.QueryOptions) SelectBuilder {
return r.newSelect(options...).Join("user on user.id = owner_id").
Columns(r.tableName+".*", "user.user_name as owner_name")
return r.newSelect(options...).Join(`"user" on "user".id = owner_id`).
Columns(r.tableName+".*", `"user".user_name as owner_name`)
}
func (r *playlistRepository) refreshSmartPlaylist(pls *model.Playlist) bool {
@ -345,7 +345,7 @@ func (r *playlistRepository) refreshCounters(pls *model.Playlist) error {
func (r *playlistRepository) loadTracks(sel SelectBuilder, id string) (model.PlaylistTracks, error) {
tracksQuery := sel.
Columns(
"coalesce(starred, 0)",
"coalesce(starred, false)",
"starred_at",
"coalesce(play_count, 0)",
"play_date",
@ -422,7 +422,7 @@ func (r *playlistRepository) removeOrphans() error {
Join("playlist p on playlist_tracks.playlist_id = p.id").
LeftJoin("media_file mf on playlist_tracks.media_file_id = mf.id").
Where(Eq{"mf.id": nil}).
GroupBy("playlist_tracks.playlist_id")
GroupBy("playlist_tracks.playlist_id", "p.name")
var pls []struct{ Id, Name string }
err := r.queryAll(sel, &pls)

View File

@ -50,7 +50,7 @@ func (r *playlistTrackRepository) Read(id string) (interface{}, error) {
" AND annotation.item_type = 'media_file'"+
" AND annotation.user_id = '"+userId(r.ctx)+"')").
Columns(
"coalesce(starred, 0)",
"coalesce(starred, false)",
"coalesce(play_count, 0)",
"coalesce(rating, 0)",
"starred_at",

View File

@ -49,13 +49,13 @@ func (r *scrobbleBufferRepository) Enqueue(service, userId, mediaFileId string,
func (r *scrobbleBufferRepository) Next(service string, userId string) (*model.ScrobbleEntry, error) {
sql := Select().Columns("s.*, m.*").
From(r.tableName+" s").
From(r.tableName + " s").
LeftJoin("media_file m on m.id = s.media_file_id").
Where(And{
Eq{"service": service},
Eq{"user_id": userId},
}).
OrderBy("play_time", "s.rowid").Limit(1)
OrderBy("play_time").Limit(1)
res := model.ScrobbleEntries{}
// TODO Rewrite queryOne to use QueryRows, to workaround the recursive embedded structs issue

View File

@ -20,7 +20,7 @@ func (r sqlRepository) newSelectWithAnnotation(idField string, options ...model.
" AND annotation.item_type = '"+r.tableName+"'"+
" AND annotation.user_id = '"+userId(r.ctx)+"')").
Columns(
"coalesce(starred, 0) as starred",
"coalesce(starred, false) as starred",
"coalesce(rating, 0) as rating",
"coalesce(play_count, 0) as play_count",
"starred_at",

View File

@ -47,7 +47,7 @@ func (r *sqlRepository) loadMediaFileGenres(mfs *model.MediaFiles) error {
return slice.RangeByChunks(ids, 900, func(ids []string) error {
sql := Select("g.*", "mg.media_file_id").From("genre g").Join("media_file_genres mg on mg.genre_id = g.id").
Where(Eq{"mg.media_file_id": ids}).OrderBy("mg.media_file_id", "mg.rowid")
Where(Eq{"mg.media_file_id": ids}).OrderBy("mg.media_file_id")
var genres []struct {
model.Genre
MediaFileId string
@ -76,7 +76,7 @@ func (r *sqlRepository) loadAlbumGenres(mfs *model.Albums) error {
return slice.RangeByChunks(ids, 900, func(ids []string) error {
sql := Select("g.*", "ag.album_id").From("genre g").Join("album_genres ag on ag.genre_id = g.id").
Where(Eq{"ag.album_id": ids}).OrderBy("ag.album_id", "ag.rowid")
Where(Eq{"ag.album_id": ids}).OrderBy("ag.album_id")
var genres []struct {
model.Genre
AlbumId string
@ -105,7 +105,7 @@ func (r *sqlRepository) loadArtistGenres(mfs *model.Artists) error {
return slice.RangeByChunks(ids, 900, func(ids []string) error {
sql := Select("g.*", "ag.artist_id").From("genre g").Join("artist_genres ag on ag.genre_id = g.id").
Where(Eq{"ag.artist_id": ids}).OrderBy("ag.artist_id", "ag.rowid")
Where(Eq{"ag.artist_id": ids}).OrderBy("ag.artist_id")
var genres []struct {
model.Genre
ArtistId string

View File

@ -34,7 +34,7 @@ func NewUserRepository(ctx context.Context, db dbx.Builder) model.UserRepository
r := &userRepository{}
r.ctx = ctx
r.db = db
r.tableName = "user"
r.tableName = `"user"`
once.Do(func() {
_ = r.initPasswordEncryptionKey()
})