mirror of
https://github.com/johrpan/musicus.git
synced 2025-10-26 11:47:25 +01:00
db: Add mediums and albums
This commit is contained in:
parent
3eed04d04b
commit
3ab0332475
4 changed files with 152 additions and 7 deletions
|
|
@ -97,7 +97,9 @@ CREATE TABLE recording_ensembles (
|
||||||
CREATE TABLE tracks_new (
|
CREATE TABLE tracks_new (
|
||||||
track_id TEXT NOT NULL PRIMARY KEY,
|
track_id TEXT NOT NULL PRIMARY KEY,
|
||||||
recording_id TEXT NOT NULL REFERENCES recordings(recording_id),
|
recording_id TEXT NOT NULL REFERENCES recordings(recording_id),
|
||||||
sequence_number INTEGER NOT NULL,
|
recording_index INTEGER NOT NULL,
|
||||||
|
medium_id TEXT REFERENCES mediums(medium_id),
|
||||||
|
medium_index INTEGER,
|
||||||
path TEXT NOT NULL,
|
path TEXT NOT NULL,
|
||||||
created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||||||
edited_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
edited_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||||||
|
|
@ -112,6 +114,38 @@ CREATE TABLE track_works (
|
||||||
PRIMARY KEY (track_id, work_id)
|
PRIMARY KEY (track_id, work_id)
|
||||||
);
|
);
|
||||||
|
|
||||||
|
CREATE TABLE mediums_new (
|
||||||
|
medium_id TEXT NOT NULL PRIMARY KEY,
|
||||||
|
discid TEXT NOT NULL,
|
||||||
|
created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||||||
|
edited_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||||||
|
last_used_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||||||
|
last_played_at TIMESTAMP
|
||||||
|
);
|
||||||
|
|
||||||
|
CREATE TABLE albums (
|
||||||
|
album_id TEXT NOT NULL PRIMARY KEY,
|
||||||
|
name TEXT NOT NULL,
|
||||||
|
created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||||||
|
edited_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||||||
|
last_used_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||||||
|
last_played_at TIMESTAMP
|
||||||
|
);
|
||||||
|
|
||||||
|
CREATE TABLE album_recordings (
|
||||||
|
album_id TEXT NOT NULL REFERENCES albums(album_id),
|
||||||
|
recording_id TEXT NOT NULL REFERENCES recordings(recording_id),
|
||||||
|
sequence_number INTEGER NOT NULL,
|
||||||
|
PRIMARY KEY (album_id, recording_id)
|
||||||
|
);
|
||||||
|
|
||||||
|
CREATE TABLE album_mediums (
|
||||||
|
album_id TEXT NOT NULL REFERENCES albums(album_id),
|
||||||
|
medium_id TEXT NOT NULL REFERENCES mediums(medium_id),
|
||||||
|
sequence_number INTEGER NOT NULL,
|
||||||
|
PRIMARY KEY (album_id, medium_id)
|
||||||
|
);
|
||||||
|
|
||||||
INSERT INTO persons_new (person_id, name)
|
INSERT INTO persons_new (person_id, name)
|
||||||
SELECT id, json_set('{}', '$.generic', first_name || ' ' || last_name)
|
SELECT id, json_set('{}', '$.generic', first_name || ' ' || last_name)
|
||||||
FROM persons;
|
FROM persons;
|
||||||
|
|
@ -164,8 +198,8 @@ SELECT recording, ensemble, '28ff0aeb11c041a6916d93e9b4884eef', 0
|
||||||
FROM performances
|
FROM performances
|
||||||
WHERE ensemble IS NOT NULL;
|
WHERE ensemble IS NOT NULL;
|
||||||
|
|
||||||
INSERT INTO tracks_new (track_id, recording_id, sequence_number, path)
|
INSERT INTO tracks_new (track_id, recording_id, recording_index, medium_id, medium_index, path)
|
||||||
SELECT id, recording, "index", path
|
SELECT id, recording, "index", medium, source_index, path
|
||||||
FROM tracks;
|
FROM tracks;
|
||||||
|
|
||||||
INSERT INTO track_works (track_id, work_id, sequence_number)
|
INSERT INTO track_works (track_id, work_id, sequence_number)
|
||||||
|
|
@ -175,6 +209,27 @@ FROM tracks
|
||||||
JOIN work_parts ON recordings.work = work_parts.work
|
JOIN work_parts ON recordings.work = work_parts.work
|
||||||
AND tracks.work_parts = work_parts.part_index;
|
AND tracks.work_parts = work_parts.part_index;
|
||||||
|
|
||||||
|
INSERT INTO mediums_new (medium_id, discid)
|
||||||
|
SELECT id, discid
|
||||||
|
FROM mediums;
|
||||||
|
|
||||||
|
INSERT INTO albums (album_id, name)
|
||||||
|
SELECT id, json_set('{}', '$.generic', name)
|
||||||
|
FROM mediums;
|
||||||
|
|
||||||
|
-- This works because mediums, that become albums in this migration, keep their ID.
|
||||||
|
INSERT INTO album_recordings (album_id, recording_id, sequence_number)
|
||||||
|
SELECT medium, recording, ROW_NUMBER() OVER (PARTITION BY medium ORDER BY min_source_index)
|
||||||
|
FROM (
|
||||||
|
SELECT medium, recording, MIN(source_index) AS min_source_index
|
||||||
|
FROM tracks GROUP BY medium, recording
|
||||||
|
);
|
||||||
|
|
||||||
|
-- See above
|
||||||
|
INSERT INTO album_mediums (album_id, medium_id, sequence_number)
|
||||||
|
SELECT id, id, 0
|
||||||
|
FROM mediums;
|
||||||
|
|
||||||
DROP TABLE persons;
|
DROP TABLE persons;
|
||||||
DROP TABLE instruments;
|
DROP TABLE instruments;
|
||||||
DROP TABLE works;
|
DROP TABLE works;
|
||||||
|
|
@ -191,4 +246,5 @@ ALTER TABLE instruments_new RENAME TO instruments;
|
||||||
ALTER TABLE works_new RENAME TO works;
|
ALTER TABLE works_new RENAME TO works;
|
||||||
ALTER TABLE recordings_new RENAME TO recordings;
|
ALTER TABLE recordings_new RENAME TO recordings;
|
||||||
ALTER TABLE tracks_new RENAME TO tracks;
|
ALTER TABLE tracks_new RENAME TO tracks;
|
||||||
ALTER TABLE ensembles_new RENAME TO ensembles;
|
ALTER TABLE ensembles_new RENAME TO ensembles;
|
||||||
|
ALTER TABLE mediums_new RENAME TO mediums;
|
||||||
|
|
@ -260,7 +260,7 @@ impl Recording {
|
||||||
.collect::<Result<Vec<Ensemble>>>()?;
|
.collect::<Result<Vec<Ensemble>>>()?;
|
||||||
|
|
||||||
let tracks: Vec<Track> = tracks::table
|
let tracks: Vec<Track> = tracks::table
|
||||||
.order(tracks::sequence_number)
|
.order(tracks::recording_index)
|
||||||
.filter(tracks::recording_id.eq(&data.recording_id))
|
.filter(tracks::recording_id.eq(&data.recording_id))
|
||||||
.select(tables::Track::as_select())
|
.select(tables::Track::as_select())
|
||||||
.load::<tables::Track>(connection)?
|
.load::<tables::Track>(connection)?
|
||||||
|
|
|
||||||
|
|
@ -1,5 +1,32 @@
|
||||||
// @generated automatically by Diesel CLI.
|
// @generated automatically by Diesel CLI.
|
||||||
|
|
||||||
|
diesel::table! {
|
||||||
|
album_mediums (album_id, medium_id) {
|
||||||
|
album_id -> Text,
|
||||||
|
medium_id -> Text,
|
||||||
|
sequence_number -> Integer,
|
||||||
|
}
|
||||||
|
}
|
||||||
|
|
||||||
|
diesel::table! {
|
||||||
|
album_recordings (album_id, recording_id) {
|
||||||
|
album_id -> Text,
|
||||||
|
recording_id -> Text,
|
||||||
|
sequence_number -> Integer,
|
||||||
|
}
|
||||||
|
}
|
||||||
|
|
||||||
|
diesel::table! {
|
||||||
|
albums (album_id) {
|
||||||
|
album_id -> Text,
|
||||||
|
name -> Text,
|
||||||
|
created_at -> Timestamp,
|
||||||
|
edited_at -> Timestamp,
|
||||||
|
last_used_at -> Timestamp,
|
||||||
|
last_played_at -> Nullable<Timestamp>,
|
||||||
|
}
|
||||||
|
}
|
||||||
|
|
||||||
diesel::table! {
|
diesel::table! {
|
||||||
ensemble_persons (ensemble_id, person_id, instrument_id) {
|
ensemble_persons (ensemble_id, person_id, instrument_id) {
|
||||||
ensemble_id -> Text,
|
ensemble_id -> Text,
|
||||||
|
|
@ -31,6 +58,17 @@ diesel::table! {
|
||||||
}
|
}
|
||||||
}
|
}
|
||||||
|
|
||||||
|
diesel::table! {
|
||||||
|
mediums (medium_id) {
|
||||||
|
medium_id -> Text,
|
||||||
|
discid -> Text,
|
||||||
|
created_at -> Timestamp,
|
||||||
|
edited_at -> Timestamp,
|
||||||
|
last_used_at -> Timestamp,
|
||||||
|
last_played_at -> Nullable<Timestamp>,
|
||||||
|
}
|
||||||
|
}
|
||||||
|
|
||||||
diesel::table! {
|
diesel::table! {
|
||||||
persons (person_id) {
|
persons (person_id) {
|
||||||
person_id -> Text,
|
person_id -> Text,
|
||||||
|
|
@ -95,7 +133,9 @@ diesel::table! {
|
||||||
tracks (track_id) {
|
tracks (track_id) {
|
||||||
track_id -> Text,
|
track_id -> Text,
|
||||||
recording_id -> Text,
|
recording_id -> Text,
|
||||||
sequence_number -> Integer,
|
recording_index -> Integer,
|
||||||
|
medium_id -> Nullable<Text>,
|
||||||
|
medium_index -> Nullable<Integer>,
|
||||||
path -> Text,
|
path -> Text,
|
||||||
created_at -> Timestamp,
|
created_at -> Timestamp,
|
||||||
edited_at -> Timestamp,
|
edited_at -> Timestamp,
|
||||||
|
|
@ -143,6 +183,10 @@ diesel::table! {
|
||||||
}
|
}
|
||||||
}
|
}
|
||||||
|
|
||||||
|
diesel::joinable!(album_mediums -> albums (album_id));
|
||||||
|
diesel::joinable!(album_mediums -> mediums (medium_id));
|
||||||
|
diesel::joinable!(album_recordings -> albums (album_id));
|
||||||
|
diesel::joinable!(album_recordings -> recordings (recording_id));
|
||||||
diesel::joinable!(ensemble_persons -> ensembles (ensemble_id));
|
diesel::joinable!(ensemble_persons -> ensembles (ensemble_id));
|
||||||
diesel::joinable!(ensemble_persons -> instruments (instrument_id));
|
diesel::joinable!(ensemble_persons -> instruments (instrument_id));
|
||||||
diesel::joinable!(ensemble_persons -> persons (person_id));
|
diesel::joinable!(ensemble_persons -> persons (person_id));
|
||||||
|
|
@ -156,6 +200,7 @@ diesel::joinable!(recording_persons -> roles (role_id));
|
||||||
diesel::joinable!(recordings -> works (work_id));
|
diesel::joinable!(recordings -> works (work_id));
|
||||||
diesel::joinable!(track_works -> tracks (track_id));
|
diesel::joinable!(track_works -> tracks (track_id));
|
||||||
diesel::joinable!(track_works -> works (work_id));
|
diesel::joinable!(track_works -> works (work_id));
|
||||||
|
diesel::joinable!(tracks -> mediums (medium_id));
|
||||||
diesel::joinable!(tracks -> recordings (recording_id));
|
diesel::joinable!(tracks -> recordings (recording_id));
|
||||||
diesel::joinable!(work_instruments -> instruments (instrument_id));
|
diesel::joinable!(work_instruments -> instruments (instrument_id));
|
||||||
diesel::joinable!(work_instruments -> works (work_id));
|
diesel::joinable!(work_instruments -> works (work_id));
|
||||||
|
|
@ -164,9 +209,13 @@ diesel::joinable!(work_persons -> roles (role_id));
|
||||||
diesel::joinable!(work_persons -> works (work_id));
|
diesel::joinable!(work_persons -> works (work_id));
|
||||||
|
|
||||||
diesel::allow_tables_to_appear_in_same_query!(
|
diesel::allow_tables_to_appear_in_same_query!(
|
||||||
|
album_mediums,
|
||||||
|
album_recordings,
|
||||||
|
albums,
|
||||||
ensemble_persons,
|
ensemble_persons,
|
||||||
ensembles,
|
ensembles,
|
||||||
instruments,
|
instruments,
|
||||||
|
mediums,
|
||||||
persons,
|
persons,
|
||||||
recording_ensembles,
|
recording_ensembles,
|
||||||
recording_persons,
|
recording_persons,
|
||||||
|
|
|
||||||
|
|
@ -129,7 +129,9 @@ pub struct RecordingEnsemble {
|
||||||
pub struct Track {
|
pub struct Track {
|
||||||
pub track_id: String,
|
pub track_id: String,
|
||||||
pub recording_id: String,
|
pub recording_id: String,
|
||||||
pub sequence_number: i32,
|
pub recording_index: i32,
|
||||||
|
pub medium_id: Option<String>,
|
||||||
|
pub medium_index: Option<i32>,
|
||||||
pub path: String,
|
pub path: String,
|
||||||
pub created_at: NaiveDateTime,
|
pub created_at: NaiveDateTime,
|
||||||
pub edited_at: NaiveDateTime,
|
pub edited_at: NaiveDateTime,
|
||||||
|
|
@ -144,3 +146,41 @@ pub struct TrackWork {
|
||||||
pub work_id: String,
|
pub work_id: String,
|
||||||
pub sequence_number: i32,
|
pub sequence_number: i32,
|
||||||
}
|
}
|
||||||
|
|
||||||
|
#[derive(Insertable, Queryable, Selectable, Clone, Debug)]
|
||||||
|
#[diesel(check_for_backend(Sqlite))]
|
||||||
|
pub struct Medium {
|
||||||
|
pub medium_id: String,
|
||||||
|
pub discid: String,
|
||||||
|
pub created_at: NaiveDateTime,
|
||||||
|
pub edited_at: NaiveDateTime,
|
||||||
|
pub last_used_at: NaiveDateTime,
|
||||||
|
pub last_played_at: Option<NaiveDateTime>,
|
||||||
|
}
|
||||||
|
|
||||||
|
#[derive(Insertable, Queryable, Selectable, Clone, Debug)]
|
||||||
|
#[diesel(check_for_backend(Sqlite))]
|
||||||
|
pub struct Album {
|
||||||
|
pub album_id: String,
|
||||||
|
pub name: TranslatedString,
|
||||||
|
pub created_at: NaiveDateTime,
|
||||||
|
pub edited_at: NaiveDateTime,
|
||||||
|
pub last_used_at: NaiveDateTime,
|
||||||
|
pub last_played_at: Option<NaiveDateTime>,
|
||||||
|
}
|
||||||
|
|
||||||
|
#[derive(Insertable, Queryable, Selectable, Clone, Debug)]
|
||||||
|
#[diesel(check_for_backend(Sqlite))]
|
||||||
|
pub struct AlbumRecording {
|
||||||
|
pub album_id: String,
|
||||||
|
pub recording_id: String,
|
||||||
|
pub sequence_number: i32,
|
||||||
|
}
|
||||||
|
|
||||||
|
#[derive(Insertable, Queryable, Selectable, Clone, Debug)]
|
||||||
|
#[diesel(check_for_backend(Sqlite))]
|
||||||
|
pub struct AlbumMedium {
|
||||||
|
pub album_id: String,
|
||||||
|
pub medium_id: String,
|
||||||
|
pub sequence_number: i32,
|
||||||
|
}
|
||||||
Loading…
Add table
Add a link
Reference in a new issue