-- Initial SQLITE schema for Aural Isle --This file represents the initial schema for the various data structures to be stored in the database. -- The Persons table will contain data about Person entities (see MODELS.md) CREATE TABLE IF NOT EXISTS Persons ( id TEXT(36), /* UUIDv4 */ remote_id TEXT, /* field to store an arbitrary remote identifier for this Person if they are not local */ name TEXT, /* "real" name */ handle TEXT, /* also commonly refered to as 'display_name' or 'screen_name', optional (if missing, name will be used as handle) */ avatar TEXT, /* optional URL to Person's avatar image / profile pic */ cover TEXT, /* optional URL to Person's cover image / header image */ bio TEXT, /* optional biographical text provided by Person */ is_active INTEGER DEFAULT (1), /* bool, default true */ is_blocked INTEGER DEFAULT (0), /* bool, default false */ created_at INTEGER, /* timestamp */ modified_at INTEGER, /* timestamp */ modified_by TEXT(36), /* UUIDv4 */ deleted_at INTEGER, /* timestamp */ deleted_by TEXT(36), /* UUIDv4 */ last_seen INTEGER, /* timestamp */ /*shipping_address TEXT,*/ /* optional, should use \n between lines to keep localized format as needed - UPDATE: moving to lookup table */ CONSTRAINT Persons_PK PRIMARY KEY (id), CONSTRAINT Persons_FK FOREIGN KEY (modified_by) REFERENCES Persons(id), CONSTRAINT Persons_FK_1 FOREIGN KEY (deleted_by) REFERENCES Persons(id) ); CREATE UNIQUE INDEX IF NOT EXISTS Persons_remote_id_IDX ON Persons (remote_id); CREATE INDEX IF NOT EXISTS Persons_name_IDX ON Persons (name); CREATE INDEX IF NOT EXISTS Persons_handle_IDX ON Persons (handle); CREATE INDEX IF NOT EXISTS Persons_is_active_IDX ON Persons (is_active); CREATE INDEX IF NOT EXISTS Persons_is_blocked_IDX ON Persons (is_blocked); CREATE INDEX IF NOT EXISTS Persons_deleted_at_IDX ON Persons (deleted_at); -- The PersonShippingAddresses table is a one-to-many lookup table relating a Person to zero or more shipping addresses CREATE TABLE IF NOT EXISTS PersonShippingAddresses ( id TEXT(36), /* UUIDv4 */ person_id TEXT(36), /* UUIDv4 */ shipping_address TEXT, /* mandatory, should use \n between lines to keep localized format as needed */ is_primary INTEGER DEFAULT (0), /* bool, default false */ created_at INTEGER, /* timestamp */ modified_at INTEGER, /* timestamp */ modified_by TEXT(36), /* UUIDv4 */ deleted_at INTEGER, /* timestamp */ deleted_by TEXT(36), /* UUIDv4 */ CONSTRAINT PersonShippingAddresses_PK PRIMARY KEY (id), CONSTRAINT PersonShippingAddresses_FK FOREIGN KEY (person_id) REFERENCES Persons(id), CONSTRAINT PersonShippingAddresses_FK_1 FOREIGN KEY (modified_by) REFERENCES Persons(id), CONSTRAINT PersonShippingAddresses_FK_2 FOREIGN KEY (deleted_by) REFERENCES Persons(id) ); CREATE UNIQUE INDEX IF NOT EXISTS PersonShippingAddresses_is_primary_IDX ON PersonShippingAddresses (is_primary); -- The PersonEmails table is a one-to-many lookup table relating a Person to zero or more email addresses CREATE TABLE IF NOT EXISTS PersonEmails ( person_id TEXT(36), email TEXT, is_verified INTEGER DEFAULT (0), is_primary INTEGER DEFAULT (0), CONSTRAINT PersonEmails_PK PRIMARY KEY (email), CONSTRAINT PersonEmails_FK FOREIGN KEY (person_id) REFERENCES Persons(id) ON DELETE CASCADE ); CREATE INDEX IF NOT EXISTS PersonEmails_person_id_IDX ON PersonEmails (person_id); CREATE INDEX IF NOT EXISTS PersonEmails_is_verified_IDX ON PersonEmails (is_verified); CREATE INDEX IF NOT EXISTS PersonEmails_is_primary_IDX ON PersonEmails (is_primary); -- The PersonCredentialProvider table will contain configuration for different authentication providers. CREATE TABLE IF NOT EXISTS PersonCredentialProvider ( id TEXT(36), name TEXT, "type" TEXT, config TEXT, CONSTRAINT PersonCredentialProvider_PK PRIMARY KEY (id) ); CREATE INDEX IF NOT EXISTS PersonCredentialProvider_name_IDX ON PersonCredentialProvider (name); CREATE INDEX IF NOT EXISTS PersonCredentialProvider_type_IDX ON PersonCredentialProvider ("type"); -- The PersonCredential table will contain authentication credentials for Persons CREATE TABLE IF NOT EXISTS PersonCredential ( id TEXT(36), person_id TEXT(36), provider_id TEXT(36), provider_user_id TEXT(36), is_enabled INTEGER DEFAULT (1), CONSTRAINT PersonCredential_PK PRIMARY KEY (id), CONSTRAINT PersonCredential_FK FOREIGN KEY (person_id) REFERENCES Persons(id) ON DELETE CASCADE, CONSTRAINT PersonCredential_FK_1 FOREIGN KEY (provider_id) REFERENCES PersonCredentialProvider(id) ON DELETE CASCADE ); CREATE INDEX IF NOT EXISTS PersonCredential_person_id_IDX ON PersonCredential (person_id); CREATE INDEX IF NOT EXISTS PersonCredential_provider_id_IDX ON PersonCredential (provider_id); CREATE INDEX IF NOT EXISTS PersonCredential_is_enabled_IDX ON PersonCredential (is_enabled); -- The PersonLocal table will contain hashed and salted passwords for users authenticating via PersonCredentialProvider.Local type provider CREATE TABLE IF NOT EXISTS PersonLocal ( person_id TEXT(36), hash TEXT, modified_at INTEGER, modified_by TEXT(36), CONSTRAINT PersonLocal_PK PRIMARY KEY (person_id), CONSTRAINT PersonLocal_FK FOREIGN KEY (person_id) REFERENCES Persons(id) ON DELETE CASCADE ); -- The Tags table will contain tags for categorization of other entities. Tags use the originating host and the tag name as a composite key to allow for us to search for commonalities across instances (for example, "show me Albums matching *::tag::jazz" to see all the jazz albums this instance is aware of, "show me Albums matching sundog-isle.reclaim.technology::tag::jazz" to see only albums tagged as jazz on that one specific instance named in the host field). CREATE TABLE IF NOT EXISTS Tags ( id TEXT(36), host TEXT, tag TEXT, CONSTRAINT Tags_PK PRIMARY KEY (id) ); CREATE UNIQUE INDEX IF NOT EXISTS Tags_host_IDX ON Tags (host,tag); -- The Labels table will contain data about record labels/imprints that manage one or more Artists and their content. CREATE TABLE IF NOT EXISTS Labels ( id TEXT(36), name TEXT, description TEXT, website TEXT, is_enabled INTEGER DEFAULT (1), created_by TEXT(36), created_at INTEGER, modified_by TEXT(36), modified_at INTEGER, deleted_by TEXT(36), deleted_at INTEGER, CONSTRAINT Labels_PK PRIMARY KEY (id), CONSTRAINT Labels_FK FOREIGN KEY (created_by) REFERENCES Persons(id), CONSTRAINT Labels_FK_1 FOREIGN KEY (modified_at) REFERENCES Persons(id), CONSTRAINT Labels_FK_2 FOREIGN KEY (deleted_by) REFERENCES Persons(id) ); CREATE INDEX IF NOT EXISTS Labels_name_IDX ON Labels (name); CREATE INDEX IF NOT EXISTS Labels_description_IDX ON Labels (description); CREATE INDEX IF NOT EXISTS Labels_is_enabled_IDX ON Labels (is_enabled); CREATE INDEX IF NOT EXISTS Labels_created_by_IDX ON Labels (created_by); CREATE INDEX IF NOT EXISTS Labels_deleted_at_IDX ON Labels (deleted_at); -- The LabelContacts table will contain key-value pairs of methods to contact representatives of the Label (for example, "fediverse: sundog@toot-lab.reclaim.technology" or "email: sundog@reclaim.technology"). CREATE TABLE IF NOT EXISTS LabelContacts ( id TEXT(36), label_id TEXT(36), "method" TEXT, address TEXT, created_by TEXT(36), created_at INTEGER, modified_by TEXT(36), modified_at INTEGER, deleted_by TEXT(36), deleted_at INTEGER, sort_order INTEGER, CONSTRAINT LabelContacts_PK PRIMARY KEY (id), CONSTRAINT LabelContacts_FK FOREIGN KEY (created_by) REFERENCES Persons(id), CONSTRAINT LabelContacts_FK_1 FOREIGN KEY (modified_by) REFERENCES Persons(id), CONSTRAINT LabelContacts_FK_2 FOREIGN KEY (deleted_by) REFERENCES Persons(id), CONSTRAINT LabelContacts_FK_3 FOREIGN KEY (label_id) REFERENCES Labels(id) ON DELETE CASCADE ); CREATE INDEX IF NOT EXISTS LabelContacts_sort_order_IDX ON LabelContacts (sort_order); -- The LabelTags table will contain Tags that have been assigned to a Label. CREATE TABLE IF NOT EXISTS LabelTags ( label_id TEXT(36), tag_id TEXT(36), is_approved INTEGER DEFAULT (0), CONSTRAINT LabelTags_PK PRIMARY KEY (label_id,tag_id), CONSTRAINT LabelTags_FK FOREIGN KEY (label_id) REFERENCES Labels(id) ON DELETE CASCADE, CONSTRAINT LabelTags_FK_1 FOREIGN KEY (tag_id) REFERENCES Tags(id) ON DELETE CASCADE ); CREATE INDEX IF NOT EXISTS LabelTags_is_approved_IDX ON LabelTags (is_approved); CREATE INDEX IF NOT EXISTS LabelTags_tag_id_IDX ON LabelTags (tag_id); CREATE INDEX IF NOT EXISTS LabelTags_label_id_IDX ON LabelTags (label_id); -- The Artists table will contain Artists! CREATE TABLE IF NOT EXISTS Artists ( id TEXT(36), label_id TEXT(36), name TEXT, bio TEXT, website TEXT, created_by TEXT(36), created_at INTEGER, modified_by TEXT(36), modified_at INTEGER, deleted_by TEXT(36), deleted_at INTEGER, is_enabled INTEGER DEFAULT (1), is_public INTEGER DEFAULT (1), CONSTRAINT Artists_PK PRIMARY KEY (id), CONSTRAINT Artists_FK FOREIGN KEY (created_by) REFERENCES Persons(id), CONSTRAINT Artists_FK_1 FOREIGN KEY (modified_by) REFERENCES Persons(id), CONSTRAINT Artists_FK_2 FOREIGN KEY (deleted_by) REFERENCES Persons(id) ); CREATE INDEX IF NOT EXISTS Artists_name_IDX ON Artists (name); CREATE INDEX IF NOT EXISTS Artists_is_enabled_IDX ON Artists (is_enabled); CREATE INDEX IF NOT EXISTS Artists_is_public_IDX ON Artists (is_public); -- The ArtistContacts tablekey-value pairs of methods to contact representatives of the Artist (for example, "fediverse: sundog@toot-lab.reclaim.technology" or "email: sundog@reclaim.technology"). CREATE TABLE IF NOT EXISTS ArtistContacts ( id TEXT(36), artist_id TEXT(36), "method" TEXT, address TEXT, created_by TEXT(36), created_at INTEGER, modified_by TEXT(36), modified_at INTEGER, deleted_by TEXT(36), deleted_at INTEGER, sort_order INTEGER, CONSTRAINT ArtistContacts_PK PRIMARY KEY (id), CONSTRAINT ArtistContacts_FK FOREIGN KEY (artist_id) REFERENCES Artists(id) ON DELETE CASCADE CONSTRAINT ArtistContacts_FK_1 FOREIGN KEY (created_by) REFERENCES Persons(id), CONSTRAINT ArtistContacts_FK_2 FOREIGN KEY (modified_by) REFERENCES Persons(id), CONSTRAINT ArtistContacts_FK_3 FOREIGN KEY (deleted_by) REFERENCES Persons(id) ); CREATE INDEX IF NOT EXISTS ArtistContacts_artist_id_IDX ON ArtistContacts (artist_id); CREATE INDEX IF NOT EXISTS ArtistContacts_deleted_at_IDX ON ArtistContacts (deleted_at); CREATE INDEX IF NOT EXISTS ArtistContacts_sort_order_IDX ON ArtistContacts (sort_order); -- The ArtistTags table will contain Tags that have been assigned to an Artist. CREATE TABLE IF NOT EXISTS ArtistTags ( artist_id TEXT(36), tag_id TEXT(36), is_approved INTEGER DEFAULT (0), CONSTRAINT ArtistTags_PK PRIMARY KEY (artist_id,tag_id), CONSTRAINT ArtistTags_FK FOREIGN KEY (artist_id) REFERENCES Artists(id) ON DELETE CASCADE, CONSTRAINT ArtistTags_FK_1 FOREIGN KEY (tag_id) REFERENCES Tags(id) ON DELETE CASCADE ); CREATE INDEX IF NOT EXISTS ArtistTags_is_approved_IDX ON ArtistTags (is_approved); CREATE INDEX IF NOT EXISTS ArtistTags_artist_id_IDX ON ArtistTags (artist_id); CREATE INDEX IF NOT EXISTS ArtistTags_tag_id_IDX ON ArtistTags (tag_id); -- The Tracks table will contain Tracks! CREATE TABLE IF NOT EXISTS Tracks ( id TEXT(36), title TEXT, description TEXT, duration REAL, is_public INTEGER, is_available INTEGER DEFAULT (1), preview_source TEXT, "source" TEXT, price INTEGER DEFAULT (0), created_by TEXT(36), created_at INTEGER, modified_by TEXT(36), modified_at INTEGER, deleted_by TEXT(36), deleted_at INTEGER, lyrics TEXT, CONSTRAINT Tracks_PK PRIMARY KEY (id), CONSTRAINT Tracks_FK FOREIGN KEY (created_by) REFERENCES Persons(id), CONSTRAINT Tracks_FK_1 FOREIGN KEY (modified_by) REFERENCES Persons(id), CONSTRAINT Tracks_FK_2 FOREIGN KEY (deleted_by) REFERENCES Persons(id) ); CREATE INDEX IF NOT EXISTS Tracks_title_IDX ON Tracks (title); CREATE INDEX IF NOT EXISTS Tracks_duration_IDX ON Tracks (duration); CREATE INDEX IF NOT EXISTS Tracks_is_public_IDX ON Tracks (is_public); CREATE INDEX IF NOT EXISTS Tracks_is_available_IDX ON Tracks (is_available); CREATE INDEX IF NOT EXISTS Tracks_price_IDX ON Tracks (price); CREATE INDEX IF NOT EXISTS Tracks_created_by_IDX ON Tracks (created_by); CREATE INDEX IF NOT EXISTS Tracks_deleted_at_IDX ON Tracks (deleted_at); CREATE INDEX IF NOT EXISTS Tracks_lyrics_IDX ON Tracks (lyrics); -- The TrackArtists table will be a one-to-many lookup table mapping Artists to a particular Track. CREATE TABLE IF NOT EXISTS TrackArtists ( track_id TEXT(36), artist_id TEXT(36), is_primary INTEGER DEFAULT (0), CONSTRAINT TrackArtists_PK PRIMARY KEY (track_id,artist_id), CONSTRAINT TrackArtists_FK FOREIGN KEY (track_id) REFERENCES Tracks(id) ON DELETE CASCADE, CONSTRAINT TrackArtists_FK_1 FOREIGN KEY (artist_id) REFERENCES Artists(id) ON DELETE CASCADE ); CREATE INDEX IF NOT EXISTS TrackArtists_is_primary_IDX ON TrackArtists (is_primary); CREATE INDEX IF NOT EXISTS TrackArtists_track_id_IDX ON TrackArtists (track_id); CREATE INDEX IF NOT EXISTS TrackArtists_artist_id_IDX ON TrackArtists (artist_id); -- The TrackTags table will contain Tags that have been assigned to a Track. CREATE TABLE IF NOT EXISTS TrackTags ( track_id TEXT(36), tag_id TEXT(36), is_approved INTEGER DEFAULT (0), CONSTRAINT TrackTags_PK PRIMARY KEY (track_id,tag_id), CONSTRAINT TrackTags_FK FOREIGN KEY (track_id) REFERENCES Tracks(id) ON DELETE CASCADE, CONSTRAINT TrackTags_FK_1 FOREIGN KEY (tag_id) REFERENCES Tags(id) ON DELETE CASCADE ); CREATE INDEX IF NOT EXISTS TrackTags_is_approved_IDX ON TrackTags (is_approved); CREATE INDEX IF NOT EXISTS TrackTags_track_id_IDX ON TrackTags (track_id); CREATE INDEX IF NOT EXISTS TrackTags_tag_id_IDX ON TrackTags (tag_id); -- The Albums table will contain Albums! CREATE TABLE IF NOT EXISTS Albums ( id TEXT(36), title TEXT, description TEXT, is_public INTEGER DEFAULT (0), is_available INTEGER DEFAULT (1), preview_source TEXT, "source" TEXT, price INTEGER DEFAULT (0), created_by TEXT(36), created_at INTEGER, modified_by TEXT(36), modified_at INTEGER, deleted_by TEXT(36), deleted_at INTEGER, CONSTRAINT Albums_PK PRIMARY KEY (id), CONSTRAINT Albums_FK FOREIGN KEY (created_by) REFERENCES Persons(id), CONSTRAINT Albums_FK_1 FOREIGN KEY (modified_by) REFERENCES Persons(id), CONSTRAINT Albums_FK_2 FOREIGN KEY (deleted_by) REFERENCES Persons(id) ); CREATE INDEX IF NOT EXISTS Albums_title_IDX ON Albums (title); CREATE INDEX IF NOT EXISTS Albums_description_IDX ON Albums (description); CREATE INDEX IF NOT EXISTS Albums_is_public_IDX ON Albums (is_public); CREATE INDEX IF NOT EXISTS Albums_is_available_IDX ON Albums (is_available); CREATE INDEX IF NOT EXISTS Albums_price_IDX ON Albums (price); CREATE INDEX IF NOT EXISTS Albums_created_by_IDX ON Albums (created_by); CREATE INDEX IF NOT EXISTS Albums_deleted_at_IDX ON Albums (deleted_at); -- The AlbumArtists table will be a one-to-many lookup table mapping Artists to a particular Album. CREATE TABLE IF NOT EXISTS AlbumArtists ( album_id TEXT(36), artist_id TEXT(36), is_primary INTEGER DEFAULT (0), CONSTRAINT AlbumArtists_PK PRIMARY KEY (album_id,artist_id), CONSTRAINT AlbumArtists_FK FOREIGN KEY (album_id) REFERENCES Albums(id) ON DELETE CASCADE, CONSTRAINT AlbumArtists_FK_1 FOREIGN KEY (artist_id) REFERENCES Artists(id) ON DELETE CASCADE ); CREATE INDEX IF NOT EXISTS AlbumArtists_is_primary_IDX ON AlbumArtists (is_primary); CREATE INDEX IF NOT EXISTS AlbumArtists_album_id_IDX ON AlbumArtists (album_id); CREATE INDEX IF NOT EXISTS AlbumArtists_artist_id_IDX ON AlbumArtists (artist_id); -- The AlbumTags table will contain Tags that have been assigned to an Album. CREATE TABLE IF NOT EXISTS AlbumTags ( album_id TEXT(36), tag_id TEXT(36), is_approved INTEGER DEFAULT (0), CONSTRAINT AlbumTags_PK PRIMARY KEY (album_id,tag_id), CONSTRAINT AlbumTags_FK FOREIGN KEY (album_id) REFERENCES Albums(id) ON DELETE CASCADE, CONSTRAINT AlbumTags_FK_1 FOREIGN KEY (tag_id) REFERENCES Tags(id) ON DELETE CASCADE ); CREATE INDEX IF NOT EXISTS AlbumTags_is_approved_IDX ON AlbumTags (is_approved); CREATE INDEX IF NOT EXISTS AlbumTags_album_id_IDX ON AlbumTags (album_id); CREATE INDEX IF NOT EXISTS AlbumTags_tag_id_IDX ON AlbumTags (tag_id); -- The AlbumTracks table will be a many-to-many lookup table mapping Tracks to Albums CREATE TABLE IF NOT EXISTS AlbumTracks ( album_id TEXT(36), track_id TEXT(36), track_number INTEGER, CONSTRAINT AlbumTracks_PK PRIMARY KEY (album_id,track_id), CONSTRAINT AlbumTracks_FK FOREIGN KEY (album_id) REFERENCES Albums(id) ON DELETE CASCADE, CONSTRAINT AlbumTracks_FK_1 FOREIGN KEY (track_id) REFERENCES Tracks(id) ON DELETE CASCADE ); CREATE INDEX IF NOT EXISTS AlbumTracks_track_number_IDX ON AlbumTracks (track_number); CREATE INDEX IF NOT EXISTS AlbumTracks_album_id_IDX ON AlbumTracks (album_id); CREATE INDEX IF NOT EXISTS AlbumTracks_track_id_IDX ON AlbumTracks (track_id); -- The Playlists table will contain Playlists! CREATE TABLE IF NOT EXISTS Playlists ( id TEXT(36), title TEXT, description TEXT, created_by TEXT(36), created_at INTEGER, modified_at INTEGER, deleted_at INTEGER, is_public INTEGER DEFAULT (1), CONSTRAINT Playlists_PK PRIMARY KEY (id), CONSTRAINT Playlists_FK FOREIGN KEY (created_by) REFERENCES Persons(id) ); CREATE INDEX IF NOT EXISTS Playlists_title_IDX ON Playlists (title); CREATE INDEX IF NOT EXISTS Playlists_description_IDX ON Playlists (description); CREATE INDEX IF NOT EXISTS Playlists_created_by_IDX ON Playlists (created_by); CREATE INDEX IF NOT EXISTS Playlists_created_at_IDX ON Playlists (created_at); CREATE INDEX IF NOT EXISTS Playlists_modified_at_IDX ON Playlists (modified_at); CREATE INDEX IF NOT EXISTS Playlists_deleted_at_IDX ON Playlists (deleted_at); CREATE INDEX IF NOT EXISTS Playlists_is_public_IDX ON Playlists (is_public); -- The PlaylistTracks table will be a many-to-many lookup table mapping Tracks to Playlists CREATE TABLE IF NOT EXISTS PlaylistTracks ( playlist_track_id TEXT(36), playlist_id TEXT(36), track_id TEXT, track_number INTEGER, CONSTRAINT PlaylistTracks_PK PRIMARY KEY (playlist_track_id), CONSTRAINT PlaylistTracks_FK FOREIGN KEY (playlist_id) REFERENCES Playlists(id) ON DELETE CASCADE, CONSTRAINT PlaylistTracks_FK_1 FOREIGN KEY (track_id) REFERENCES Tracks(id) ON DELETE CASCADE ); CREATE INDEX IF NOT EXISTS PlaylistTracks_track_number_IDX ON PlaylistTracks (track_number); CREATE INDEX IF NOT EXISTS PlaylistTracks_playlist_id_IDX ON PlaylistTracks (playlist_id); CREATE INDEX IF NOT EXISTS PlaylistTracks_track_id_IDX ON PlaylistTracks (track_id); -- The PlaylistTags table will contain Tags that have been assigned to a Playlist. CREATE TABLE IF NOT EXISTS PlaylistTags ( playlist_id TEXT(36), tag_id TEXT(36), is_approved INTEGER DEFAULT (0), CONSTRAINT PlaylistTags_PK PRIMARY KEY (playlist_id,tag_id), CONSTRAINT PlaylistTags_FK FOREIGN KEY (playlist_id) REFERENCES Playlists(id) ON DELETE CASCADE, CONSTRAINT PlaylistTags_FK_1 FOREIGN KEY (tag_id) REFERENCES Tags(id) ON DELETE CASCADE ); CREATE INDEX IF NOT EXISTS PlaylistTags_is_approved_IDX ON PlaylistTags (is_approved); CREATE INDEX IF NOT EXISTS PlaylistTags_playlist_id_IDX ON PlaylistTags (playlist_id); CREATE INDEX IF NOT EXISTS PlaylistTags_tag_id_IDX ON PlaylistTags (tag_id); -- The Comments table will contain Comments! CREATE TABLE IF NOT EXISTS Comments ( id TEXT(36), body TEXT, created_by TEXT(36), created_at INTEGER, modified_by TEXT(36), modified_at INTEGER, deleted_by TEXT(36), deleted_at INTEGER, is_public INTEGER DEFAULT (1), is_approved INTEGER DEFAULT (0), in_reply_to TEXT(36), CONSTRAINT Comments_PK PRIMARY KEY (id), CONSTRAINT Comments_FK FOREIGN KEY (created_by) REFERENCES Persons(id), CONSTRAINT Comments_FK_1 FOREIGN KEY (modified_by) REFERENCES Persons(id), CONSTRAINT Comments_FK_2 FOREIGN KEY (deleted_by) REFERENCES Persons(id) ); CREATE INDEX IF NOT EXISTS Comments_body_IDX ON Comments (body); CREATE INDEX IF NOT EXISTS Comments_created_at_IDX ON Comments (created_at); CREATE INDEX IF NOT EXISTS Comments_modified_at_IDX ON Comments (modified_at); CREATE INDEX IF NOT EXISTS Comments_deleted_at_IDX ON Comments (deleted_at); CREATE INDEX IF NOT EXISTS Comments_is_public_IDX ON Comments (is_public); CREATE INDEX IF NOT EXISTS Comments_is_approved_IDX ON Comments (is_approved); CREATE INDEX IF NOT EXISTS Comments_in_reply_to_IDX ON Comments (in_reply_to); -- The LabelComments table will relate Comments to the Label they are about, if pertinent. CREATE TABLE IF NOT EXISTS LabelComments ( label_id TEXT(36), comment_id TEXT(36), CONSTRAINT LabelComments_PK PRIMARY KEY (label_id,comment_id), CONSTRAINT LabelComments_FK FOREIGN KEY (label_id) REFERENCES Labels(id) ON DELETE CASCADE, CONSTRAINT LabelComments_FK_1 FOREIGN KEY (comment_id) REFERENCES Comments(id) ON DELETE CASCADE ); CREATE INDEX IF NOT EXISTS LabelComments_label_id_IDX ON LabelComments (label_id); CREATE INDEX IF NOT EXISTS LabelComments_comment_id_IDX ON LabelComments (comment_id); -- The ArtistComments table will relate Comments to the Artist they are about, if pertinent. CREATE TABLE IF NOT EXISTS ArtistComments ( artist_id TEXT(36), comment_id TEXT(36), CONSTRAINT ArtistComments_PK PRIMARY KEY (artist_id,comment_id), CONSTRAINT ArtistComments_FK FOREIGN KEY (artist_id) REFERENCES Artists(id) ON DELETE CASCADE, CONSTRAINT ArtistComments_FK_1 FOREIGN KEY (comment_id) REFERENCES Comments(id) ON DELETE CASCADE ); CREATE INDEX IF NOT EXISTS ArtistComments_artist_id_IDX ON ArtistComments (artist_id); CREATE INDEX IF NOT EXISTS ArtistComments_comment_id_IDX ON ArtistComments (comment_id); -- The TrackComments table will relate Comments to the Track they are about, if pertinent. CREATE TABLE IF NOT EXISTS TrackComments ( track_id TEXT(36), comment_id TEXT(36), CONSTRAINT TrackComments_PK PRIMARY KEY (track_id,comment_id), CONSTRAINT TrackComments_FK FOREIGN KEY (track_id) REFERENCES Tracks(id) ON DELETE CASCADE, CONSTRAINT TrackComments_FK_1 FOREIGN KEY (comment_id) REFERENCES Comments(id) ON DELETE CASCADE ); CREATE INDEX IF NOT EXISTS TrackComments_track_id_IDX ON TrackComments (track_id); CREATE INDEX IF NOT EXISTS TrackComments_comment_id_IDX ON TrackComments (comment_id); -- The AlbumComments table will relate Comments to the Album they are about, if pertinent. CREATE TABLE IF NOT EXISTS AlbumComments ( album_id TEXT(36), comment_id TEXT(36), CONSTRAINT AlbumComments_PK PRIMARY KEY (album_id,comment_id), CONSTRAINT AlbumComments_FK FOREIGN KEY (album_id) REFERENCES Albums(id) ON DELETE CASCADE, CONSTRAINT AlbumComments_FK_1 FOREIGN KEY (comment_id) REFERENCES Comments(id) ON DELETE CASCADE ); CREATE INDEX IF NOT EXISTS AlbumComments_album_id_IDX ON AlbumComments (album_id); CREATE INDEX IF NOT EXISTS AlbumComments_comment_id_IDX ON AlbumComments (comment_id); -- The PlaylistComments table will relate Comments to the Playlist they are about, if pertinent. CREATE TABLE IF NOT EXISTS PlaylistComments ( playlist_id TEXT(36), comment_id TEXT(36), CONSTRAINT PlaylistComments_PK PRIMARY KEY (playlist_id,comment_id), CONSTRAINT PlaylistComments_FK FOREIGN KEY (playlist_id) REFERENCES Playlists(id) ON DELETE CASCADE, CONSTRAINT PlaylistComments_FK_1 FOREIGN KEY (comment_id) REFERENCES Comments(id) ON DELETE CASCADE ); CREATE INDEX IF NOT EXISTS PlaylistComments_playlist_id_IDX ON PlaylistComments (playlist_id); CREATE INDEX IF NOT EXISTS PlaylistComments_comment_id_IDX ON PlaylistComments (comment_id); -- The Images table will contain Images! CREATE TABLE IF NOT EXISTS Images ( id TEXT(36), name TEXT, "path" TEXT, url TEXT, width INTEGER, height INTEGER, alt_text TEXT, is_public INTEGER DEFAULT (1), allow_hotlinking INTEGER DEFAULT (0), created_by TEXT(36), created_at INTEGER, modified_by TEXT(36), modified_at INTEGER, deleted_by TEXT(36), deleted_at INTEGER, CONSTRAINT Images_PK PRIMARY KEY (id), CONSTRAINT Images_FK FOREIGN KEY (created_by) REFERENCES Persons(id), CONSTRAINT Images_FK_1 FOREIGN KEY (modified_by) REFERENCES Persons(id), CONSTRAINT Images_FK_2 FOREIGN KEY (deleted_by) REFERENCES Persons(id) ); CREATE INDEX IF NOT EXISTS Images_name_IDX ON Images (name); CREATE INDEX IF NOT EXISTS Images_path_IDX ON Images ("path"); CREATE INDEX IF NOT EXISTS Images_url_IDX ON Images (url); CREATE INDEX IF NOT EXISTS Images_alt_text_IDX ON Images (alt_text); CREATE INDEX IF NOT EXISTS Images_is_public_IDX ON Images (is_public); CREATE INDEX IF NOT EXISTS Images_allow_hotlinking_IDX ON Images (allow_hotlinking); CREATE INDEX IF NOT EXISTS Images_created_by_IDX ON Images (created_by); CREATE INDEX IF NOT EXISTS Images_deleted_at_IDX ON Images (deleted_at); -- The Videos table will contain Videos! CREATE TABLE IF NOT EXISTS Videos ( id TEXT(36), name TEXT, "path" TEXT, url TEXT, width INTEGER, height INTEGER, duration NUMERIC, alt_text TEXT, is_public INTEGER DEFAULT (1), allow_hotlinking INTEGER DEFAULT (0), created_by TEXT(36), created_at INTEGER, modified_by TEXT(36), modified_at INTEGER, deleted_by TEXT(36), deleted_at INTEGER, CONSTRAINT Videos_PK PRIMARY KEY (id), CONSTRAINT Videos_FK FOREIGN KEY (created_by) REFERENCES Persons(id), CONSTRAINT Videos_FK_1 FOREIGN KEY (modified_by) REFERENCES Persons(id), CONSTRAINT Videos_FK_2 FOREIGN KEY (deleted_by) REFERENCES Persons(id) ); CREATE INDEX IF NOT EXISTS Videos_name_IDX ON Videos (name); CREATE INDEX IF NOT EXISTS Videos_path_IDX ON Videos ("path"); CREATE INDEX IF NOT EXISTS Videos_url_IDX ON Videos (url); CREATE INDEX IF NOT EXISTS Videos_alt_text_IDX ON Videos (alt_text); CREATE INDEX IF NOT EXISTS Videos_is_public_IDX ON Videos (is_public); CREATE INDEX IF NOT EXISTS Videos_allow_hotlinking_IDX ON Videos (allow_hotlinking); CREATE INDEX IF NOT EXISTS Videos_created_by_IDX ON Videos (created_by); CREATE INDEX IF NOT EXISTS Videos_deleted_at_IDX ON Videos (deleted_at); -- The Articles table will contain Articles! CREATE TABLE IF NOT EXISTS Articles ( id TEXT(36), title TEXT, body TEXT, description TEXT, created_by TEXT(36), created_at INTEGER, modified_at INTEGER, published_at INTEGER, deleted_at INTEGER, is_public INTEGER DEFAULT (0), is_draft INTEGER DEFAULT (1), CONSTRAINT Articles_PK PRIMARY KEY (id), CONSTRAINT Articles_FK FOREIGN KEY (created_by) REFERENCES Persons(id) ); CREATE INDEX IF NOT EXISTS Articles_title_IDX ON Articles (title); CREATE INDEX IF NOT EXISTS Articles_body_IDX ON Articles (body); CREATE INDEX IF NOT EXISTS Articles_description_IDX ON Articles (description); CREATE INDEX IF NOT EXISTS Articles_created_by_IDX ON Articles (created_by); CREATE INDEX IF NOT EXISTS Articles_published_at_IDX ON Articles (published_at); CREATE INDEX IF NOT EXISTS Articles_deleted_at_IDX ON Articles (deleted_at); CREATE INDEX IF NOT EXISTS Articles_is_public_IDX ON Articles (is_public); CREATE INDEX IF NOT EXISTS Articles_is_draft_IDX ON Articles (is_draft); -- The ArticleTags table will contain Tags that have been assigned to an Article. CREATE TABLE IF NOT EXISTS ArticleTags ( article_id TEXT(36), tag_id TEXT(36), is_approved INTEGER DEFAULT (0), CONSTRAINT ArticleTags_PK PRIMARY KEY (article_id,tag_id), CONSTRAINT ArticleTags_FK FOREIGN KEY (article_id) REFERENCES Articles(id) ON DELETE CASCADE, CONSTRAINT ArticleTags_FK_1 FOREIGN KEY (tag_id) REFERENCES Tags(id) ON DELETE CASCADE ); CREATE INDEX IF NOT EXISTS ArticleTags_is_approved_IDX ON ArticleTags (is_approved); -- The ArticleComments table will relate Comments to the Article they are about, if pertinent. CREATE TABLE IF NOT EXISTS ArticleComments ( article_id TEXT(36), comment_id TEXT(36), CONSTRAINT ArticleComments_PK PRIMARY KEY (article_id,comment_id), CONSTRAINT ArticleComments_FK FOREIGN KEY (article_id) REFERENCES Articles(id) ON DELETE CASCADE, CONSTRAINT ArticleComments_FK_1 FOREIGN KEY (comment_id) REFERENCES Comments(id) ON DELETE CASCADE ); CREATE INDEX IF NOT EXISTS ArticleComments_article_id_IDX ON ArticleComments (article_id); CREATE INDEX IF NOT EXISTS ArticleComments_comment_id_IDX ON ArticleComments (comment_id); -- The OtherProducts table will contain products for sale that are not Albums nor Tracks nor Collections. CREATE TABLE IF NOT EXISTS OtherProducts ( id TEXT(36), name TEXT, description TEXT, created_by TEXT(36), created_at INTEGER, modified_by TEXT(36), modified_at INTEGER, deleted_by TEXT(36), deleted_at INTEGER, is_public INTEGER DEFAULT (0), is_available INTEGER DEFAULT (0), requires_shipping INTEGER DEFAULT (0), CONSTRAINT OtherProducts_PK PRIMARY KEY (id), CONSTRAINT OtherProducts_FK FOREIGN KEY (created_by) REFERENCES Persons(id), CONSTRAINT OtherProducts_FK_1 FOREIGN KEY (modified_by) REFERENCES Persons(id), CONSTRAINT OtherProducts_FK_2 FOREIGN KEY (deleted_by) REFERENCES Persons(id) ); CREATE INDEX IF NOT EXISTS OtherProducts_name_IDX ON OtherProducts (name); CREATE INDEX IF NOT EXISTS OtherProducts_description_IDX ON OtherProducts (description); CREATE INDEX IF NOT EXISTS OtherProducts_created_by_IDX ON OtherProducts (created_by); CREATE INDEX IF NOT EXISTS OtherProducts_created_at_IDX ON OtherProducts (created_at); CREATE INDEX IF NOT EXISTS OtherProducts_modified_by_IDX ON OtherProducts (modified_by); CREATE INDEX IF NOT EXISTS OtherProducts_modified_at_IDX ON OtherProducts (modified_at); CREATE INDEX IF NOT EXISTS OtherProducts_deleted_by_IDX ON OtherProducts (deleted_by); CREATE INDEX IF NOT EXISTS OtherProducts_deleted_at_IDX ON OtherProducts (deleted_at); CREATE INDEX IF NOT EXISTS OtherProducts_is_public_IDX ON OtherProducts (is_public); CREATE INDEX IF NOT EXISTS OtherProducts_is_available_IDX ON OtherProducts (is_available); CREATE INDEX IF NOT EXISTS OtherProducts_requires_shipping_IDX ON OtherProducts (requires_shipping); -- The Collections table will contain Collections where each Collection is comprised of one or more Tracks, Albums, and/or OtherProducts packaged together for sale. CREATE TABLE IF NOT EXISTS Collections ( id TEXT(36), name TEXT, description TEXT, created_by TEXT(36), created_at INTEGER, modified_by TEXT(36), modified_at INTEGER, deleted_by TEXT(36), deleted_at INTEGER, is_public INTEGER DEFAULT (0), is_available INTEGER DEFAULT (0), CONSTRAINT Collections_PK PRIMARY KEY (id), CONSTRAINT Collections_FK FOREIGN KEY (created_by) REFERENCES Persons(id), CONSTRAINT Collections_FK_1 FOREIGN KEY (modified_by) REFERENCES Persons(id), CONSTRAINT Collections_FK_2 FOREIGN KEY (deleted_by) REFERENCES Persons(id) ); CREATE INDEX IF NOT EXISTS Collections_name_IDX ON Collections (name); CREATE INDEX IF NOT EXISTS Collections_description_IDX ON Collections (description); CREATE INDEX IF NOT EXISTS Collections_created_by_IDX ON Collections (created_by); CREATE INDEX IF NOT EXISTS Collections_created_at_IDX ON Collections (created_at); CREATE INDEX IF NOT EXISTS Collections_modified_by_IDX ON Collections (modified_by); CREATE INDEX IF NOT EXISTS Collections_modified_at_IDX ON Collections (modified_at); CREATE INDEX IF NOT EXISTS Collections_deleted_by_IDX ON Collections (deleted_by); CREATE INDEX IF NOT EXISTS Collections_deleted_at_IDX ON Collections (deleted_at); CREATE INDEX IF NOT EXISTS Collections_is_public_IDX ON Collections (is_public); CREATE INDEX IF NOT EXISTS Collections_is_available_IDX ON Collections (is_available); -- The CollectionAlbums table will relate a Collection to the Album(s) it contains. CREATE TABLE IF NOT EXISTS CollectionAlbums ( collection_id TEXT(36), album_id TEXT(36), CONSTRAINT CollectionAlbums_PK PRIMARY KEY (collection_id,album_id), CONSTRAINT CollectionAlbums_FK FOREIGN KEY (collection_id) REFERENCES Collections(id) ON DELETE CASCADE, CONSTRAINT CollectionAlbums_FK_1 FOREIGN KEY (album_id) REFERENCES Albums(id) ON DELETE CASCADE ); CREATE INDEX IF NOT EXISTS CollectionAlbums_collection_id_IDX ON CollectionAlbums (collection_id); CREATE INDEX IF NOT EXISTS CollectionAlbums_album_id_IDX ON CollectionAlbums (album_id); -- The CollectionTracks table will relate a Collection to the Track(s) it contains. CREATE TABLE IF NOT EXISTS CollectionTracks ( collection_id TEXT(36), track_id TEXT(36), CONSTRAINT CollectionTracks_PK PRIMARY KEY (collection_id,track_id), CONSTRAINT CollectionTracks_FK FOREIGN KEY (collection_id) REFERENCES Collections(id) ON DELETE CASCADE, CONSTRAINT CollectionTracks_FK_1 FOREIGN KEY (track_id) REFERENCES Tracks(id) ON DELETE CASCADE ); CREATE INDEX IF NOT EXISTS CollectionTracks_collection_id_IDX ON CollectionTracks (collection_id); CREATE INDEX IF NOT EXISTS CollectionTracks_track_id_IDX ON CollectionTracks (track_id); -- The CollectionOtherProducts table will relate a Collection to the OtherProduct(s) it contains. CREATE TABLE IF NOT EXISTS CollectionOtherProducts ( collection_id TEXT(36), other_product_id TEXT(36), CONSTRAINT CollectionOtherProducts_PK PRIMARY KEY (collection_id,other_product_id), CONSTRAINT CollectionOtherProducts_FK FOREIGN KEY (collection_id) REFERENCES Collections(id) ON DELETE CASCADE, CONSTRAINT CollectionOtherProducts_FK_1 FOREIGN KEY (other_product_id) REFERENCES OtherProducts(id) ON DELETE CASCADE ); CREATE INDEX IF NOT EXISTS CollectionOtherProducts_collection_id_IDX ON CollectionOtherProducts (collection_id); CREATE INDEX IF NOT EXISTS CollectionOtherProducts_other_product_id_IDX ON CollectionOtherProducts (other_product_id); -- The Skus table will contain SKUs () representing items available for Purchase through the server. CREATE TABLE IF NOT EXISTS Skus ( id TEXT(36), item_type TEXT, item_id TEXT(36), variant TEXT, description TEXT, price NUMERIC DEFAULT (0.00), requires_shipping INTEGER DEFAULT (0), shipping_charge NUMERIC DEFAULT (0.00), CONSTRAINT Skus_PK PRIMARY KEY (id) ); CREATE INDEX IF NOT EXISTS Skus_item_type_IDX ON Skus (item_type); CREATE INDEX IF NOT EXISTS Skus_item_id_IDX ON Skus (item_id); CREATE INDEX IF NOT EXISTS Skus_variant_IDX ON Skus (variant); CREATE INDEX IF NOT EXISTS Skus_description_IDX ON Skus (description); CREATE INDEX IF NOT EXISTS Skus_price_IDX ON Skus (price); CREATE INDEX IF NOT EXISTS Skus_requires_shipping_IDX ON Skus (requires_shipping); CREATE INDEX IF NOT EXISTS Skus_shipping_charge_IDX ON Skus (shipping_charge); -- The LineItems table will contain individual SKUs and their associated quantites as part of a Purchase. CREATE TABLE IF NOT EXISTS LineItems ( id TEXT(36), sku_id TEXT(36), quantity INTEGER DEFAULT (1), CONSTRAINT LineItems_PK PRIMARY KEY (id), CONSTRAINT LineItems_FK FOREIGN KEY (sku_id) REFERENCES Skus(id) ); CREATE INDEX IF NOT EXISTS LineItems_sku_id_IDX ON LineItems (sku_id); CREATE INDEX IF NOT EXISTS LineItems_quantity_IDX ON LineItems (quantity); -- The CouponCodes table will contain coupon codes that can be redeemed for a discount, either by amount or percentage, on a Purchase. CREATE TABLE IF NOT EXISTS CouponCodes ( id TEXT(36), name TEXT, code TEXT, uses INTEGER DEFAULT (0), max_uses INTEGER DEFAULT (0), expiration INTEGER, discount_flat NUMERIC DEFAULT (0.00), discount_percentage NUMERIC DEFAULT (0.00), is_sku_specific INTEGER DEFAULT (0), is_active INTEGER DEFAULT (0), created_by TEXT(36), created_at INTEGER, modified_by TEXT(36), modified_at INTEGER, deleted_by TEXT(36), deleted_at INTEGER, CONSTRAINT CouponCodes_PK PRIMARY KEY (id), CONSTRAINT CouponCodes_FK FOREIGN KEY (created_by) REFERENCES Persons(id), CONSTRAINT CouponCodes_FK_1 FOREIGN KEY (modified_by) REFERENCES Persons(id), CONSTRAINT CouponCodes_FK_2 FOREIGN KEY (deleted_by) REFERENCES Persons(id) ); CREATE INDEX IF NOT EXISTS CouponCodes_name_IDX ON CouponCodes (name); CREATE UNIQUE INDEX IF NOT EXISTS CouponCodes_code_IDX ON CouponCodes (code); CREATE INDEX IF NOT EXISTS CouponCodes_uses_IDX ON CouponCodes (uses); CREATE INDEX IF NOT EXISTS CouponCodes_max_uses_IDX ON CouponCodes (max_uses); CREATE INDEX IF NOT EXISTS CouponCodes_expiration_IDX ON CouponCodes (expiration); CREATE INDEX IF NOT EXISTS CouponCodes_is_sku_specific_IDX ON CouponCodes (is_sku_specific); CREATE INDEX IF NOT EXISTS CouponCodes_is_active_IDX ON CouponCodes (is_active); CREATE INDEX IF NOT EXISTS CouponCodes_created_by_IDX ON CouponCodes (created_by); CREATE INDEX IF NOT EXISTS CouponCodes_created_at_IDX ON CouponCodes (created_at); CREATE INDEX IF NOT EXISTS CouponCodes_modified_by_IDX ON CouponCodes (modified_by); CREATE INDEX IF NOT EXISTS CouponCodes_modified_at_IDX ON CouponCodes (modified_at); CREATE INDEX IF NOT EXISTS CouponCodes_deleted_by_IDX ON CouponCodes (deleted_by); CREATE INDEX IF NOT EXISTS CouponCodes_deleted_at_IDX ON CouponCodes (deleted_at); -- The CouponCodeSkus table will relate a CouponCode to one or more Skus the CouponCode can be applied to, if CouponCode.is_sku_specific is true. (If CouponCode.is_sku_specific is false the CouponCode can be applied to an entire Purchase regardless of the Skus being purchased.) CREATE TABLE IF NOT EXISTS CouponCodeSkus ( coupon_code_id TEXT(36), sku_id TEXT(36), CONSTRAINT CouponCodeSkus_PK PRIMARY KEY (coupon_code_id,sku_id), CONSTRAINT CouponCodeSkus_FK FOREIGN KEY (coupon_code_id) REFERENCES CouponCodes(id), CONSTRAINT CouponCodeSkus_FK_1 FOREIGN KEY (sku_id) REFERENCES Skus(id) ); -- The Purchases table will contain Purchases! CREATE TABLE IF NOT EXISTS Purchases ( id TEXT(36), state TEXT, purchased_by TEXT(36), purchased_at INTEGER, fulfilled_by TEXT(36), fulfilled_at INTEGER, total_charge NUMERIC DEFAULT (0.00), CONSTRAINT Purchases_PK PRIMARY KEY (id), CONSTRAINT Purchases_FK FOREIGN KEY (purchased_by) REFERENCES Persons(id), CONSTRAINT Purchases_FK_1 FOREIGN KEY (fulfilled_by) REFERENCES Persons(id) ); CREATE INDEX IF NOT EXISTS Purchases_state_IDX ON Purchases (state); CREATE INDEX IF NOT EXISTS Purchases_purchased_by_IDX ON Purchases (purchased_by); CREATE INDEX IF NOT EXISTS Purchases_purchased_at_IDX ON Purchases (purchased_at); CREATE INDEX IF NOT EXISTS Purchases_fulfilled_by_IDX ON Purchases (fulfilled_by); CREATE INDEX IF NOT EXISTS Purchases_fulfilled_at_IDX ON Purchases (fulfilled_at); CREATE INDEX IF NOT EXISTS Purchases_total_charge_IDX ON Purchases (total_charge); -- The PurchaseLineItems table will relate a Purchase to one or more LineItems. CREATE TABLE IF NOT EXISTS PurchaseLineItems ( purchase_id TEXT(36), line_item_id TEXT(36), CONSTRAINT PurchaseLineItems_PK PRIMARY KEY (purchase_id,line_item_id), CONSTRAINT PurchaseLineItems_FK FOREIGN KEY (purchase_id) REFERENCES Purchases(id), CONSTRAINT PurchaseLineItems_FK_1 FOREIGN KEY (line_item_id) REFERENCES LineItems(id) ON DELETE CASCADE ); CREATE INDEX IF NOT EXISTS PurchaseLineItems_purchase_id_IDX ON PurchaseLineItems (purchase_id); CREATE INDEX IF NOT EXISTS PurchaseLineItems_line_item_id_IDX ON PurchaseLineItems (line_item_id); -- The PurchaseCouponCodes table will relate a Purchase to one or more CouponCodes successfully applied to the Purchase. CREATE TABLE IF NOT EXISTS PurchaseCouponCodes ( purchase_id TEXT(36), coupon_code_id TEXT(36), CONSTRAINT PurchaseCouponCodes_PK PRIMARY KEY (purchase_id,coupon_code_id), CONSTRAINT PurchaseCouponCodes_FK FOREIGN KEY (purchase_id) REFERENCES Purchases(id), CONSTRAINT PurchaseCouponCodes_FK_1 FOREIGN KEY (coupon_code_id) REFERENCES CouponCodes(id) ); CREATE INDEX IF NOT EXISTS PurchaseCouponCodes_purchase_id_IDX ON PurchaseCouponCodes (purchase_id); CREATE INDEX IF NOT EXISTS PurchaseCouponCodes_coupon_code_id_IDX ON PurchaseCouponCodes (coupon_code_id);