From 816a8d88a7696b23d052e8e115ae9898ecc8d3b3 Mon Sep 17 00:00:00 2001 From: "Alexander \"Arav\" Andreev" Date: Thu, 9 May 2024 23:53:33 +0400 Subject: [PATCH] Introduce a statistics DB implemented in SQLite3. --- internal/statistics/db/sqlite/db.go | 191 ++++++++++++++++++ .../db/sqlite/queries/history_add.sql | 3 + .../db/sqlite/queries/last_n_songs.sql | 19 ++ .../db/sqlite/queries/most_popular_songs.sql | 10 + .../queries/most_simultaneous_listeners.sql | 8 + .../statistics/db/sqlite/queries/schema.sql | 15 ++ .../statistics/db/sqlite/queries/song_add.sql | 6 + internal/statistics/statistics.go | 13 ++ 8 files changed, 265 insertions(+) create mode 100644 internal/statistics/db/sqlite/db.go create mode 100644 internal/statistics/db/sqlite/queries/history_add.sql create mode 100644 internal/statistics/db/sqlite/queries/last_n_songs.sql create mode 100644 internal/statistics/db/sqlite/queries/most_popular_songs.sql create mode 100644 internal/statistics/db/sqlite/queries/most_simultaneous_listeners.sql create mode 100644 internal/statistics/db/sqlite/queries/schema.sql create mode 100644 internal/statistics/db/sqlite/queries/song_add.sql create mode 100644 internal/statistics/statistics.go diff --git a/internal/statistics/db/sqlite/db.go b/internal/statistics/db/sqlite/db.go new file mode 100644 index 0000000..495bab7 --- /dev/null +++ b/internal/statistics/db/sqlite/db.go @@ -0,0 +1,191 @@ +package sqlite + +import ( + "database/sql" + "dwelling-radio/internal/radio" + "dwelling-radio/internal/statistics" + _ "embed" + "fmt" + "time" + + _ "github.com/mattn/go-sqlite3" + "github.com/pkg/errors" +) + +const dbDateFormat = "2006-01-02 15:04:05.999" + +var ( + //go:embed queries/schema.sql + querySchema string + + //go:embed queries/song_add.sql + querySongAdd string + + //go:embed queries/history_add.sql + queryHistoryAdd string + + //go:embed queries/last_n_songs.sql + queryLastNSongs string + //go:embed queries/most_popular_songs.sql + queryMostPopularSongs string + //go:embed queries/most_simultaneous_listeners.sql + queryMostSimultaneousListeners string +) + +var ( + stmtSongAdd *sql.Stmt + stmtHistoryAdd *sql.Stmt + stmtLastNSongs *sql.Stmt + stmtMostPopularSongs *sql.Stmt + stmtMostSimultaneousListeners *sql.Stmt +) + +type SQLiteStatistics struct { + db *sql.DB +} + +func initDBStatements(db *sql.DB) error { + db.Exec("PRAGMA foreign_keys = ON;") + + _, err := db.Exec(querySchema) + if err != nil { + return errors.Wrap(err, "failed to init schema") + } + + stmtSongAdd, err = db.Prepare(querySongAdd) + if err != nil { + return errors.Wrap(err, "failed to prepare querySongAdd") + } + + stmtHistoryAdd, err = db.Prepare(queryHistoryAdd) + if err != nil { + return errors.Wrap(err, "failed to prepare queryHistoryAdd") + } + + stmtLastNSongs, err = db.Prepare(queryLastNSongs) + if err != nil { + return errors.Wrap(err, "failed to prepare queryLastNSongs") + } + + stmtMostPopularSongs, err = db.Prepare(queryMostPopularSongs) + if err != nil { + return errors.Wrap(err, "failed to prepare queryMostPopularSongs") + } + + stmtMostSimultaneousListeners, err = db.Prepare(queryMostSimultaneousListeners) + if err != nil { + return errors.Wrap(err, "failed to prepare queryMostSimultaneousListeners") + } + + return nil +} + +func New(path string) (statistics.Statistics, error) { + db, err := sql.Open("sqlite3", fmt.Sprintf("file:%s?_journal=WAL&_mutex=full", path)) + if err != nil { + return nil, err + } + + if err := initDBStatements(db); err != nil { + return nil, err + } + + return &SQLiteStatistics{db: db}, nil +} + +func (s *SQLiteStatistics) Add(song *radio.Song) error { + if song == nil || song.Artist == "" || song.Title == "" { + return errors.New("No song or an empty one was passed.") + } + + tx, err := s.db.Begin() + if err != nil { + return err + } + defer tx.Rollback() + + row := tx.Stmt(stmtSongAdd).QueryRow(song.Artist, song.Title) + if row.Err() != nil { + return row.Err() + } + + var songID int64 + if err := row.Scan(&songID); err != nil { + return err + } + + res, err := tx.Stmt(stmtHistoryAdd).Exec(song.StartAt.UTC().Format(dbDateFormat), + songID, song.Listeners, song.MaxListeners) + if err != nil { + return err + } else if ra, err := res.RowsAffected(); ra == 0 || err != nil { + return errors.New("a song wasn't added to history, but there were no errors") + } + + tx.Commit() + + return nil +} + +func (s *SQLiteStatistics) LastNSongs(n int64) ([]radio.Song, error) { + if n == 0 { + return nil, nil + } + + tx, err := s.db.Begin() + if err != nil { + return nil, err + } + defer tx.Rollback() + + rows, err := tx.Stmt(stmtLastNSongs).Query(n) + if err != nil { + return nil, err + } + + songs := make([]radio.Song, n) + + i := 0 + for rows.Next() { + var startAt string + + if err := rows.Scan(&startAt, &songs[i].Artist, &songs[i].Title, + &songs[i].Listeners, &songs[i].MaxListeners); err != nil { + return nil, err + } + + songs[i].StartAt, err = time.Parse(dbDateFormat, startAt) + if err != nil { + return nil, err + } + + i++ + } + + tx.Commit() + + if i == 0 { + return nil, nil + } + + lst := make([]radio.Song, i) + copy(lst, songs[:]) + + return lst, nil +} + +func (s *SQLiteStatistics) MostNPopularSongs(n int64) ([]radio.Song, error) { + if n == 0 { + return nil, nil + } + + return nil, nil +} + +func (s *SQLiteStatistics) MostSimultaneousListeners() (radio.Song, error) { + return radio.Song{}, nil +} + +func (s *SQLiteStatistics) Close() error { + return s.db.Close() +} diff --git a/internal/statistics/db/sqlite/queries/history_add.sql b/internal/statistics/db/sqlite/queries/history_add.sql new file mode 100644 index 0000000..b422896 --- /dev/null +++ b/internal/statistics/db/sqlite/queries/history_add.sql @@ -0,0 +1,3 @@ +INSERT OR IGNORE INTO `history` + (`start_at`, `song_id`, `listeners`, `max_listeners`) +VALUES (?,?,?,?); \ No newline at end of file diff --git a/internal/statistics/db/sqlite/queries/last_n_songs.sql b/internal/statistics/db/sqlite/queries/last_n_songs.sql new file mode 100644 index 0000000..4969d7c --- /dev/null +++ b/internal/statistics/db/sqlite/queries/last_n_songs.sql @@ -0,0 +1,19 @@ +SELECT + `start_at`, + `artist`, + `title`, + `listeners`, + `max_listeners` +FROM + (SELECT + `start_at`, + `artist`, + `title`, + `listeners`, + `max_listeners` + FROM `history` + LEFT JOIN `song` + ON `song`.`song_id` = `history`.`song_id` + ORDER BY `start_at` DESC + LIMIT ? ) +ORDER BY `start_at` ASC; \ No newline at end of file diff --git a/internal/statistics/db/sqlite/queries/most_popular_songs.sql b/internal/statistics/db/sqlite/queries/most_popular_songs.sql new file mode 100644 index 0000000..d8ea2cc --- /dev/null +++ b/internal/statistics/db/sqlite/queries/most_popular_songs.sql @@ -0,0 +1,10 @@ +SELECT + `artist`, + `title`, + SUM(`listeners`) AS `most_listeners` +FROM `history` +LEFT JOIN `song` + ON `song`.`song_id` = `history`.`song_id` +GROUP BY `song`.`song_id` +ORDER BY `most_listeners` DESC +LIMIT ?; \ No newline at end of file diff --git a/internal/statistics/db/sqlite/queries/most_simultaneous_listeners.sql b/internal/statistics/db/sqlite/queries/most_simultaneous_listeners.sql new file mode 100644 index 0000000..2c7eeca --- /dev/null +++ b/internal/statistics/db/sqlite/queries/most_simultaneous_listeners.sql @@ -0,0 +1,8 @@ +SELECT + MAX(`start_at`) AS `start_at`, + `artist`, + `title`, + MAX(`max_listeners`) AS `max_listeners` +FROM `history` +LEFT JOIN `song` + ON `song`.`song_id` = `history`.`song_id`; \ No newline at end of file diff --git a/internal/statistics/db/sqlite/queries/schema.sql b/internal/statistics/db/sqlite/queries/schema.sql new file mode 100644 index 0000000..a3538c9 --- /dev/null +++ b/internal/statistics/db/sqlite/queries/schema.sql @@ -0,0 +1,15 @@ +CREATE TABLE IF NOT EXISTS `song` ( + `song_id` INTEGER NOT NULL, + `artist` TEXT NOT NULL, + `title` TEXT NOT NULL, + PRIMARY KEY (`song_id` AUTOINCREMENT), + UNIQUE (`artist`, `title`) ); + +CREATE TABLE IF NOT EXISTS `history` ( + `start_at` TEXT NOT NULL DEFAULT (strftime('%Y-%m-%d %H:%M:%f', 'now')), + `song_id` INTEGER NOT NULL, + `listeners` INTEGER NOT NULL, + `max_listeners` INTEGER NOT NULL, + PRIMARY KEY (`start_at`), + FOREIGN KEY (`song_id`) REFERENCES `song` (`song_id`) + ON UPDATE CASCADE ON DELETE CASCADE ); diff --git a/internal/statistics/db/sqlite/queries/song_add.sql b/internal/statistics/db/sqlite/queries/song_add.sql new file mode 100644 index 0000000..977898e --- /dev/null +++ b/internal/statistics/db/sqlite/queries/song_add.sql @@ -0,0 +1,6 @@ +INSERT INTO `song` + (`artist`, `title`) +VALUES (?, ?) + ON CONFLICT DO + UPDATE SET `song_id`=`song_id` +RETURNING `song_id`; \ No newline at end of file diff --git a/internal/statistics/statistics.go b/internal/statistics/statistics.go new file mode 100644 index 0000000..3b6dda5 --- /dev/null +++ b/internal/statistics/statistics.go @@ -0,0 +1,13 @@ +package statistics + +import "dwelling-radio/internal/radio" + +const MostListenedDateFormat string = "02 January 2006 at 15:04:05 MST" + +type Statistics interface { + Add(*radio.Song) error + LastNSongs(n int64) ([]radio.Song, error) + MostNPopularSongs(n int64) ([]radio.Song, error) + MostSimultaneousListeners() (radio.Song, error) + Close() error +}