From d459e8bdd64b0294dd18c90c94da7b2385887fdf Mon Sep 17 00:00:00 2001 From: Stefan Richter Date: Sun, 20 Nov 2022 21:47:19 -0800 Subject: [PATCH] Adding support for PostgreSQL as database This adds support for a second database backend: PostgreSQL (in addition to sqlite3). This allows externailzing the database used by gonic. --- cmd/gonic/gonic.go | 29 +++++++++---- db/db.go | 24 ++++++++--- db/migrations.go | 52 ++++++++++++++++------- mockfs/mockfs.go | 2 +- server/ctrlsubsonic/handlers_by_folder.go | 6 +-- server/ctrlsubsonic/handlers_by_tags.go | 6 +-- server/ctrlsubsonic/handlers_raw.go | 2 +- 7 files changed, 85 insertions(+), 36 deletions(-) diff --git a/cmd/gonic/gonic.go b/cmd/gonic/gonic.go index 625c348e..76fef21e 100644 --- a/cmd/gonic/gonic.go +++ b/cmd/gonic/gonic.go @@ -3,6 +3,7 @@ package main import ( "context" + "encoding/base64" "errors" "expvar" "flag" @@ -26,6 +27,7 @@ import ( "github.com/google/shlex" "github.com/gorilla/securecookie" + _ "github.com/jinzhu/gorm/dialects/postgres" _ "github.com/jinzhu/gorm/dialects/sqlite" "github.com/sentriz/gormstore" "golang.org/x/sync/errgroup" @@ -66,7 +68,12 @@ func main() { confPlaylistsPath := flag.String("playlists-path", "", "path to your list of new or existing m3u playlists that gonic can manage") - confDBPath := flag.String("db-path", "gonic.db", "path to database (optional)") + confSqlitePath := flag.String("db-path", "gonic.db", "path to database (optional, default: gonic.db)") + confPostgresHost := flag.String("postgres-host", "", "name of the PostgreSQL gonicServer (optional)") + confPostgresPort := flag.Int("postgres-port", 5432, "port to use for PostgreSQL connection (optional, default: 5432)") + confPostgresName := flag.String("postgres-db", "gonic", "name of the PostgreSQL database (optional, default: gonic)") + confPostgresUser := flag.String("postgres-user", "gonic", "name of the PostgreSQL user (optional, default: gonic)") + confPostgresSslModel := flag.String("postgres-ssl-mode", "verify-full", "the ssl mode used for connecting to the PostreSQL instance (optional, default: verify-full)") confScanIntervalMins := flag.Uint("scan-interval", 0, "interval (in minutes) to automatically scan music (optional)") confScanAtStart := flag.Bool("scan-at-start-enabled", false, "whether to perform an initial scan at startup (optional)") @@ -136,7 +143,12 @@ func main() { log.Fatalf("couldn't create covers cache path: %v\n", err) } - dbc, err := db.New(*confDBPath, db.DefaultOptions()) + var dbc *db.DB + if len(*confPostgresHost) > 0 { + dbc, err = db.NewPostgres(*confPostgresHost, *confPostgresPort, *confPostgresName, *confPostgresUser, os.Getenv("GONIC_POSTGRES_PW"), *confPostgresSslModel) + } else { + dbc, err = db.NewSqlite3(*confSqlitePath, db.DefaultOptions()) + } if err != nil { log.Fatalf("error opening database: %v\n", err) } @@ -144,7 +156,7 @@ func main() { err = dbc.Migrate(db.MigrationContext{ Production: true, - DBPath: *confDBPath, + DBPath: *confSqlitePath, OriginalMusicPath: confMusicPaths[0].path, PlaylistsPath: *confPlaylistsPath, PodcastsPath: *confPodcastPath, @@ -225,17 +237,18 @@ func main() { jukebx = jukebox.New() } - sessKey, err := dbc.GetSetting("session_key") + encSessKey, err := dbc.GetSetting("session_key") if err != nil { log.Panicf("error getting session key: %v\n", err) } - if sessKey == "" { - sessKey = string(securecookie.GenerateRandomKey(32)) - if err := dbc.SetSetting("session_key", sessKey); err != nil { + sessKey, err := base64.StdEncoding.DecodeString(encSessKey) + if err != nil || len(sessKey) == 0 { + sessKey = securecookie.GenerateRandomKey(32) + if err := dbc.SetSetting("session_key", base64.StdEncoding.EncodeToString(sessKey)); err != nil { log.Panicf("error setting session key: %v\n", err) } } - sessDB := gormstore.New(dbc.DB, []byte(sessKey)) + sessDB := gormstore.New(dbc.DB, []byte(encSessKey)) sessDB.SessionOpts.HttpOnly = true sessDB.SessionOpts.SameSite = http.SameSiteLaxMode diff --git a/db/db.go b/db/db.go index 9ea81a97..ef642d82 100644 --- a/db/db.go +++ b/db/db.go @@ -42,7 +42,7 @@ type DB struct { *gorm.DB } -func New(path string, options url.Values) (*DB, error) { +func NewSqlite3(path string, options url.Values) (*DB, error) { // https://github.com/mattn/go-sqlite3#connection-string url := url.URL{ Scheme: "file", @@ -53,13 +53,26 @@ func New(path string, options url.Values) (*DB, error) { if err != nil { return nil, fmt.Errorf("with gorm: %w", err) } + return newDB(db) +} + +func NewPostgres(host string, port int, databaseName string, username string, password string, sslmode string) (*DB, error) { + pathAndArgs := fmt.Sprintf("host=%s port=%d user=%s dbname=%s password=%s sslmode=%s", host, port, username, databaseName, password, sslmode) + db, err := gorm.Open("postgres", pathAndArgs) + if err != nil { + return nil, fmt.Errorf("with gorm: %w", err) + } + return newDB(db) +} + +func newDB(db *gorm.DB) (*DB, error) { db.SetLogger(log.New(os.Stdout, "gorm ", 0)) db.DB().SetMaxOpenConns(1) return &DB{DB: db}, nil } func NewMock() (*DB, error) { - return New(":memory:", mockOptions()) + return NewSqlite3(":memory:", mockOptions()) } func (db *DB) InsertBulkLeftMany(table string, head []string, left int, col []int) error { @@ -72,10 +85,11 @@ func (db *DB) InsertBulkLeftMany(table string, head []string, left int, col []in rows = append(rows, "(?, ?)") values = append(values, left, c) } - q := fmt.Sprintf("INSERT OR IGNORE INTO %q (%s) VALUES %s", + q := fmt.Sprintf("INSERT INTO %q (%s) VALUES %s ON CONFLICT (%s) DO NOTHING", table, strings.Join(head, ", "), strings.Join(rows, ", "), + strings.Join(head, ", "), ) return db.Exec(q, values...).Error } @@ -612,8 +626,8 @@ func join[T fmt.Stringer](in []T, sep string) string { return strings.Join(strs, sep) } -func Dump(ctx context.Context, db *gorm.DB, to string) error { - dest, err := New(to, url.Values{}) +func DumpToSqlite3(ctx context.Context, db *gorm.DB, to string) error { + dest, err := NewSqlite3(to, url.Values{}) if err != nil { return fmt.Errorf("create dest db: %w", err) } diff --git a/db/migrations.go b/db/migrations.go index 80304cf5..e9517bef 100644 --- a/db/migrations.go +++ b/db/migrations.go @@ -106,14 +106,14 @@ func constructNoTx(ctx MigrationContext, id string, f func(*gorm.DB, MigrationCo func migrateInitSchema(tx *gorm.DB, _ MigrationContext) error { return tx.AutoMigrate( Genre{}, + Artist{}, + Album{}, + Track{}, TrackGenre{}, AlbumGenre{}, - Track{}, - Artist{}, User{}, Setting{}, Play{}, - Album{}, PlayQueue{}, ). Error @@ -179,12 +179,18 @@ func migrateAddGenre(tx *gorm.DB, _ MigrationContext) error { func migrateUpdateTranscodePrefIDX(tx *gorm.DB, _ MigrationContext) error { var hasIDX int - tx. - Select("1"). - Table("sqlite_master"). - Where("type = ?", "index"). - Where("name = ?", "idx_user_id_client"). - Count(&hasIDX) + if tx.Dialect().GetName() == "sqlite3" { + tx.Select("1"). + Table("sqlite_master"). + Where("type = ?", "index"). + Where("name = ?", "idx_user_id_client"). + Count(&hasIDX) + } else if tx.Dialect().GetName() == "postgres" { + tx.Select("1"). + Table("pg_indexes"). + Where("indexname = ?", "idx_user_id_client"). + Count(&hasIDX) + } if hasIDX == 1 { // index already exists return nil @@ -461,9 +467,15 @@ func migratePlaylistsQueuesToFullID(tx *gorm.DB, _ MigrationContext) error { if err := step.Error; err != nil { return fmt.Errorf("step migrate play_queues to full id: %w", err) } - step = tx.Exec(` + if tx.Dialect().GetName() == "postgres" { + step = tx.Exec(` + UPDATE play_queues SET newcurrent=('tr-' || current)::varchar[200]; + `) + } else { + step = tx.Exec(` UPDATE play_queues SET newcurrent=('tr-' || CAST(current AS varchar(10))); `) + } if err := step.Error; err != nil { return fmt.Errorf("step migrate play_queues to full id: %w", err) } @@ -590,7 +602,7 @@ func migrateAlbumArtistsMany2Many(tx *gorm.DB, _ MigrationContext) error { return fmt.Errorf("step insert from albums: %w", err) } - step = tx.Exec(`DROP INDEX idx_albums_tag_artist_id`) + step = tx.Exec(`DROP INDEX IF EXISTS idx_albums_tag_artist_id`) if err := step.Error; err != nil { return fmt.Errorf("step drop index: %w", err) } @@ -730,10 +742,10 @@ func migratePlaylistsPaths(tx *gorm.DB, ctx MigrationContext) error { } func backupDBPre016(tx *gorm.DB, ctx MigrationContext) error { - if !ctx.Production { + if ctx.Production { return nil } - return Dump(context.Background(), tx, fmt.Sprintf("%s.%d.bak", ctx.DBPath, time.Now().Unix())) + return DumpToSqlite3(context.Background(), tx, fmt.Sprintf("%s.%d.bak", ctx.DBPath, time.Now().Unix())) } func migrateAlbumTagArtistString(tx *gorm.DB, _ MigrationContext) error { @@ -770,12 +782,22 @@ func migrateArtistAppearances(tx *gorm.DB, _ MigrationContext) error { return fmt.Errorf("step transfer album artists: %w", err) } - step = tx.Exec(` + if tx.Dialect().GetName() == "sqlite3" { + step = tx.Exec(` INSERT OR IGNORE INTO artist_appearances (artist_id, album_id) SELECT track_artists.artist_id, tracks.album_id FROM track_artists JOIN tracks ON tracks.id=track_artists.track_id `) + } else { + step = tx.Exec(` + INSERT INTO artist_appearances (artist_id, album_id) + SELECT track_artists.artist_id, tracks.album_id + FROM track_artists + JOIN tracks ON tracks.id=track_artists.track_id + ON CONFLICT DO NOTHING + `) + } if err := step.Error; err != nil { return fmt.Errorf("step transfer album artists: %w", err) } @@ -795,7 +817,7 @@ func migrateTemporaryDisplayAlbumArtist(tx *gorm.DB, _ MigrationContext) error { return tx.Exec(` UPDATE albums SET tag_album_artist=( - SELECT group_concat(artists.name, ', ') + SELECT string_agg(artists.name, ', ') FROM artists JOIN album_artists ON album_artists.artist_id=artists.id AND album_artists.album_id=albums.id GROUP BY album_artists.album_id diff --git a/mockfs/mockfs.go b/mockfs/mockfs.go index 450c136b..53bf9441 100644 --- a/mockfs/mockfs.go +++ b/mockfs/mockfs.go @@ -309,7 +309,7 @@ func (m *MockFS) DumpDB(suffix ...string) { p = append(p, suffix...) destPath := filepath.Join(os.TempDir(), strings.Join(p, "-")) - if err := db.Dump(context.Background(), m.db.DB, destPath); err != nil { + if err := db.DumpToSqlite3(context.Background(), m.db.DB, destPath); err != nil { m.t.Fatalf("dumping db: %v", err) } diff --git a/server/ctrlsubsonic/handlers_by_folder.go b/server/ctrlsubsonic/handlers_by_folder.go index 2f20017b..600ea096 100644 --- a/server/ctrlsubsonic/handlers_by_folder.go +++ b/server/ctrlsubsonic/handlers_by_folder.go @@ -31,13 +31,13 @@ func (c *Controller) ServeGetIndexes(r *http.Request) *spec.Response { } var folders []*db.Album c.dbc. - Select("*, count(sub.id) child_count"). + Select("albums.*, count(sub.id) child_count"). Preload("AlbumStar", "user_id=?", user.ID). Preload("AlbumRating", "user_id=?", user.ID). Joins("LEFT JOIN albums sub ON albums.id=sub.parent_id"). Where("albums.parent_id IN ?", rootQ.SubQuery()). Group("albums.id"). - Order("albums.right_path COLLATE NOCASE"). + Order("albums.right_path"). Find(&folders) // [a-z#] -> 27 indexMap := make(map[string]*spec.Index, 27) @@ -80,7 +80,7 @@ func (c *Controller) ServeGetMusicDirectory(r *http.Request) *spec.Response { Where("parent_id=?", id.Value). Preload("AlbumStar", "user_id=?", user.ID). Preload("AlbumRating", "user_id=?", user.ID). - Order("albums.right_path COLLATE NOCASE"). + Order("albums.right_path"). Find(&childFolders) for _, ch := range childFolders { childrenObj = append(childrenObj, spec.NewTCAlbumByFolder(ch)) diff --git a/server/ctrlsubsonic/handlers_by_tags.go b/server/ctrlsubsonic/handlers_by_tags.go index 3f5da918..39e552bd 100644 --- a/server/ctrlsubsonic/handlers_by_tags.go +++ b/server/ctrlsubsonic/handlers_by_tags.go @@ -26,13 +26,13 @@ func (c *Controller) ServeGetArtists(r *http.Request) *spec.Response { user := r.Context().Value(CtxUser).(*db.User) var artists []*db.Artist q := c.dbc. - Select("*, count(album_artists.album_id) album_count"). + Select("artists.*, count(album_artists.album_id) album_count"). Joins("JOIN album_artists ON album_artists.artist_id=artists.id"). Preload("ArtistStar", "user_id=?", user.ID). Preload("ArtistRating", "user_id=?", user.ID). Preload("Info"). Group("artists.id"). - Order("artists.name COLLATE NOCASE") + Order("artists.name") if m := getMusicFolder(c.musicPaths, params); m != "" { q = q. Joins("JOIN albums ON albums.id=album_artists.album_id"). @@ -230,7 +230,7 @@ func (c *Controller) ServeSearchThree(r *http.Request) *spec.Response { // search artists var artists []*db.Artist q := c.dbc. - Select("*, count(albums.id) album_count"). + Select("artists.*, count(albums.id) album_count"). Group("artists.id") for _, s := range queries { q = q.Where(`name LIKE ? OR name_u_dec LIKE ?`, s, s) diff --git a/server/ctrlsubsonic/handlers_raw.go b/server/ctrlsubsonic/handlers_raw.go index d050ebe4..91578f57 100644 --- a/server/ctrlsubsonic/handlers_raw.go +++ b/server/ctrlsubsonic/handlers_raw.go @@ -256,7 +256,7 @@ func streamGetTransodePreference(dbc *db.DB, userID int, client string) (*db.Tra var pref db.TranscodePreference err := dbc. Where("user_id=?", userID). - Where("client COLLATE NOCASE IN (?)", []string{"*", client}). + Where("client IN (?)", []string{"*", client}). Order("client DESC"). // ensure "*" is last if it's there First(&pref). Error