Skip to content

Commit

Permalink
Add SQL scripts for connecting new music services and migrating user …
Browse files Browse the repository at this point in the history
…data (#1384)

* Add new external_auth table for music services

* Add migration script for moving spotify users data to new tables

* Rename external_auth to external_service_oauth and external_auth_service to external_service_oauth_type.

* Add indices for external_service_oauth table

* Rename files to make order of application clear

* Fix indent
  • Loading branch information
amCap1712 committed Apr 14, 2021
1 parent 4eca81e commit 59d3398
Show file tree
Hide file tree
Showing 8 changed files with 81 additions and 0 deletions.
6 changes: 6 additions & 0 deletions admin/sql/create_foreign_keys.sql
Original file line number Diff line number Diff line change
Expand Up @@ -24,6 +24,12 @@ ALTER TABLE spotify_auth
REFERENCES "user" (id)
ON DELETE CASCADE;

ALTER TABLE external_service_oauth
ADD CONSTRAINT external_service_oauth_user_id_foreign_key
FOREIGN KEY (user_id)
REFERENCES "user" (id)
ON DELETE CASCADE;

ALTER TABLE recommendation.cf_recording
ADD CONSTRAINT cf_recording_user_id_foreign_key
FOREIGN KEY (user_id)
Expand Down
4 changes: 4 additions & 0 deletions admin/sql/create_indexes.sql
Original file line number Diff line number Diff line change
Expand Up @@ -17,6 +17,10 @@ CREATE UNIQUE INDEX msid_ndx_recording_stats ON statistics.recording (msid);

CREATE INDEX latest_listened_at_spotify_auth ON spotify_auth (latest_listened_at DESC NULLS LAST);

CREATE INDEX user_id_ndx_external_service_oauth ON external_service_oauth (user_id);
CREATE INDEX service_ndx_external_service_oauth ON external_service_oauth (service);
CREATE UNIQUE INDEX user_id_service_ndx_external_service_oauth ON external_service_oauth (user_id, service);

CREATE UNIQUE INDEX user_id_rec_msid_ndx_feedback ON recording_feedback (user_id, recording_msid);

-- NOTE: If the indexes for the similar_user table changes, update the code in listenbrainz/db/similar_users.py !
Expand Down
1 change: 1 addition & 0 deletions admin/sql/create_primary_keys.sql
Original file line number Diff line number Diff line change
Expand Up @@ -3,6 +3,7 @@ BEGIN;
ALTER TABLE "user" ADD CONSTRAINT user_pkey PRIMARY KEY (id);
ALTER TABLE api_compat.session ADD CONSTRAINT session_pkey PRIMARY KEY (sid);
ALTER TABLE spotify_auth ADD CONSTRAINT spotify_auth_pkey PRIMARY KEY (user_id);
ALTER TABLE external_service_oauth ADD CONSTRAINT external_service_oauth_pkey PRIMARY KEY (id);

ALTER TABLE statistics.user ADD CONSTRAINT stats_user_pkey PRIMARY KEY (user_id);
ALTER TABLE statistics.artist ADD CONSTRAINT stats_artist_pkey PRIMARY KEY (id);
Expand Down
12 changes: 12 additions & 0 deletions admin/sql/create_tables.sql
Original file line number Diff line number Diff line change
Expand Up @@ -104,6 +104,18 @@ CREATE TABLE spotify_auth (
permission VARCHAR NOT NULL
);

CREATE TABLE external_service_oauth (
id SERIAL,
user_id INTEGER NOT NULL,
service external_service_oauth_type NOT NULL,
access_token TEXT NOT NULL,
refresh_token TEXT,
token_expires TIMESTAMP WITH TIME ZONE,
last_updated TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
record_listens BOOLEAN NOT NULL,
service_details JSONB
);

CREATE TABLE statistics.artist (
id SERIAL, -- PK
msid UUID NOT NULL,
Expand Down
2 changes: 2 additions & 0 deletions admin/sql/create_types.sql
Original file line number Diff line number Diff line change
Expand Up @@ -7,3 +7,5 @@ CREATE TYPE user_relationship_enum AS ENUM('follow');
CREATE TYPE recommendation_feedback_type_enum AS ENUM('like', 'love', 'dislike', 'hate', 'bad_recommendation');

CREATE TYPE user_timeline_event_type_enum AS ENUM('recording_recommendation', 'notification');

CREATE TYPE external_service_oauth_type AS ENUM ('spotify', 'youtube');
1 change: 1 addition & 0 deletions admin/sql/drop_tables.sql
Original file line number Diff line number Diff line change
Expand Up @@ -3,6 +3,7 @@ BEGIN;
DROP TABLE IF EXISTS "user" CASCADE;
DROP TABLE IF EXISTS data_dump CASCADE;
DROP TABLE IF EXISTS spotify_auth CASCADE;
DROP TABLE IF EXISTS external_service_oauth CASCADE;
DROP TABLE IF EXISTS recording_feedback CASCADE;
DROP TABLE IF EXISTS missing_musicbrainz_data CASCADE;
DROP TABLE IF EXISTS user_relationship CASCADE;
Expand Down
29 changes: 29 additions & 0 deletions admin/sql/updates/2021-04-12-1-new-music-services-table.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,29 @@
BEGIN;

CREATE TYPE external_service_oauth_type AS ENUM ('spotify', 'youtube');

CREATE TABLE external_service_oauth (
id SERIAL,
user_id INTEGER NOT NULL,
service external_service_oauth_type NOT NULL,
access_token TEXT NOT NULL,
refresh_token TEXT,
token_expires TIMESTAMP WITH TIME ZONE,
last_updated TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
record_listens BOOLEAN NOT NULL,
service_details JSONB
);

ALTER TABLE external_service_oauth ADD CONSTRAINT external_service_oauth_pkey PRIMARY KEY (id);

ALTER TABLE external_service_oauth
ADD CONSTRAINT external_service_oauth_user_id_foreign_key
FOREIGN KEY (user_id)
REFERENCES "user" (id)
ON DELETE CASCADE;

CREATE INDEX user_id_ndx_external_service_oauth ON external_service_oauth (user_id);
CREATE INDEX service_ndx_external_service_oauth ON external_service_oauth (service);
CREATE UNIQUE INDEX user_id_service_ndx_external_service_oauth ON external_service_oauth (user_id, service);

COMMIT;
Original file line number Diff line number Diff line change
@@ -0,0 +1,26 @@
BEGIN;
INSERT INTO external_service_oauth
(
user_id,
service,
access_token,
refresh_token,
token_expires,
last_updated,
record_listens,
service_details
)
SELECT user_id,
'spotify' as service,
user_token as access_token,
refresh_token,
token_expires,
last_updated,
record_listens,
jsonb_build_object(
'latest_listened_at', latest_listened_at,
'error_message', error_message,
'permission', permission
)
FROM spotify_auth;
COMMIT;

0 comments on commit 59d3398

Please sign in to comment.