Permalink
Browse files

Add actual migrations

This is the datamodel we're gonna use throughout the demo. It only consists of 4 tables:

tracks having an artist and a genre, and plays storing when tracks have been played.
  • Loading branch information...
michael-simons committed Jul 23, 2016
1 parent 8a4fa68 commit 247640a3a5e5e36ffa80354f6248bc87e8232be9
@@ -1,2 +0,0 @@
*
!.gitignore
@@ -0,0 +1,6 @@
CREATE TABLE artists (
id INTEGER NOT NULL,
artist varchar2(255) NOT NULL,
CONSTRAINT artists_pk PRIMARY KEY (id),
CONSTRAINT artists_uk UNIQUE (artist)
);
@@ -0,0 +1,6 @@
CREATE TABLE genres (
id INTEGER NOT NULL,
genre varchar2(255) NOT NULL,
CONSTRAINT genres_pk PRIMARY KEY (id),
CONSTRAINT genres_uk UNIQUE (genre)
);
@@ -0,0 +1,17 @@
CREATE TABLE tracks (
id INTEGER NOT NULL,
artist_id INTEGER NOT NULL,
genre_id INTEGER NOT NULL,
album VARCHAR2(255) NOT NULL,
name VARCHAR2(4000) NOT NULL,
year NUMBER(4) NULL,
compilation VARCHAR2(1) DEFAULT 'f' NOT NULL CHECK(compilation IN ('t','f')) ,
disc_count NUMBER(2) NULL,
disc_number NUMBER(2) NULL,
track_count NUMBER(2) NULL,
track_number NUMBER(2) NULL,
CONSTRAINT tracks_pk PRIMARY KEY (id),
CONSTRAINT tracks_uk UNIQUE (artist_id, genre_id, album, name, track_number, disc_number),
CONSTRAINT tracks_artists_fk FOREIGN KEY (artist_id) REFERENCES artists(id),
CONSTRAINT tracks_genres_fk FOREIGN KEY (genre_id) REFERENCES genres(id)
);
@@ -0,0 +1,11 @@
CREATE TABLE plays (
id INTEGER NOT NULL,
track_id INTEGER NOT NULL,
played_on TIMESTAMP NOT NULL,
CONSTRAINT plays_pk PRIMARY KEY (id),
CONSTRAINT plays_tracks_fk FOREIGN KEY (track_id) REFERENCES tracks(id)
);
CREATE INDEX plays_played_on ON plays (played_on);
CREATE INDEX plays_played_on_date ON plays (trunc(played_on, 'DD'));

0 comments on commit 247640a

Please sign in to comment.