mirror of
https://github.com/idanoo/GoScrobble.git
synced 2024-11-21 16:11:56 +00:00
Migrating to postgresql
This commit is contained in:
parent
97a6087e42
commit
6c52aa7d78
28
.env.example
28
.env.example
@ -1,28 +0,0 @@
|
||||
MYSQL_HOST=
|
||||
MYSQL_USER=
|
||||
MYSQL_PASS=
|
||||
MYSQL_DB=
|
||||
|
||||
REDIS_HOST=127.0.0.1
|
||||
REDIS_PORT=6379
|
||||
REDIS_DB=
|
||||
REDIS_PREFIX="gs:"
|
||||
REDIS_AUTH=""
|
||||
|
||||
JWT_SECRET=
|
||||
JWT_EXPIRY=1800
|
||||
REFRESH_EXPIRY=604800
|
||||
|
||||
REVERSE_PROXIES=127.0.0.1
|
||||
PORT=42069
|
||||
|
||||
SENDGRID_API_KEY=
|
||||
MAIL_FROM_ADDRESS=
|
||||
MAIL_FROM_NAME=
|
||||
|
||||
DEV_MODE=false
|
||||
GOSCROBBLE_DOMAIN=""
|
||||
|
||||
DATA_DIRECTORY="/var/www/goscrobble-data"
|
||||
FRONTEND_DIRECTORY="/var/www/goscrobble-web"
|
||||
API_DOCS_DIRECTORY="/var/www/goscrobble-api/docs/api/build"
|
23
README.md
23
README.md
@ -2,7 +2,7 @@
|
||||
|
||||
Golang based music scrobbler.
|
||||
|
||||
Stack: Go 1.16+, Node 15+, React 17+, MySQL 8.0+, Redis
|
||||
Stack: Go 1.16+, Node 15+, React 17+, Postgresql 14.0+, Redis
|
||||
|
||||
There are prebuilt binaries/packages available.
|
||||
|
||||
@ -13,30 +13,25 @@ Copy .env.example to .env and set variables. You can use https://www.grc.com/pas
|
||||
|
||||
[Environment Variables](docs/config.md)
|
||||
|
||||
## Setup MySQL
|
||||
create user 'goscrobble'@'%' identified by 'supersecurepass';
|
||||
create database goscrobble;
|
||||
grant all privileges on goscrobble.* to 'goscrobble'@'%';
|
||||
|
||||
## Local Development
|
||||
cp .env.example .env # Fill in the blanks
|
||||
go mod tidy
|
||||
CGO_ENABLED=0 go run cmd/go-scrobble/*.go
|
||||
## Local development with docker
|
||||
This assumes you have goscrobble-api and goscrobble-web cloned in the same folder.
|
||||
|
||||
cp .env.development .env
|
||||
docker-compose up -d
|
||||
|
||||
Access API @ http://127.0.0.1:42069/api/v1
|
||||
Access frontend @ http://127.0.0.1:3000
|
||||
|
||||
## Prod deployment
|
||||
cp .env.example .env # Fill in the blanks
|
||||
cp .env.production .env # Fill in the blanks
|
||||
go build -o goscrobble cmd/go-scrobble/*.go
|
||||
./goscrobble
|
||||
|
||||
## Build API Docs
|
||||
## Build API docs
|
||||
cd docs/api && docker run --rm --name slate -v $(pwd)/build:/srv/slate/build -v $(pwd)/source:/srv/slate/source slatedocs/slate build
|
||||
|
||||
|
||||
## Test API Docs
|
||||
cd docs/api && docker run --rm --name slate -p 4567:4567 -v $(pwd)/source:/srv/slate/source slatedocs/slate serve
|
||||
|
||||
## Support Development!
|
||||
## Support development!
|
||||
Feel free to support hosting and my coffee addiction https://liberapay.com/idanoo
|
@ -9,7 +9,7 @@ import (
|
||||
"time"
|
||||
|
||||
"github.com/joho/godotenv"
|
||||
"gitlab.com/idanoo/go-scrobble/internal/goscrobble"
|
||||
"gitlab.com/goscrobble/goscrobble-api/internal/goscrobble"
|
||||
)
|
||||
|
||||
func init() {
|
42
docker-compose.yml
Normal file
42
docker-compose.yml
Normal file
@ -0,0 +1,42 @@
|
||||
version: "3.9"
|
||||
|
||||
services:
|
||||
frontend:
|
||||
image: node:16
|
||||
volumes:
|
||||
- ../goscrobble-web:/app
|
||||
restart: always
|
||||
ports:
|
||||
- "127.0.0.1:3000:3000"
|
||||
environment:
|
||||
- REACT_APP_API_URL=http://127.0.0.1:42069
|
||||
command: bash -c "cd /app && npm install && yarn start"
|
||||
|
||||
backend:
|
||||
image: golang:1.16
|
||||
volumes:
|
||||
- ./:/app
|
||||
- data:/data
|
||||
ports:
|
||||
- "127.0.0.1:42069:42069"
|
||||
restart: always
|
||||
command: bash -c "cd /app && go mod tidy && go run cmd/goscrobble/*.go"
|
||||
|
||||
postgres:
|
||||
image: postgres:14.1
|
||||
volumes:
|
||||
- database-data:/var/lib/postgresql/data/
|
||||
restart: always
|
||||
environment:
|
||||
- POSTGRES_USER=goscrobble
|
||||
- POSTGRES_PASSWORD=supersecretdatabasepassword1
|
||||
- POSTGRES_DB=goscrobble
|
||||
|
||||
redis:
|
||||
image: redis:6.2
|
||||
ports:
|
||||
- "127.0.0.1:6379:6379"
|
||||
|
||||
volumes:
|
||||
database-data:
|
||||
data:
|
@ -2,6 +2,7 @@
|
||||
- Split frontend/backend code into separate repos (https://gitlab.com/goscrobble/goscrobble-web)
|
||||
- Added new ENV VARS to support unique configurations: DATA_DIRECTORY, FRONTEND_DIRECTORY, API_DOCS_DIRECTORY
|
||||
- Started API documentation @ /docs (https://goscrobble.com/docs/)
|
||||
- Added docker-compose file for local development!
|
||||
|
||||
# 0.0.33
|
||||
- Add mod permission
|
||||
|
@ -1,5 +1,5 @@
|
||||
## Timezones
|
||||
GoScrobble runs as UTC and connects to MySQL as UTC. All timezone handling is done in the frontend.
|
||||
GoScrobble runs as UTC and connects to postgres as UTC. All timezone handling is done in the frontend.
|
||||
|
||||
## FRONTEND VARS
|
||||
These are stored in `web/.env.production` and `web/.env.development`
|
||||
@ -8,10 +8,10 @@ These are stored in `web/.env.production` and `web/.env.development`
|
||||
|
||||
|
||||
## BACKEND VARS
|
||||
MYSQL_HOST= // MySQL Server
|
||||
MYSQL_USER= // MySQL User
|
||||
MYSQL_PASS= // MySQL Password
|
||||
MYSQL_DB= // MySQL Database
|
||||
POSTGRES_HOST= // postgres Server
|
||||
POSTGRES_USER= // postgres User
|
||||
POSTGRES_PASS= // postgres Password
|
||||
POSTGRES_DB= // postgres Database
|
||||
|
||||
REDIS_HOST=127.0.0.1 // Redis host
|
||||
REDIS_PORT= // Redis port (defaults 6379)
|
||||
|
4
go.mod
4
go.mod
@ -1,4 +1,4 @@
|
||||
module gitlab.com/idanoo/go-scrobble
|
||||
module gitlab.com/goscrobble/goscrobble-api
|
||||
|
||||
go 1.16
|
||||
|
||||
@ -11,13 +11,13 @@ require (
|
||||
github.com/docker/go-connections v0.4.0 // indirect
|
||||
github.com/docker/go-units v0.4.0 // indirect
|
||||
github.com/go-redis/redis/v8 v8.8.0
|
||||
github.com/go-sql-driver/mysql v1.5.0
|
||||
github.com/gogo/protobuf v1.3.1 // indirect
|
||||
github.com/golang-migrate/migrate v3.5.4+incompatible
|
||||
github.com/golang/protobuf v1.4.3 // indirect
|
||||
github.com/google/uuid v1.2.0
|
||||
github.com/gorilla/mux v1.8.0
|
||||
github.com/joho/godotenv v1.3.0
|
||||
github.com/lib/pq v1.10.4
|
||||
github.com/opencontainers/go-digest v1.0.0 // indirect
|
||||
github.com/opencontainers/image-spec v1.0.1 // indirect
|
||||
github.com/pkg/errors v0.9.1 // indirect
|
||||
|
4
go.sum
4
go.sum
@ -34,8 +34,6 @@ github.com/fsnotify/fsnotify v1.4.9 h1:hsms1Qyu0jgnwNXIxa+/V/PDsU6CfLf6CNO8H7IWo
|
||||
github.com/fsnotify/fsnotify v1.4.9/go.mod h1:znqG4EE+3YCdAaPaxE2ZRY/06pZUdp0tY4IgpuI1SZQ=
|
||||
github.com/go-redis/redis/v8 v8.8.0 h1:fDZP58UN/1RD3DjtTXP/fFZ04TFohSYhjZDkcDe2dnw=
|
||||
github.com/go-redis/redis/v8 v8.8.0/go.mod h1:F7resOH5Kdug49Otu24RjHWwgK7u9AmtqWMnCV1iP5Y=
|
||||
github.com/go-sql-driver/mysql v1.5.0 h1:ozyZYNQW3x3HtqT1jira07DN2PArx2v7/mN66gGcHOs=
|
||||
github.com/go-sql-driver/mysql v1.5.0/go.mod h1:DCzpHaOWr8IXmIStZouvnhqoel9Qv2LBy8hT2VhHyBg=
|
||||
github.com/gogo/protobuf v1.3.1 h1:DqDEcV5aeaTmdFBePNpYsp3FlcVH/2ISVVM9Qf8PSls=
|
||||
github.com/gogo/protobuf v1.3.1/go.mod h1:SlYgWuQ5SjCEi6WLHjHCa1yvBfUnHcTbrrZtXPKa29o=
|
||||
github.com/golang-migrate/migrate v3.5.4+incompatible h1:R7OzwvCJTCgwapPCiX6DyBiu2czIUMDCB118gFTKTUA=
|
||||
@ -72,6 +70,8 @@ github.com/joho/godotenv v1.3.0/go.mod h1:7hK45KPybAkOC6peb+G5yklZfMxEjkZhHbwpqx
|
||||
github.com/kisielk/errcheck v1.2.0/go.mod h1:/BMXB+zMLi60iA8Vv6Ksmxu/1UDYcXs4uQLJ+jE2L00=
|
||||
github.com/kisielk/gotool v1.0.0/go.mod h1:XhKaO+MFFWcvkIS/tQcRk01m1F5IRFswLeQ+oQHNcck=
|
||||
github.com/konsorten/go-windows-terminal-sequences v1.0.1/go.mod h1:T0+1ngSBFLxvqU3pZ+m/2kptfBszLMUkC4ZK/EgS/cQ=
|
||||
github.com/lib/pq v1.10.4 h1:SO9z7FRPzA03QhHKJrH5BXA6HU1rS4V2nIVrrNC1iYk=
|
||||
github.com/lib/pq v1.10.4/go.mod h1:AlVN5x4E4T544tWzH6hKfbfQvm3HdbOxrmggDNAPY9o=
|
||||
github.com/nxadm/tail v1.4.4 h1:DQuhQpB1tVlglWS2hLQ5OV6B5r8aGxSrPc5Qo6uTN78=
|
||||
github.com/nxadm/tail v1.4.4/go.mod h1:kenIhsEOeOJmVchQTgglprH7qJGnHDVpk1VPCcaMI8A=
|
||||
github.com/onsi/ginkgo v1.6.0/go.mod h1:lLunBs/Ym6LB5Z9jYTR76FiuTmxDTDusOGeTQH+WWjE=
|
||||
|
@ -73,7 +73,7 @@ func insertAlbum(name string, mbid string, spotifyId string, artists []string, i
|
||||
func getAlbumByCol(col string, val string, tx *sql.Tx) Album {
|
||||
var album Album
|
||||
err := tx.QueryRow(
|
||||
"SELECT BIN_TO_UUID(`uuid`, true), `name`, IFNULL(`desc`, ''), IFNULL(`img`,''), `mbid`, `spotify_id` FROM `albums` WHERE `"+col+"` = ?",
|
||||
"SELECT uuid, name, IFNULL(desc, ''), IFNULL(img,''), mbid, spotify_id FROM albums WHERE "+col+" = $1",
|
||||
val).Scan(&album.UUID, &album.Name, &album.Desc, &album.Img, &album.MusicBrainzID, &album.SpotifyID)
|
||||
|
||||
if err != nil {
|
||||
@ -92,8 +92,8 @@ func insertNewAlbum(album *Album, name string, mbid string, spotifyId string, im
|
||||
album.SpotifyID = spotifyId
|
||||
album.Img = img
|
||||
|
||||
_, err := tx.Exec("INSERT INTO `albums` (`uuid`, `name`, `mbid`, `spotify_id`, `img`) "+
|
||||
"VALUES (UUID_TO_BIN(?, true),?,?,?,?)", album.UUID, album.Name, album.MusicBrainzID, album.SpotifyID, album.Img)
|
||||
_, err := tx.Exec("INSERT INTO albums (uuid, name, mbid, spotify_id, img) "+
|
||||
"VALUES ($1,$2,$3,$4,$5)", album.UUID, album.Name, album.MusicBrainzID, album.SpotifyID, album.Img)
|
||||
|
||||
return err
|
||||
}
|
||||
@ -101,8 +101,8 @@ func insertNewAlbum(album *Album, name string, mbid string, spotifyId string, im
|
||||
func (album *Album) linkAlbumToArtists(artists []string, tx *sql.Tx) error {
|
||||
var err error
|
||||
for _, artist := range artists {
|
||||
_, err = tx.Exec("INSERT INTO `album_artist` (`album`, `artist`) "+
|
||||
"VALUES (UUID_TO_BIN(?, true), UUID_TO_BIN(?, true))", album.UUID, artist)
|
||||
_, err = tx.Exec("INSERT INTO album_artist (album, artist) "+
|
||||
"VALUES ($1,$2)", album.UUID, artist)
|
||||
if err != nil {
|
||||
return err
|
||||
}
|
||||
@ -112,14 +112,14 @@ func (album *Album) linkAlbumToArtists(artists []string, tx *sql.Tx) error {
|
||||
}
|
||||
|
||||
func (album *Album) updateAlbum(col string, val string, tx *sql.Tx) error {
|
||||
_, err := tx.Exec("UPDATE `albums` SET `"+col+"` = ? WHERE `uuid` = UUID_TO_BIN(?,true)", val, album.UUID)
|
||||
_, err := tx.Exec("UPDATE albums SET "+col+" = $1 WHERE uuid = $2", val, album.UUID)
|
||||
|
||||
return err
|
||||
}
|
||||
|
||||
func getAlbumByUUID(uuid string) (Album, error) {
|
||||
var album Album
|
||||
err := db.QueryRow("SELECT BIN_TO_UUID(`uuid`, true), `name`, IFNULL(`desc`,''), IFNULL(`img`,''), `mbid`, `spotify_id` FROM `albums` WHERE `uuid` = UUID_TO_BIN(?, true)",
|
||||
err := db.QueryRow("SELECT uuid, name, IFNULL(desc,''), IFNULL(img,''), mbid, spotify_id FROM albums WHERE uuid = $1",
|
||||
uuid).Scan(&album.UUID, &album.Name, &album.Desc, &album.Img, &album.MusicBrainzID, &album.SpotifyID)
|
||||
|
||||
if err != nil {
|
||||
|
@ -83,7 +83,7 @@ func insertArtist(name string, mbid string, spotifyId string, img string, tx *sq
|
||||
func getArtistByCol(col string, val string, tx *sql.Tx) Artist {
|
||||
var artist Artist
|
||||
err := tx.QueryRow(
|
||||
"SELECT BIN_TO_UUID(`uuid`, true), `name`, IFNULL(`desc`,''), IFNULL(`img`,''), `mbid`, `spotify_id` FROM `artists` WHERE `"+col+"` = ?",
|
||||
"SELECT uuid, name, IFNULL(desc,''), IFNULL(img,''), mbid, spotify_id FROM artists WHERE "+col+" = $1",
|
||||
val).Scan(&artist.UUID, &artist.Name, &artist.Desc, &artist.Img, &artist.MusicBrainzID, &artist.SpotifyID)
|
||||
|
||||
if err != nil {
|
||||
@ -102,21 +102,21 @@ func insertNewArtist(artist *Artist, name string, mbid string, spotifyId string,
|
||||
artist.SpotifyID = spotifyId
|
||||
artist.Img = img
|
||||
|
||||
_, err := tx.Exec("INSERT INTO `artists` (`uuid`, `name`, `mbid`, `spotify_id`, `img`) "+
|
||||
"VALUES (UUID_TO_BIN(?, true),?,?,?,?)", artist.UUID, artist.Name, artist.MusicBrainzID, artist.SpotifyID, artist.Img)
|
||||
_, err := tx.Exec("INSERT INTO artists (uuid, name, mbid, spotify_id, img) "+
|
||||
"VALUES ($1,$2,$3,$4,$5)", artist.UUID, artist.Name, artist.MusicBrainzID, artist.SpotifyID, artist.Img)
|
||||
|
||||
return err
|
||||
}
|
||||
|
||||
func (artist *Artist) updateArtist(col string, val string, tx *sql.Tx) error {
|
||||
_, err := tx.Exec("UPDATE `artists` SET `"+col+"` = ? WHERE `uuid` = UUID_TO_BIN(?,true)", val, artist.UUID)
|
||||
_, err := tx.Exec("UPDATE artists SET "+col+" = $1 WHERE uuid = $2", val, artist.UUID)
|
||||
|
||||
return err
|
||||
}
|
||||
|
||||
func getArtistByUUID(uuid string) (Artist, error) {
|
||||
var artist Artist
|
||||
err := db.QueryRow("SELECT BIN_TO_UUID(`uuid`, true), `name`, IFNULL(`desc`, ''), IFNULL(`img`,''), `mbid`, `spotify_id` FROM `artists` WHERE `uuid` = UUID_TO_BIN(?, true)",
|
||||
err := db.QueryRow("SELECT uuid, name, IFNULL(desc, ''), IFNULL(img,''), mbid, spotify_id FROM artists WHERE uuid = $1",
|
||||
uuid).Scan(&artist.UUID, &artist.Name, &artist.Desc, &artist.Img, &artist.MusicBrainzID, &artist.SpotifyID)
|
||||
|
||||
if err == sql.ErrNoRows {
|
||||
@ -129,13 +129,13 @@ func getArtistByUUID(uuid string) (Artist, error) {
|
||||
func getTopArtists(userUuid string) (TopArtists, error) {
|
||||
var topArtist TopArtists
|
||||
|
||||
rows, err := db.Query("SELECT BIN_TO_UUID(`artists`.`uuid`, true), `artists`.`name`, IFNULL(BIN_TO_UUID(`artists`.`uuid`, true),''), count(*) "+
|
||||
"FROM `scrobbles` "+
|
||||
"JOIN `tracks` ON `tracks`.`uuid` = `scrobbles`.`track` "+
|
||||
rows, err := db.Query("SELECT artists.uuid, artists.name, IFNULL(artists.uuid,''), count(*) "+
|
||||
"FROM scrobbles "+
|
||||
"JOIN tracks ON tracks.uuid = scrobbles.track "+
|
||||
"JOIN track_artist ON track_artist.track = tracks.uuid "+
|
||||
"JOIN artists ON track_artist.artist = artists.uuid "+
|
||||
"WHERE `scrobbles`.`user` = UUID_TO_BIN(?, true) "+
|
||||
"GROUP BY `artists`.`uuid` "+
|
||||
"WHERE scrobbles.user = $1 "+
|
||||
"GROUP BY artists.uuid "+
|
||||
"ORDER BY count(*) DESC "+
|
||||
"LIMIT 14;",
|
||||
userUuid)
|
||||
|
@ -20,7 +20,7 @@ func getAllConfigs() (Config, error) {
|
||||
config := Config{}
|
||||
configs := make(map[string]string)
|
||||
|
||||
rows, err := db.Query("SELECT `key`, `value` FROM `config`")
|
||||
rows, err := db.Query("SELECT key, value FROM config")
|
||||
if err != nil {
|
||||
log.Printf("Failed to fetch config: %+v", err)
|
||||
return config, errors.New("Failed to fetch configs")
|
||||
@ -53,7 +53,7 @@ func getAllConfigs() (Config, error) {
|
||||
}
|
||||
|
||||
func updateConfigValue(key string, value string) error {
|
||||
_, err := db.Exec("UPDATE `config` SET `value` = ? WHERE `key` = ?", value, key)
|
||||
_, err := db.Exec("UPDATE config SET value = $1 WHERE key = $2", value, key)
|
||||
if err != nil {
|
||||
fmt.Printf("Failed to update config: %+v", err)
|
||||
return errors.New("Failed to update config value.")
|
||||
@ -65,8 +65,8 @@ func updateConfigValue(key string, value string) error {
|
||||
func getConfigValue(key string) (string, error) {
|
||||
var value string
|
||||
|
||||
err := db.QueryRow("SELECT `value` FROM `config` "+
|
||||
"WHERE `key` = ?",
|
||||
err := db.QueryRow("SELECT value FROM config "+
|
||||
"WHERE key = $1",
|
||||
key).Scan(&value)
|
||||
|
||||
if err == sql.ErrNoRows {
|
||||
|
@ -8,22 +8,26 @@ import (
|
||||
"os"
|
||||
"time"
|
||||
|
||||
_ "github.com/go-sql-driver/mysql"
|
||||
"github.com/golang-migrate/migrate"
|
||||
"github.com/golang-migrate/migrate/database/mysql"
|
||||
"github.com/golang-migrate/migrate/database/postgres"
|
||||
_ "github.com/golang-migrate/migrate/source/file"
|
||||
_ "github.com/lib/pq"
|
||||
)
|
||||
|
||||
var db *sql.DB
|
||||
|
||||
// InitDb - Boots up a DB connection
|
||||
func InitDb() {
|
||||
dbHost := os.Getenv("MYSQL_HOST")
|
||||
dbUser := os.Getenv("MYSQL_USER")
|
||||
dbPass := os.Getenv("MYSQL_PASS")
|
||||
dbName := os.Getenv("MYSQL_DB")
|
||||
dbHost := os.Getenv("POSTGRES_HOST")
|
||||
dbUser := os.Getenv("POSTGRES_USER")
|
||||
dbPass := os.Getenv("POSTGRES_PASS")
|
||||
dbName := os.Getenv("POSTGRES_DB")
|
||||
|
||||
dbConn, err := sql.Open(
|
||||
"postgres",
|
||||
fmt.Sprintf("host=%s port=%d user=%s password=%s dbname=%s sslmode=disable", dbHost, 5432, dbUser, dbPass, dbName),
|
||||
)
|
||||
|
||||
dbConn, err := sql.Open("mysql", dbUser+":"+dbPass+"@tcp("+dbHost+")/"+dbName+"?multiStatements=true&parseTime=true&loc=Etc%2FUTC")
|
||||
if err != nil {
|
||||
panic(err)
|
||||
}
|
||||
@ -49,14 +53,14 @@ func CloseDbConn() {
|
||||
|
||||
func runMigrations() {
|
||||
fmt.Println("Checking database migrations")
|
||||
driver, err := mysql.WithInstance(db, &mysql.Config{})
|
||||
driver, err := postgres.WithInstance(db, &postgres.Config{})
|
||||
if err != nil {
|
||||
log.Fatalf("Unable to run migrations! %v", err)
|
||||
}
|
||||
|
||||
m, err := migrate.NewWithDatabaseInstance(
|
||||
"file://migrations",
|
||||
"mysql",
|
||||
"postgres",
|
||||
driver,
|
||||
)
|
||||
if err != nil {
|
||||
|
@ -13,7 +13,7 @@ type Genre struct {
|
||||
func getGenreByUUID(uuid string) Genre {
|
||||
var genre Genre
|
||||
err := db.QueryRow(
|
||||
"SELECT BIN_TO_UUID(`uuid`, true), `name` FROM `artists` WHERE `uuid` = UUID_TO_BIN(?,true)",
|
||||
"SELECT uuid, name FROM artists WHERE uuid = $1",
|
||||
uuid).Scan(&genre.UUID, &genre.Name)
|
||||
|
||||
if err != nil {
|
||||
@ -28,7 +28,7 @@ func getGenreByUUID(uuid string) Genre {
|
||||
func getGenreByName(name string) Genre {
|
||||
var genre Genre
|
||||
err := db.QueryRow(
|
||||
"SELECT BIN_TO_UUID(`uuid`, true), `name` FROM `artists` WHERE `name` = ?",
|
||||
"SELECT uuid, name FROM artists WHERE name = $1",
|
||||
name).Scan(&genre.UUID, &genre.Name)
|
||||
|
||||
if err != nil {
|
||||
@ -41,7 +41,7 @@ func getGenreByName(name string) Genre {
|
||||
}
|
||||
|
||||
func (genre *Genre) updateGenreName(name string, value string) error {
|
||||
_, err := db.Exec("UPDATE `genres` SET `name` = ? WHERE uuid = UUID_TO_BIN(?, true)", name, genre.UUID)
|
||||
_, err := db.Exec("UPDATE genres SET name = $1 WHERE uuid = $2", name, genre.UUID)
|
||||
|
||||
return err
|
||||
}
|
||||
|
@ -238,7 +238,7 @@ func (user *User) updateImageDataFromSpotify() error {
|
||||
client := auth.NewClient(token)
|
||||
client.AutoRetry = true
|
||||
|
||||
rows, err := db.Query("SELECT BIN_TO_UUID(`uuid`, true), `name` FROM `artists` WHERE IFNULL(`img`,'') NOT IN ('pending', 'complete') LIMIT 100")
|
||||
rows, err := db.Query("SELECT uuid, name FROM artists WHERE IFNULL(img,'') NOT IN ('pending', 'complete') LIMIT 100")
|
||||
if err != nil {
|
||||
log.Printf("Failed to fetch config: %+v", err)
|
||||
return errors.New("Failed to fetch artists")
|
||||
@ -282,7 +282,7 @@ func (user *User) updateImageDataFromSpotify() error {
|
||||
}
|
||||
tx.Commit()
|
||||
|
||||
rows, err = db.Query("SELECT BIN_TO_UUID(`uuid`, true), `name` FROM `albums` WHERE IFNULL(`img`,'') NOT IN ('pending', 'complete') LIMIT 100")
|
||||
rows, err = db.Query("SELECT uuid, name FROM albums WHERE IFNULL(img,'') NOT IN ('pending', 'complete') LIMIT 100")
|
||||
if err != nil {
|
||||
log.Printf("Failed to fetch config: %+v", err)
|
||||
return errors.New("Failed to fetch artists")
|
||||
|
@ -20,8 +20,8 @@ type OauthToken struct {
|
||||
func getOauthToken(userUuid string, service string) (OauthToken, error) {
|
||||
var oauth OauthToken
|
||||
|
||||
err := db.QueryRow("SELECT BIN_TO_UUID(`user`, true), `service`, `access_token`, `refresh_token`, `expiry`, `username`, `last_synced`, `url` FROM `oauth_tokens` "+
|
||||
"WHERE `user` = UUID_TO_BIN(?, true) AND `service` = ?",
|
||||
err := db.QueryRow("SELECT user, service, access_token, refresh_token, expiry, username, last_synced, url FROM oauth_tokens "+
|
||||
"WHERE user = $1 AND service = $2",
|
||||
userUuid, service).Scan(&oauth.UserUUID, &oauth.Service, &oauth.AccessToken, &oauth.RefreshToken, &oauth.Expiry, &oauth.Username, &oauth.LastSynced, &oauth.URL)
|
||||
|
||||
if err == sql.ErrNoRows {
|
||||
@ -32,14 +32,14 @@ func getOauthToken(userUuid string, service string) (OauthToken, error) {
|
||||
}
|
||||
|
||||
func insertOauthToken(userUuid string, service string, token string, refresh string, expiry time.Time, username string, lastSynced time.Time, url string) error {
|
||||
_, err := db.Exec("REPLACE INTO `oauth_tokens` (`user`, `service`, `access_token`, `refresh_token`, `expiry`, `username`, `last_synced`, `url`) "+
|
||||
"VALUES (UUID_TO_BIN(?, true),?,?,?,?,?,?,?)", userUuid, service, token, refresh, expiry, username, lastSynced, url)
|
||||
_, err := db.Exec("REPLACE INTO oauth_tokens (user, service, access_token, refresh_token, expiry, username, last_synced, url) "+
|
||||
"VALUES ($1,$2,$3,$4,$5,$6,$7,$8)", userUuid, service, token, refresh, expiry, username, lastSynced, url)
|
||||
|
||||
return err
|
||||
}
|
||||
|
||||
func removeOauthToken(userUuid string, service string) error {
|
||||
_, err := db.Exec("DELETE FROM `oauth_tokens` WHERE `user` = UUID_TO_BIN(?, true) AND `service` = ?", userUuid, service)
|
||||
_, err := db.Exec("DELETE FROM oauth_tokens WHERE user = $1 AND service = $2", userUuid, service)
|
||||
|
||||
return err
|
||||
}
|
||||
|
@ -59,7 +59,7 @@ func getScrobblesForUser(userUuid string, limit int, page int) (ScrobbleResponse
|
||||
|
||||
// Yeah this isn't great. But for now.. it works! Cache later
|
||||
total, err := getDbCount(
|
||||
"SELECT COUNT(*) FROM `scrobbles` WHERE `user` = UUID_TO_BIN(?, true) ", userUuid)
|
||||
"SELECT COUNT(*) FROM scrobbles WHERE user = $1", userUuid)
|
||||
|
||||
if err != nil {
|
||||
log.Printf("Failed to fetch scrobble count: %+v", err)
|
||||
@ -67,16 +67,16 @@ func getScrobblesForUser(userUuid string, limit int, page int) (ScrobbleResponse
|
||||
}
|
||||
|
||||
rows, err := db.Query(
|
||||
"SELECT BIN_TO_UUID(`scrobbles`.`uuid`, true), `scrobbles`.`created_at`, BIN_TO_UUID(`artists`.`uuid`, true), `artists`.`name`, `albums`.`name`, BIN_TO_UUID(`tracks`.`uuid`, true), `tracks`.`name`, `scrobbles`.`source` FROM `scrobbles` "+
|
||||
"SELECT scrobbles.uuid, scrobbles.created_at, artists.uuid, artists.name, albums.name, tracks.uuid, tracks.name, scrobbles.source FROM scrobbles "+
|
||||
"JOIN tracks ON scrobbles.track = tracks.uuid "+
|
||||
"JOIN track_artist ON track_artist.track = tracks.uuid "+
|
||||
"JOIN track_album ON track_album.track = tracks.uuid "+
|
||||
"JOIN artists ON track_artist.artist = artists.uuid "+
|
||||
"JOIN albums ON track_album.album = albums.uuid "+
|
||||
"JOIN users ON scrobbles.user = users.uuid "+
|
||||
"WHERE user = UUID_TO_BIN(?, true) "+
|
||||
"WHERE user = $1 "+
|
||||
"GROUP BY scrobbles.uuid, albums.uuid "+
|
||||
"ORDER BY scrobbles.created_at DESC LIMIT ?",
|
||||
"ORDER BY scrobbles.created_at DESC LIMIT $2",
|
||||
userUuid, limit)
|
||||
|
||||
if err != nil {
|
||||
@ -110,14 +110,14 @@ func getScrobblesForUser(userUuid string, limit int, page int) (ScrobbleResponse
|
||||
}
|
||||
|
||||
func insertNewScrobble(user string, track string, source string, timestamp time.Time, ip net.IP, tx *sql.Tx) error {
|
||||
_, err := tx.Exec("INSERT INTO `scrobbles` (`uuid`, `created_at`, `created_ip`, `user`, `track`, `source`) "+
|
||||
"VALUES (UUID_TO_BIN(?, true), ?, ?, UUID_TO_BIN(?, true), UUID_TO_BIN(?, true), ?)", newUUID(), timestamp, ip, user, track, source)
|
||||
_, err := tx.Exec(`INSERT INTO scrobbles (uuid, created_at, created_ip, "user", track, source) `+
|
||||
`VALUES ($1,$2,$3,$4,$5,$6)`, newUUID(), timestamp, ip.String(), user, track, source)
|
||||
|
||||
return err
|
||||
}
|
||||
|
||||
func checkIfScrobbleExists(userUuid string, timestamp time.Time, source string) bool {
|
||||
count, err := getDbCount("SELECT COUNT(*) FROM `scrobbles` WHERE `user` = UUID_TO_BIN(?, true) AND `created_at` = ? AND `source` = ?",
|
||||
count, err := getDbCount(`SELECT COUNT(*) FROM scrobbles WHERE "user" = $1 AND created_at = $2 AND source = $3`,
|
||||
userUuid, timestamp, source)
|
||||
|
||||
if err != nil {
|
||||
|
@ -53,25 +53,25 @@ func getAllStats() (StatsRequest, error) {
|
||||
statsReq := StatsRequest{}
|
||||
var err error
|
||||
|
||||
statsReq.Users, err = getDbCount("SELECT COUNT(*) FROM `users` WHERE `active` = 1")
|
||||
statsReq.Users, err = getDbCount("SELECT COUNT(*) FROM users WHERE active = true")
|
||||
if err != nil {
|
||||
log.Printf("Failed to fetch user count: %+v", err)
|
||||
return statsReq, errors.New("Failed to fetch stats")
|
||||
}
|
||||
|
||||
statsReq.Scrobbles, err = getDbCount("SELECT COUNT(*) FROM `scrobbles`")
|
||||
statsReq.Scrobbles, err = getDbCount("SELECT COUNT(*) FROM scrobbles")
|
||||
if err != nil {
|
||||
log.Printf("Failed to fetch scrobble count: %+v", err)
|
||||
return statsReq, errors.New("Failed to fetch stats")
|
||||
}
|
||||
|
||||
statsReq.Tracks, err = getDbCount("SELECT COUNT(*) FROM `tracks`")
|
||||
statsReq.Tracks, err = getDbCount("SELECT COUNT(*) FROM tracks")
|
||||
if err != nil {
|
||||
log.Printf("Failed to fetch track count: %+v", err)
|
||||
return statsReq, errors.New("Failed to fetch stats")
|
||||
}
|
||||
|
||||
statsReq.Artists, err = getDbCount("SELECT COUNT(*) FROM `artists`")
|
||||
statsReq.Artists, err = getDbCount("SELECT COUNT(*) FROM artists")
|
||||
if err != nil {
|
||||
log.Printf("Failed to fetch artist count: %+v", err)
|
||||
return statsReq, errors.New("Failed to fetch stats")
|
||||
|
@ -29,7 +29,7 @@ func getUserUuidForToken(token string) (string, error) {
|
||||
var uuid string
|
||||
cachedKey := getRedisVal("user_token:" + token)
|
||||
if cachedKey == "" {
|
||||
err := db.QueryRow("SELECT BIN_TO_UUID(`uuid`, true) FROM `users` WHERE `token` = ? AND `active` = 1", token).Scan(&uuid)
|
||||
err := db.QueryRow("SELECT uuid FROM users WHERE token = $1 AND active = true", token).Scan(&uuid)
|
||||
if err != nil {
|
||||
return "", errors.New("Invalid Token")
|
||||
}
|
||||
@ -43,21 +43,21 @@ func getUserUuidForToken(token string) (string, error) {
|
||||
|
||||
func insertRefreshToken(userUuid string, token string) error {
|
||||
uuid := newUUID()
|
||||
_, err := db.Exec("INSERT INTO `refresh_tokens` (`uuid`, `user`, `token`) VALUES (UUID_TO_BIN(?,true),UUID_TO_BIN(?,true),?)",
|
||||
_, err := db.Exec(`INSERT INTO refresh_tokens (uuid, "user", token) VALUES ($1,$2,$3)`,
|
||||
uuid, userUuid, token)
|
||||
|
||||
return err
|
||||
}
|
||||
|
||||
func deleteRefreshToken(token string) error {
|
||||
_, err := db.Exec("DELETE FROM `refresh_tokens` WHERE `token` = ?", token)
|
||||
_, err := db.Exec("DELETE FROM refresh_tokens WHERE token = $1", token)
|
||||
|
||||
return err
|
||||
}
|
||||
|
||||
func isValidRefreshToken(refreshTokenStr string) (User, error) {
|
||||
var refresh RefreshToken
|
||||
err := db.QueryRow("SELECT BIN_TO_UUID(`uuid`, true), BIN_TO_UUID(`user`, true), `token`, `expiry` FROM `refresh_tokens` WHERE `token` = ?",
|
||||
err := db.QueryRow("SELECT uuid, user, token, expiry FROM refresh_tokens WHERE token = $1",
|
||||
refreshTokenStr).Scan(&refresh.UUID, &refresh.User, &refresh.Token, &refresh.Expiry)
|
||||
if err != nil {
|
||||
return User{}, errors.New("Invalid Refresh Token")
|
||||
|
@ -98,7 +98,7 @@ func insertTrack(name string, legnth int, mbid string, spotifyId string, album s
|
||||
func getTrackByCol(col string, val string, tx *sql.Tx) Track {
|
||||
var track Track
|
||||
err := tx.QueryRow(
|
||||
"SELECT BIN_TO_UUID(`uuid`, true), `name`, IFNULL(`desc`,''), IFNULL(`img`,''), `mbid` FROM `tracks` WHERE `"+col+"` = ? LIMIT 1",
|
||||
"SELECT uuid, name, IFNULL(desc,''), IFNULL(img,''), mbid FROM tracks WHERE "+col+" = $1 LIMIT 1",
|
||||
val).Scan(&track.UUID, &track.Name, &track.Desc, &track.Img, &track.MusicBrainzID)
|
||||
|
||||
if err != nil {
|
||||
@ -114,11 +114,11 @@ func getTrackWithArtists(name string, artists []string, album string, tx *sql.Tx
|
||||
var track Track
|
||||
artistString := strings.Join(artists, "','")
|
||||
err := tx.QueryRow(
|
||||
"SELECT BIN_TO_UUID(`uuid`, true), `name`, IFNULL(`desc`,''), IFNULL(`img`,''), `mbid` FROM `tracks` "+
|
||||
"LEFT JOIN `track_artist` ON `tracks`.`uuid` = `track_artist`.`track` "+
|
||||
"LEFT JOIN `track_album` ON `tracks`.`uuid` = `track_album`.`track` "+
|
||||
"WHERE `name` = ? AND BIN_TO_UUID(`track_artist`.`artist`, true) IN ('"+artistString+"') "+
|
||||
"AND BIN_TO_UUID(`track_album`.`album`,true) = ? LIMIT 1",
|
||||
"SELECT uuid, name, IFNULL(desc,''), IFNULL(img,''), mbid FROM tracks "+
|
||||
"LEFT JOIN track_artist ON tracks.uuid = track_artist.track "+
|
||||
"LEFT JOIN track_album ON tracks.uuid = track_album.track "+
|
||||
"WHERE name = $1 AND track_artist.artistIN ('"+artistString+"') "+
|
||||
"AND track_album.album = $2 LIMIT 1",
|
||||
name, album).Scan(&track.UUID, &track.Name, &track.Desc, &track.Img, &track.MusicBrainzID)
|
||||
|
||||
if err != nil {
|
||||
@ -137,8 +137,8 @@ func insertNewTrack(track *Track, name string, length int, mbid string, spotifyI
|
||||
track.MusicBrainzID = mbid
|
||||
track.SpotifyID = spotifyId
|
||||
|
||||
_, err := tx.Exec("INSERT INTO `tracks` (`uuid`, `name`, `length`, `mbid`, `spotify_id`) "+
|
||||
"VALUES (UUID_TO_BIN(?, true),?,?,?,?)", track.UUID, track.Name, track.Length, track.MusicBrainzID, track.SpotifyID)
|
||||
_, err := tx.Exec("INSERT INTO tracks (uuid, name, length, mbid, spotify_id) "+
|
||||
"VALUES ($1,$2,$3,$4,$5)", track.UUID, track.Name, track.Length, track.MusicBrainzID, track.SpotifyID)
|
||||
|
||||
return err
|
||||
}
|
||||
@ -158,8 +158,8 @@ func (track *Track) linkTrack(album string, artists []string, tx *sql.Tx) error
|
||||
}
|
||||
|
||||
func (track *Track) linkTrackToAlbum(albumUuid string, tx *sql.Tx) error {
|
||||
_, err := tx.Exec("INSERT INTO `track_album` (`track`, `album`) "+
|
||||
"VALUES (UUID_TO_BIN(?, true), UUID_TO_BIN(?, true))", track.UUID, albumUuid)
|
||||
_, err := tx.Exec("INSERT INTO track_album (track, album) "+
|
||||
"VALUES ($1, $2)", track.UUID, albumUuid)
|
||||
|
||||
return err
|
||||
}
|
||||
@ -167,8 +167,8 @@ func (track *Track) linkTrackToAlbum(albumUuid string, tx *sql.Tx) error {
|
||||
func (track *Track) linkTrackToArtists(artists []string, tx *sql.Tx) error {
|
||||
var err error
|
||||
for _, artist := range artists {
|
||||
_, err = tx.Exec("INSERT INTO `track_artist` (`track`, `artist`) "+
|
||||
"VALUES (UUID_TO_BIN(?, true),UUID_TO_BIN(?, true))", track.UUID, artist)
|
||||
_, err = tx.Exec("INSERT INTO track_artist (track, artist) "+
|
||||
"VALUES ($1,$2)", track.UUID, artist)
|
||||
if err != nil {
|
||||
return err
|
||||
}
|
||||
@ -178,18 +178,18 @@ func (track *Track) linkTrackToArtists(artists []string, tx *sql.Tx) error {
|
||||
}
|
||||
|
||||
func (track *Track) updateTrack(col string, val string, tx *sql.Tx) error {
|
||||
_, err := tx.Exec("UPDATE `tracks` SET `"+col+"` = ? WHERE `uuid` = UUID_TO_BIN(?,true)", val, track.UUID)
|
||||
_, err := tx.Exec("UPDATE tracks SET "+col+" = $1 WHERE uuid = $2", val, track.UUID)
|
||||
|
||||
return err
|
||||
}
|
||||
|
||||
func getTrackByUUID(uuid string) (Track, error) {
|
||||
var track Track
|
||||
err := db.QueryRow("SELECT BIN_TO_UUID(`tracks`.`uuid`, true), `tracks`.`name`, IFNULL(`albums`.`desc`,''), IFNULL(BIN_TO_UUID(`albums`.`uuid`, true),''), `tracks`.`length`, `tracks`.`mbid`, `tracks`.`spotify_id` "+
|
||||
"FROM `tracks` "+
|
||||
err := db.QueryRow("SELECT tracks.uuid, tracks.name, IFNULL(albums.desc,''), IFNULL(albums.uuid,''), tracks.length, tracks.mbid, tracks.spotify_id "+
|
||||
"FROM tracks "+
|
||||
"LEFT JOIN track_album ON track_album.track = tracks.uuid "+
|
||||
"LEFT JOIN albums ON track_album.album = albums.uuid "+
|
||||
"WHERE `tracks`.`uuid` = UUID_TO_BIN(?, true)",
|
||||
"WHERE tracks.uuid = $1",
|
||||
uuid).Scan(&track.UUID, &track.Name, &track.Desc, &track.Img, &track.Length, &track.MusicBrainzID, &track.SpotifyID)
|
||||
|
||||
if err != nil {
|
||||
@ -203,13 +203,13 @@ func getTrackByUUID(uuid string) (Track, error) {
|
||||
func getTopTracks(userUuid string) (TopTracks, error) {
|
||||
var topTracks TopTracks
|
||||
|
||||
rows, err := db.Query("SELECT BIN_TO_UUID(`tracks`.`uuid`, true), `tracks`.`name`, IFNULL(BIN_TO_UUID(`albums`.`uuid`, true),''), count(*) "+
|
||||
"FROM `scrobbles` "+
|
||||
"JOIN `tracks` ON `tracks`.`uuid` = `scrobbles`.`track` "+
|
||||
rows, err := db.Query("SELECT tracks.uuid, tracks.name, IFNULL(albums.uuid,''), count(*) "+
|
||||
"FROM scrobbles "+
|
||||
"JOIN tracks ON tracks.uuid = scrobbles.track "+
|
||||
"JOIN track_album ON track_album.track = tracks.uuid "+
|
||||
"JOIN albums ON track_album.album = albums.uuid "+
|
||||
"WHERE `user` = UUID_TO_BIN(?, true) "+
|
||||
"GROUP BY `scrobbles`.`track` "+
|
||||
"WHERE user = $1 "+
|
||||
"GROUP BY scrobbles.track "+
|
||||
"ORDER BY count(*) DESC "+
|
||||
"LIMIT 14",
|
||||
userUuid)
|
||||
@ -251,9 +251,9 @@ func (track *Track) loadExtraTrackInfo() error {
|
||||
func (track *Track) getArtistsForTrack() error {
|
||||
artists := []Artist{}
|
||||
|
||||
rows, err := db.Query("SELECT BIN_TO_UUID(`track_artist`.`artist`, true) "+
|
||||
"FROM `track_artist` "+
|
||||
"WHERE `track_artist`.`track` = UUID_TO_BIN(?, true)",
|
||||
rows, err := db.Query("SELECT track_artist.artist "+
|
||||
"FROM track_artist "+
|
||||
"WHERE track_artist.track = $1",
|
||||
track.UUID)
|
||||
if err != nil {
|
||||
log.Printf("Failed to fetch artists for track: %+v", err)
|
||||
@ -283,9 +283,9 @@ func (track *Track) getArtistsForTrack() error {
|
||||
func (track *Track) getAlbumsForTrack() error {
|
||||
albums := []Album{}
|
||||
|
||||
rows, err := db.Query("SELECT BIN_TO_UUID(`track_album`.`album`, true) "+
|
||||
"FROM `track_album` "+
|
||||
"WHERE `track_album`.`track` = UUID_TO_BIN(?, true)",
|
||||
rows, err := db.Query("SELECT track_album.album "+
|
||||
"FROM track_album "+
|
||||
"WHERE track_album.track = $1",
|
||||
track.UUID)
|
||||
if err != nil {
|
||||
log.Printf("Failed to fetch album for track: %+v", err)
|
||||
@ -320,7 +320,7 @@ func getTopUsersForTrackUUID(trackUUID string, limit int, page int) (TopUserTrac
|
||||
// Yeah this isn't great. But for now.. it works! Cache later
|
||||
// TODO: This is counting total scrobbles, not unique users
|
||||
total, err := getDbCount(
|
||||
"SELECT COUNT(*) FROM `scrobbles` WHERE `track` = UUID_TO_BIN(?, true) GROUP BY `track`, `user`", trackUUID)
|
||||
"SELECT COUNT(*) FROM scrobbles WHERE track = $1 GROUP BY track, user", trackUUID)
|
||||
|
||||
if err != nil {
|
||||
log.Printf("Failed to fetch scrobble count: %+v", err)
|
||||
@ -328,12 +328,12 @@ func getTopUsersForTrackUUID(trackUUID string, limit int, page int) (TopUserTrac
|
||||
}
|
||||
|
||||
rows, err := db.Query(
|
||||
"SELECT BIN_TO_UUID(`scrobbles`.`user`, true), `users`.`username`, COUNT(*) "+
|
||||
"FROM `scrobbles` "+
|
||||
"JOIN `users` ON `scrobbles`.`user` = `users`.`uuid` "+
|
||||
"WHERE `track` = UUID_TO_BIN(?, true) "+
|
||||
"GROUP BY `scrobbles`.`user` "+
|
||||
"ORDER BY COUNT(*) DESC LIMIT ?",
|
||||
"SELECT scrobbles.user, users.username, COUNT(*) "+
|
||||
"FROM scrobbles "+
|
||||
"JOIN users ON scrobbles.user = users.uuid "+
|
||||
"WHERE track = $1 "+
|
||||
"GROUP BY scrobbles.user "+
|
||||
"ORDER BY COUNT(*) DESC LIMIT $2",
|
||||
trackUUID, limit)
|
||||
|
||||
if err != nil {
|
||||
|
@ -99,7 +99,7 @@ func loginUser(logReq *RequestRequest, ip net.IP) ([]byte, error) {
|
||||
}
|
||||
|
||||
if strings.Contains(logReq.Username, "@") {
|
||||
err := db.QueryRow("SELECT BIN_TO_UUID(`uuid`, true), `username`, `email`, `password`, `admin`, `mod` FROM `users` WHERE `email` = ? AND `active` = 1",
|
||||
err := db.QueryRow("SELECT uuid, username, email, password, admin, mod FROM users WHERE email = $1 AND active = true",
|
||||
logReq.Username).Scan(&user.UUID, &user.Username, &user.Email, &user.Password, &user.Admin, &user.Mod)
|
||||
if err != nil {
|
||||
if err == sql.ErrNoRows {
|
||||
@ -107,7 +107,7 @@ func loginUser(logReq *RequestRequest, ip net.IP) ([]byte, error) {
|
||||
}
|
||||
}
|
||||
} else {
|
||||
err := db.QueryRow("SELECT BIN_TO_UUID(`uuid`, true), `username`, `email`, `password`, `admin`, `mod` FROM `users` WHERE `username` = ? AND `active` = 1",
|
||||
err := db.QueryRow("SELECT uuid, username, email, password, admin, mod FROM users WHERE username = $1 AND active = true",
|
||||
logReq.Username).Scan(&user.UUID, &user.Username, &user.Email, &user.Password, &user.Admin, &user.Mod)
|
||||
if err == sql.ErrNoRows {
|
||||
return resp, errors.New("Invalid Username or Password")
|
||||
@ -136,20 +136,24 @@ func loginUser(logReq *RequestRequest, ip net.IP) ([]byte, error) {
|
||||
// insertUser - Does the dirtywork!
|
||||
func insertUser(username string, email string, password []byte, ip net.IP) error {
|
||||
token := generateToken(32)
|
||||
uuid := newUUID()
|
||||
|
||||
log.Printf(ip.String())
|
||||
|
||||
_, err := db.Exec("INSERT INTO users (uuid, created_at, created_ip, modified_at, modified_ip, username, email, password, token) "+
|
||||
"VALUES (UUID_TO_BIN(UUID(), true),NOW(),?,NOW(),?,?,?,?,?)", ip, ip, username, email, password, token)
|
||||
"VALUES ($1,NOW(),$2,NOW(),$3,$4,$5,$6,$7)", uuid, ip.String(), ip.String(), username, email, password, token)
|
||||
|
||||
return err
|
||||
}
|
||||
|
||||
func (user *User) updateUser(field string, value string, ip net.IP) error {
|
||||
_, err := db.Exec("UPDATE users SET `"+field+"` = ?, modified_at = NOW(), modified_ip = ? WHERE uuid = UUID_TO_BIN(?, true)", value, ip, user.UUID)
|
||||
_, err := db.Exec("UPDATE users SET "+field+" = $1, modified_at = NOW(), modified_ip = $2 WHERE uuid = $3", value, ip, user.UUID)
|
||||
|
||||
return err
|
||||
}
|
||||
|
||||
func (user *User) updateUserDirect(field string, value string) error {
|
||||
_, err := db.Exec("UPDATE users SET `"+field+"` = ? WHERE uuid = UUID_TO_BIN(?, true)", value, user.UUID)
|
||||
_, err := db.Exec("UPDATE users SET "+field+" = $1 WHERE uuid = $2", value, user.UUID)
|
||||
|
||||
return err
|
||||
}
|
||||
@ -172,7 +176,7 @@ func isValidPassword(password string, user User) bool {
|
||||
// userAlreadyExists - Returns bool indicating if a record exists for either username or email
|
||||
// Using two look ups to make use of DB indexes.
|
||||
func userAlreadyExists(req *RequestRequest) bool {
|
||||
count, err := getDbCount("SELECT COUNT(*) FROM users WHERE username = ?", req.Username)
|
||||
count, err := getDbCount("SELECT COUNT(*) FROM users WHERE username = $1", req.Username)
|
||||
if err != nil {
|
||||
fmt.Printf("Error querying for duplicate users: %v", err)
|
||||
return true
|
||||
@ -184,7 +188,7 @@ func userAlreadyExists(req *RequestRequest) bool {
|
||||
|
||||
if req.Email != "" {
|
||||
// Only run email check if there's an email...
|
||||
count, err = getDbCount("SELECT COUNT(*) FROM users WHERE email = ?", req.Email)
|
||||
count, err = getDbCount("SELECT COUNT(*) FROM users WHERE email = $1", req.Email)
|
||||
}
|
||||
|
||||
if err != nil {
|
||||
@ -197,7 +201,7 @@ func userAlreadyExists(req *RequestRequest) bool {
|
||||
|
||||
func getUserByUUID(uuid string) (User, error) {
|
||||
var user User
|
||||
err := db.QueryRow("SELECT BIN_TO_UUID(`uuid`, true), `created_at`, `created_ip`, `modified_at`, `modified_ip`, `username`, `email`, `password`, `verified`, `admin`, `mod`, `timezone`, `token` FROM `users` WHERE `uuid` = UUID_TO_BIN(?, true) AND `active` = 1",
|
||||
err := db.QueryRow("SELECT uuid, created_at, created_ip, modified_at, modified_ip, username, email, password, verified, admin, mod, timezone, token FROM users WHERE uuid = $1 AND active = true",
|
||||
uuid).Scan(&user.UUID, &user.CreatedAt, &user.CreatedIp, &user.ModifiedAt, &user.ModifiedIP, &user.Username, &user.Email, &user.Password, &user.Verified, &user.Admin, &user.Mod, &user.Timezone, &user.Token)
|
||||
|
||||
if err == sql.ErrNoRows {
|
||||
@ -209,7 +213,7 @@ func getUserByUUID(uuid string) (User, error) {
|
||||
|
||||
func getUserByUsername(username string) (User, error) {
|
||||
var user User
|
||||
err := db.QueryRow("SELECT BIN_TO_UUID(`uuid`, true), `created_at`, `created_ip`, `modified_at`, `modified_ip`, `username`, `email`, `password`, `verified`, `admin`, `mod`, `timezone`, `token` FROM `users` WHERE `username` = ? AND `active` = 1",
|
||||
err := db.QueryRow("SELECT uuid, created_at, created_ip, modified_at, modified_ip, username, email, password, verified, admin, mod, timezone, token FROM users WHERE username = $1 AND active = true",
|
||||
username).Scan(&user.UUID, &user.CreatedAt, &user.CreatedIp, &user.ModifiedAt, &user.ModifiedIP, &user.Username, &user.Email, &user.Password, &user.Verified, &user.Admin, &user.Mod, &user.Timezone, &user.Token)
|
||||
|
||||
if err == sql.ErrNoRows {
|
||||
@ -221,7 +225,7 @@ func getUserByUsername(username string) (User, error) {
|
||||
|
||||
func getUserByEmail(email string) (User, error) {
|
||||
var user User
|
||||
err := db.QueryRow("SELECT BIN_TO_UUID(`uuid`, true), `created_at`, `created_ip`, `modified_at`, `modified_ip`, `username`, `email`, `password`, `verified`, `admin`, `mod`, `timezone`, `token` FROM `users` WHERE `email` = ? AND `active` = 1",
|
||||
err := db.QueryRow("SELECT uuid, created_at, created_ip, modified_at, modified_ip, username, email, password, verified, admin, mod, timezone, token FROM users WHERE email = $1 AND active = true",
|
||||
email).Scan(&user.UUID, &user.CreatedAt, &user.CreatedIp, &user.ModifiedAt, &user.ModifiedIP, &user.Username, &user.Email, &user.Password, &user.Verified, &user.Admin, &user.Mod, &user.Timezone, &user.Token)
|
||||
|
||||
if err == sql.ErrNoRows {
|
||||
@ -233,8 +237,8 @@ func getUserByEmail(email string) (User, error) {
|
||||
|
||||
func getUserByResetToken(token string) (User, error) {
|
||||
var user User
|
||||
err := db.QueryRow("SELECT BIN_TO_UUID(`users`.`uuid`, true), `created_at`, `created_ip`, `modified_at`, `modified_ip`, `username`, `email`, `password`, `verified`, `admin`, `mod`, `timezone`, `token` FROM `users` "+
|
||||
"JOIN `resettoken` ON `resettoken`.`user` = `users`.`uuid` WHERE `resettoken`.`token` = ? AND `active` = 1",
|
||||
err := db.QueryRow("SELECT users.uuid, created_at, created_ip, modified_at, modified_ip, username, email, password, verified, admin, mod, timezone, token FROM users "+
|
||||
"JOIN resettoken ON resettoken.user = users.uuid WHERE resettoken.token = $1 AND active = true",
|
||||
token).Scan(&user.UUID, &user.CreatedAt, &user.CreatedIp, &user.ModifiedAt, &user.ModifiedIP, &user.Username, &user.Email, &user.Password, &user.Verified, &user.Admin, &user.Mod, &user.Timezone, &user.Token)
|
||||
|
||||
if err == sql.ErrNoRows {
|
||||
@ -265,26 +269,26 @@ func (user *User) sendResetEmail(ip net.IP) error {
|
||||
}
|
||||
|
||||
func (user *User) saveResetToken(token string, expiry time.Time) error {
|
||||
_, _ = db.Exec("DELETE FROM `resettoken` WHERE `user` = UUID_TO_BIN(?, true)", user.UUID)
|
||||
_, err := db.Exec("INSERT INTO `resettoken` (`user`, `token`, `expiry`) "+
|
||||
"VALUES (UUID_TO_BIN(?, true),?, ?)", user.UUID, token, expiry)
|
||||
_, _ = db.Exec("DELETE FROM resettoken WHERE user = $1", user.UUID)
|
||||
_, err := db.Exec("INSERT INTO resettoken (user, token, expiry) "+
|
||||
"VALUES ($1,$2,$3)", user.UUID, token, expiry)
|
||||
|
||||
return err
|
||||
}
|
||||
|
||||
func clearOldResetTokens() {
|
||||
_, _ = db.Exec("DELETE FROM `resettoken` WHERE `expiry` < NOW()")
|
||||
_, _ = db.Exec("DELETE FROM resettoken WHERE expiry < NOW()")
|
||||
}
|
||||
|
||||
func clearResetToken(token string) error {
|
||||
_, err := db.Exec("DELETE FROM `resettoken` WHERE `token` = ?", token)
|
||||
_, err := db.Exec("DELETE FROM resettoken WHERE token = $1", token)
|
||||
|
||||
return err
|
||||
}
|
||||
|
||||
// checkResetToken - If a token exists check it
|
||||
func checkResetToken(token string) (bool, error) {
|
||||
count, err := getDbCount("SELECT COUNT(*) FROM `resettoken` WHERE `token` = ? ", token)
|
||||
count, err := getDbCount("SELECT COUNT(*) FROM resettoken WHERE token = $1", token)
|
||||
|
||||
if err != nil {
|
||||
return false, err
|
||||
@ -299,7 +303,7 @@ func (user *User) updatePassword(newPassword string, ip net.IP) error {
|
||||
return errors.New("Bad password")
|
||||
}
|
||||
|
||||
_, err = db.Exec("UPDATE `users` SET `password` = ? WHERE `uuid` = UUID_TO_BIN(?, true)", hash, user.UUID)
|
||||
_, err = db.Exec("UPDATE users SET password = $1 WHERE uuid = $2", hash, user.UUID)
|
||||
if err != nil {
|
||||
return errors.New("Failed to update password")
|
||||
}
|
||||
@ -317,8 +321,8 @@ func (user *User) getNavidromeTokens() (OauthToken, error) {
|
||||
|
||||
func getAllSpotifyUsers() ([]User, error) {
|
||||
users := make([]User, 0)
|
||||
rows, err := db.Query("SELECT BIN_TO_UUID(`users`.`uuid`, true), `created_at`, `created_ip`, `modified_at`, `modified_ip`, `users`.`username`, `email`, `password`, `verified`, `admin`, `mod`, `timezone` FROM `users` " +
|
||||
"JOIN `oauth_tokens` ON `oauth_tokens`.`user` = `users`.`uuid` AND `oauth_tokens`.`service` = 'spotify' WHERE `users`.`active` = 1")
|
||||
rows, err := db.Query("SELECT users.uuid, created_at, created_ip, modified_at, modified_ip, users.username, email, password, verified, admin, mod, timezone FROM users " +
|
||||
"JOIN oauth_tokens ON oauth_tokens.user = users.uuid AND oauth_tokens.service = 'spotify' WHERE users.active = true")
|
||||
|
||||
if err != nil {
|
||||
log.Printf("Failed to fetch spotify users: %+v", err)
|
||||
@ -349,8 +353,8 @@ func getAllSpotifyUsers() ([]User, error) {
|
||||
|
||||
func getAllNavidromeUsers() ([]User, error) {
|
||||
users := make([]User, 0)
|
||||
rows, err := db.Query("SELECT BIN_TO_UUID(`users`.`uuid`, true), `created_at`, `created_ip`, `modified_at`, `modified_ip`, `users`.`username`, `email`, `password`, `verified`, `admin`, `mod`, `timezone` FROM `users` " +
|
||||
"JOIN `oauth_tokens` ON `oauth_tokens`.`user` = `users`.`uuid` AND `oauth_tokens`.`service` = 'navidrome' WHERE `users`.`active` = 1")
|
||||
rows, err := db.Query("SELECT users.uuid, created_at, created_ip, modified_at, modified_ip, users.username, email, password, verified, admin, mod, timezone FROM users " +
|
||||
"JOIN oauth_tokens ON oauth_tokens.user = users.uuid AND oauth_tokens.service = 'navidrome' WHERE users.active = true")
|
||||
|
||||
if err != nil {
|
||||
log.Printf("Failed to fetch navidrome users: %+v", err)
|
||||
|
@ -87,7 +87,7 @@ func getUserIp(r *http.Request) net.IP {
|
||||
}
|
||||
|
||||
if host == "" {
|
||||
host = "0.0.0.0"
|
||||
host = "0.0.0.0/0"
|
||||
}
|
||||
|
||||
ip = net.ParseIP(host)
|
||||
@ -103,7 +103,7 @@ func Inet_Aton(ip net.IP) int64 {
|
||||
|
||||
// Inet6_Aton converts an IP Address (IPv4 or IPv6) net.IP object to a hexadecimal
|
||||
// representaiton. This function is the equivalent of
|
||||
// inet6_aton({{ ip address }}) in MySQL.
|
||||
// inet6_aton({{ ip address }}) in Postgres.
|
||||
func Inet6_Aton(ip net.IP) string {
|
||||
ipv4 := false
|
||||
if ip.To4() != nil {
|
||||
|
@ -1 +1 @@
|
||||
ALTER TABLE `tracks` DROP COLUMN `length`;
|
||||
ALTER TABLE tracks DROP COLUMN length;
|
@ -1 +1 @@
|
||||
ALTER TABLE `tracks` ADD COLUMN `length` INT NOT NULL DEFAULT 0;
|
||||
ALTER TABLE tracks ADD COLUMN length INT NOT NULL DEFAULT 0;
|
@ -1 +1 @@
|
||||
DROP TABLE IF EXISTS `genres`;
|
||||
DROP TABLE IF EXISTS genres;
|
@ -1,5 +1,6 @@
|
||||
CREATE TABLE IF NOT EXISTS `genres` (
|
||||
`uuid` BINARY(16) PRIMARY KEY,
|
||||
`name` VARCHAR(255) NOT NULL,
|
||||
KEY `nameLookup` (`name`)
|
||||
) DEFAULT CHARACTER SET = utf8mb4 COLLATE = utf8mb4_0900_ai_ci;
|
||||
CREATE TABLE IF NOT EXISTS genres (
|
||||
uuid uuid PRIMARY KEY,
|
||||
name VARCHAR(255) NOT NULL
|
||||
);
|
||||
|
||||
CREATE INDEX genresNameLookup ON genres (name)
|
@ -1 +1 @@
|
||||
DROP TABLE IF EXISTS `refresh_tokens`;
|
||||
DROP TABLE IF EXISTS refresh_tokens;
|
@ -1,10 +1,11 @@
|
||||
CREATE TABLE IF NOT EXISTS `refresh_tokens` (
|
||||
`uuid` BINARY(16) PRIMARY KEY,
|
||||
`user` BINARY(16),
|
||||
`token` VARCHAR(64) NOT NULL,
|
||||
`expiry` DATETIME NOT NULL DEFAULT NOW(),
|
||||
KEY `userLookup` (`user`),
|
||||
KEY `tokenLookup` (`token`),
|
||||
KEY `expiryLookup` (`expiry`),
|
||||
FOREIGN KEY (user) REFERENCES users(uuid)
|
||||
) DEFAULT CHARACTER SET = utf8mb4 COLLATE = utf8mb4_0900_ai_ci;
|
||||
CREATE TABLE IF NOT EXISTS refresh_tokens (
|
||||
uuid uuid PRIMARY KEY,
|
||||
"user" uuid,
|
||||
token VARCHAR(64) NOT NULL,
|
||||
expiry timestamptz NOT NULL DEFAULT NOW(),
|
||||
FOREIGN KEY ("user") REFERENCES users(uuid)
|
||||
);
|
||||
|
||||
CREATE INDEX refreshtokensUserLookup ON refresh_tokens ("user");
|
||||
CREATE INDEX refreshtokensTokenLookup ON refresh_tokens (token);
|
||||
CREATE INDEX refreshtokensExpiryLookup ON refresh_tokens (expiry);
|
||||
|
@ -1 +1 @@
|
||||
ALTER TABLE `users` DROP COLUMN `mod`;
|
||||
ALTER TABLE users DROP COLUMN mod;
|
@ -1 +1 @@
|
||||
ALTER TABLE `users` ADD COLUMN `mod` TINYINT(1) NOT NULL DEFAULT 0 AFTER `admin`;
|
||||
ALTER TABLE users ADD COLUMN mod BOOL NOT NULL DEFAULT FALSE;
|
@ -1 +1 @@
|
||||
DROP TABLE IF EXISTS `config`;
|
||||
DROP TABLE IF EXISTS config;
|
@ -1,5 +1,5 @@
|
||||
CREATE TABLE IF NOT EXISTS `config` (
|
||||
`key` VARCHAR(255) NOT NULL,
|
||||
`value` VARCHAR(255) NULL DEFAULT NULL,
|
||||
PRIMARY KEY(`key`)
|
||||
) DEFAULT CHARACTER SET = utf8mb4 COLLATE = utf8mb4_0900_ai_ci;
|
||||
CREATE TABLE IF NOT EXISTS config (
|
||||
key VARCHAR(255) NOT NULL,
|
||||
value VARCHAR(255) NULL,
|
||||
PRIMARY KEY(key)
|
||||
);
|
@ -1 +1 @@
|
||||
DROP TABLE IF EXISTS `users`;
|
||||
DROP TABLE IF EXISTS users;
|
@ -1,17 +1,18 @@
|
||||
CREATE TABLE IF NOT EXISTS `users` (
|
||||
`uuid` BINARY(16) PRIMARY KEY,
|
||||
`created_at` DATETIME NOT NULL DEFAULT NOW(),
|
||||
`created_ip` VARBINARY(16) NULL DEFAULT NULL,
|
||||
`modified_at` DATETIME NOT NULL DEFAULT NOW(),
|
||||
`modified_ip` VARBINARY(16) NULL DEFAULT NULL,
|
||||
`username` VARCHAR(64) NOT NULL,
|
||||
`password` VARCHAR(60) NOT NULL,
|
||||
`email` VARCHAR(255) NULL DEFAULT NULL,
|
||||
`verified` TINYINT(1) NOT NULL DEFAULT 0,
|
||||
`active` TINYINT(1) NOT NULL DEFAULT 1,
|
||||
`admin` TINYINT(1) NOT NULL DEFAULT 0,
|
||||
`private` TINYINT(1) NOT NULL DEFAULT 0,
|
||||
`timezone` VARCHAR(100) NOT NULL DEFAULT 'Pacific/Auckland',
|
||||
KEY `usernameLookup` (`username`, `active`),
|
||||
KEY `emailLookup` (`email`, `active`)
|
||||
) DEFAULT CHARACTER SET = utf8mb4 COLLATE = utf8mb4_0900_ai_ci;
|
||||
CREATE TABLE IF NOT EXISTS users (
|
||||
uuid uuid PRIMARY KEY,
|
||||
created_at timestamptz NOT NULL DEFAULT NOW(),
|
||||
created_ip INET NULL,
|
||||
modified_at timestamptz NOT NULL DEFAULT NOW(),
|
||||
modified_ip INET NULL,
|
||||
username VARCHAR(64) NOT NULL,
|
||||
password VARCHAR(60) NOT NULL,
|
||||
email VARCHAR(255) NULL,
|
||||
verified BOOL NOT NULL DEFAULT FALSE,
|
||||
active BOOL NOT NULL DEFAULT TRUE,
|
||||
admin BOOL NOT NULL DEFAULT FALSE,
|
||||
private BOOL NOT NULL DEFAULT FALSE,
|
||||
timezone VARCHAR(100) NOT NULL DEFAULT 'Pacific/Auckland'
|
||||
);
|
||||
|
||||
CREATE INDEX usersUsernameLookup ON users (username, active);
|
||||
CREATE INDEX usersEmailLookup ON users (email, active);
|
@ -1,8 +1,8 @@
|
||||
START TRANSACTION;
|
||||
DROP TABLE IF EXISTS `artists`;
|
||||
DROP TABLE IF EXISTS `albums`;
|
||||
DROP TABLE IF EXISTS `tracks`;
|
||||
DROP TABLE IF EXISTS `track_artist`;
|
||||
DROP TABLE IF EXISTS `scrobble_track`;
|
||||
DROP TABLE IF EXISTS artists;
|
||||
DROP TABLE IF EXISTS albums;
|
||||
DROP TABLE IF EXISTS tracks;
|
||||
DROP TABLE IF EXISTS track_artist;
|
||||
DROP TABLE IF EXISTS scrobble_track;
|
||||
|
||||
COMMIT;
|
@ -1,69 +1,71 @@
|
||||
START TRANSACTION;
|
||||
|
||||
CREATE TABLE IF NOT EXISTS `links` (
|
||||
`scrobble` BINARY(16) NOT NULL,
|
||||
`track` BINARY(16) NOT NULL,
|
||||
PRIMARY KEY (`scrobble`, `track`),
|
||||
KEY `trackLookup` (`track`)
|
||||
) DEFAULT CHARACTER SET = utf8mb4 COLLATE = utf8mb4_0900_ai_ci;
|
||||
CREATE TABLE IF NOT EXISTS links (
|
||||
scrobble uuid NOT NULL,
|
||||
track uuid NOT NULL,
|
||||
PRIMARY KEY (scrobble, track)
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS `artists` (
|
||||
`uuid` BINARY(16) PRIMARY KEY,
|
||||
`name` VARCHAR(255) NOT NULL,
|
||||
`desc` TEXT,
|
||||
`img` VARCHAR(255) DEFAULT NULL
|
||||
) DEFAULT CHARACTER SET = utf8mb4 COLLATE = utf8mb4_0900_ai_ci;
|
||||
CREATE INDEX trackLookup ON links (track);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS `albums` (
|
||||
`uuid` BINARY(16) PRIMARY KEY,
|
||||
`name` VARCHAR(255) NOT NULL,
|
||||
`desc` TEXT,
|
||||
`img` VARCHAR(255) DEFAULT NULL
|
||||
) DEFAULT CHARACTER SET = utf8mb4 COLLATE = utf8mb4_0900_ai_ci;
|
||||
CREATE TABLE IF NOT EXISTS artists (
|
||||
uuid uuid PRIMARY KEY,
|
||||
name VARCHAR(255) NOT NULL,
|
||||
"desc" TEXT,
|
||||
img VARCHAR(255)
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS `tracks` (
|
||||
`uuid` BINARY(16) PRIMARY KEY,
|
||||
`name` VARCHAR(255) NOT NULL,
|
||||
`desc` TEXT,
|
||||
`img` VARCHAR(255) DEFAULT NULL
|
||||
) DEFAULT CHARACTER SET = utf8mb4 COLLATE = utf8mb4_0900_ai_ci;
|
||||
CREATE TABLE IF NOT EXISTS albums (
|
||||
uuid uuid PRIMARY KEY,
|
||||
name VARCHAR(255) NOT NULL,
|
||||
"desc" TEXT,
|
||||
img VARCHAR(255)
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS `scrobbles` (
|
||||
`uuid` BINARY(16) PRIMARY KEY,
|
||||
`created_at` DATETIME NOT NULL,
|
||||
`created_ip` VARBINARY(16) NULL DEFAULT NULL,
|
||||
`user` BINARY(16) NOT NULL,
|
||||
`track` BINARY(16) NOT NULL,
|
||||
`source` VARCHAR(100) NOT NULL DEFAULT '',
|
||||
KEY `userLookup` (`user`),
|
||||
KEY `dateLookup` (`created_at`),
|
||||
KEY `sourceLookup` (`source`),
|
||||
CREATE TABLE IF NOT EXISTS tracks (
|
||||
uuid uuid PRIMARY KEY,
|
||||
name VARCHAR(255) NOT NULL,
|
||||
"desc" TEXT,
|
||||
img VARCHAR(255)
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS scrobbles (
|
||||
uuid uuid PRIMARY KEY,
|
||||
created_at timestamptz NOT NULL,
|
||||
created_ip INET NULL,
|
||||
"user" uuid NOT NULL,
|
||||
track uuid NOT NULL,
|
||||
source VARCHAR(100) NOT NULL DEFAULT '',
|
||||
FOREIGN KEY (track) REFERENCES tracks(uuid),
|
||||
FOREIGN KEY (user) REFERENCES users(uuid)
|
||||
) DEFAULT CHARACTER SET = utf8mb4 COLLATE = utf8mb4_0900_ai_ci;
|
||||
FOREIGN KEY ("user") REFERENCES users(uuid)
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS `album_artist` (
|
||||
`album` BINARY(16) NOT NULL,
|
||||
`artist` BINARY(16) NOT NULL,
|
||||
PRIMARY KEY (`album`, `artist`),
|
||||
CREATE INDEX scrobblesUserLookup ON scrobbles ("user");
|
||||
CREATE INDEX scrobblesDateLookup ON scrobbles (created_at);
|
||||
CREATE INDEX scrobblesSourceLookup ON scrobbles (source);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS album_artist (
|
||||
album uuid NOT NULL,
|
||||
artist uuid NOT NULL,
|
||||
PRIMARY KEY (album, artist),
|
||||
FOREIGN KEY (album) REFERENCES albums(uuid),
|
||||
FOREIGN KEY (artist) REFERENCES artists(uuid)
|
||||
) DEFAULT CHARACTER SET = utf8mb4 COLLATE = utf8mb4_0900_ai_ci;
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS `track_album` (
|
||||
`track` BINARY(16) NOT NULL,
|
||||
`album` BINARY(16) NOT NULL,
|
||||
PRIMARY KEY (`track`, `album`),
|
||||
CREATE TABLE IF NOT EXISTS track_album (
|
||||
track uuid NOT NULL,
|
||||
album uuid NOT NULL,
|
||||
PRIMARY KEY (track, album),
|
||||
FOREIGN KEY (track) REFERENCES tracks(uuid),
|
||||
FOREIGN KEY (album) REFERENCES albums(uuid)
|
||||
) DEFAULT CHARACTER SET = utf8mb4 COLLATE = utf8mb4_0900_ai_ci;
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS `track_artist` (
|
||||
`track` BINARY(16) NOT NULL,
|
||||
`artist` BINARY(16) NOT NULL,
|
||||
PRIMARY KEY (`track`, `artist`),
|
||||
CREATE TABLE IF NOT EXISTS track_artist (
|
||||
track uuid NOT NULL,
|
||||
artist uuid NOT NULL,
|
||||
PRIMARY KEY (track, artist),
|
||||
FOREIGN KEY (track) REFERENCES tracks(uuid),
|
||||
FOREIGN KEY (artist) REFERENCES artists(uuid)
|
||||
) DEFAULT CHARACTER SET = utf8mb4 COLLATE = utf8mb4_0900_ai_ci;
|
||||
);
|
||||
|
||||
COMMIT;
|
||||
|
@ -1,7 +1,7 @@
|
||||
START TRANSACTION;
|
||||
|
||||
ALTER TABLE albums DROP COLUMN `mbid`;
|
||||
ALTER TABLE artists DROP COLUMN `mbid`;
|
||||
ALTER TABLE tracks DROP COLUMN `mbid`;
|
||||
ALTER TABLE albums DROP COLUMN mbid;
|
||||
ALTER TABLE artists DROP COLUMN mbid;
|
||||
ALTER TABLE tracks DROP COLUMN mbid;
|
||||
|
||||
COMMIT;
|
||||
|
@ -1,7 +1,7 @@
|
||||
START TRANSACTION;
|
||||
|
||||
ALTER TABLE albums ADD COLUMN `mbid` VARCHAR(36) DEFAULT '';
|
||||
ALTER TABLE artists ADD COLUMN `mbid` VARCHAR(36) DEFAULT '';
|
||||
ALTER TABLE tracks ADD COLUMN `mbid` VARCHAR(36) DEFAULT '';
|
||||
ALTER TABLE albums ADD COLUMN mbid VARCHAR(36) DEFAULT '';
|
||||
ALTER TABLE artists ADD COLUMN mbid VARCHAR(36) DEFAULT '';
|
||||
ALTER TABLE tracks ADD COLUMN mbid VARCHAR(36) DEFAULT '';
|
||||
|
||||
COMMIT;
|
||||
|
@ -1 +1 @@
|
||||
ALTER TABLE `users` DROP COLUMN `token`;
|
||||
ALTER TABLE users DROP COLUMN token;
|
@ -1 +1 @@
|
||||
ALTER TABLE `users` ADD COLUMN `token` VARCHAR(32) NOT NULL;
|
||||
ALTER TABLE users ADD COLUMN token VARCHAR(32) NOT NULL;
|
@ -1 +1 @@
|
||||
TRUNCATE `config`;
|
||||
TRUNCATE config;
|
@ -1,5 +1,5 @@
|
||||
INSERT INTO
|
||||
`config`(`key`, `value`)
|
||||
config(key, value)
|
||||
VALUES
|
||||
('SPOTIFY_API_ID', ''),
|
||||
('SPOTIFY_API_SECRET', ''),
|
||||
|
@ -1 +1 @@
|
||||
DROP TABLE IF EXISTS `resettoken`;
|
||||
DROP TABLE IF EXISTS resettoken;
|
||||
|
@ -1,6 +1,7 @@
|
||||
CREATE TABLE IF NOT EXISTS `resettoken` (
|
||||
`user` BINARY(16) PRIMARY KEY,
|
||||
`token` VARCHAR(64) NOT NULL,
|
||||
`expiry` DATETIME NOT NULL,
|
||||
KEY `tokenLookup` (`token`)
|
||||
) DEFAULT CHARACTER SET = utf8mb4 COLLATE = utf8mb4_0900_ai_ci;
|
||||
CREATE TABLE IF NOT EXISTS resettoken (
|
||||
"user" uuid PRIMARY KEY,
|
||||
token VARCHAR(64) NOT NULL,
|
||||
expiry timestamptz NOT NULL
|
||||
);
|
||||
|
||||
CREATE INDEX resettokenTokenLookup ON resettoken (token)
|
||||
|
@ -1 +1 @@
|
||||
DROP TABLE IF EXISTS `oauth_tokens`;
|
||||
DROP TABLE IF EXISTS oauth_tokens;
|
@ -1,11 +1,11 @@
|
||||
CREATE TABLE IF NOT EXISTS `oauth_tokens` (
|
||||
`user` BINARY(16),
|
||||
`service` VARCHAR(64) NOT NULL,
|
||||
`access_token` VARCHAR(255) NULL DEFAULT '',
|
||||
`refresh_token` VARCHAR(255) NULL DEFAULT '',
|
||||
`url` VARCHAR(255) NULL DEFAULT '',
|
||||
`expiry` DATETIME NOT NULL,
|
||||
`username` VARCHAR(100) NULL DEFAULT '',
|
||||
`last_synced` DATETIME NOT NULL DEFAULT NOW(),
|
||||
PRIMARY KEY `userService` (`user`, `service`)
|
||||
) DEFAULT CHARACTER SET = utf8mb4 COLLATE = utf8mb4_0900_ai_ci;
|
||||
CREATE TABLE IF NOT EXISTS oauth_tokens (
|
||||
"user" uuid,
|
||||
service VARCHAR(64) NOT NULL,
|
||||
access_token VARCHAR(255) NULL DEFAULT '',
|
||||
refresh_token VARCHAR(255) NULL DEFAULT '',
|
||||
url VARCHAR(255) NULL DEFAULT '',
|
||||
expiry timestamptz NOT NULL,
|
||||
username VARCHAR(100) NULL DEFAULT '',
|
||||
last_synced timestamptz NOT NULL DEFAULT NOW(),
|
||||
PRIMARY KEY ("user", "service")
|
||||
);
|
||||
|
@ -1,8 +1,8 @@
|
||||
START TRANSACTION;
|
||||
|
||||
ALTER TABLE `tracks` DROP COLUMN `spotify_id`;
|
||||
ALTER TABLE `users` DROP COLUMN `spotify_id`;
|
||||
ALTER TABLE `albums` DROP COLUMN `spotify_id`;
|
||||
ALTER TABLE `artists` DROP COLUMN `spotify_id`;
|
||||
ALTER TABLE tracks DROP COLUMN spotify_id;
|
||||
ALTER TABLE users DROP COLUMN spotify_id;
|
||||
ALTER TABLE albums DROP COLUMN spotify_id;
|
||||
ALTER TABLE artists DROP COLUMN spotify_id;
|
||||
|
||||
COMMIT;
|
@ -1,13 +1,13 @@
|
||||
START TRANSACTION;
|
||||
|
||||
ALTER TABLE `users` ADD COLUMN `spotify_id` VARCHAR(255) NOT NULL DEFAULT '';
|
||||
ALTER TABLE `albums` ADD COLUMN `spotify_id` VARCHAR(255) NOT NULL DEFAULT '';
|
||||
ALTER TABLE `artists` ADD COLUMN `spotify_id` VARCHAR(255) NOT NULL DEFAULT '';
|
||||
ALTER TABLE `tracks` ADD COLUMN `spotify_id` VARCHAR(255) NOT NULL DEFAULT '';
|
||||
ALTER TABLE users ADD COLUMN spotify_id VARCHAR(255) NOT NULL DEFAULT '';
|
||||
ALTER TABLE albums ADD COLUMN spotify_id VARCHAR(255) NOT NULL DEFAULT '';
|
||||
ALTER TABLE artists ADD COLUMN spotify_id VARCHAR(255) NOT NULL DEFAULT '';
|
||||
ALTER TABLE tracks ADD COLUMN spotify_id VARCHAR(255) NOT NULL DEFAULT '';
|
||||
|
||||
ALTER TABLE `users` ADD INDEX `spotifyLookup` (`spotify_id`);
|
||||
ALTER TABLE `albums` ADD INDEX `spotifyLookup` (`spotify_id`);
|
||||
ALTER TABLE `artists` ADD INDEX `spotifyLookup` (`spotify_id`);
|
||||
ALTER TABLE `tracks` ADD INDEX `spotifyLookup` (`spotify_id`);
|
||||
CREATE INDEX usersSpotifyLookup ON users (spotify_id);
|
||||
CREATE INDEX albumsSpotifyLookup ON albums (spotify_id);
|
||||
CREATE INDEX artistsSpotifyLookup ON artists (spotify_id);
|
||||
CREATE INDEX tracksSpotifyLookup ON tracks (spotify_id);
|
||||
|
||||
COMMIT;
|
Loading…
Reference in New Issue
Block a user