Skip to content

Commit

Permalink
Discovery solana DB slot migration (#2793)
Browse files Browse the repository at this point in the history
* Add discovery migration for sol slot to db

* Update migration with index instead of pk

* Update orm models

* make migration idempotent

* Update migration and models

* Fix tests

* Fix discovery db multi head
  • Loading branch information
jowlee committed Apr 4, 2022
1 parent c238dd8 commit 6deac71
Show file tree
Hide file tree
Showing 5 changed files with 268 additions and 29 deletions.
Original file line number Diff line number Diff line change
@@ -0,0 +1,217 @@
"""solana slots migration
Revision ID: 11060779bb3a
Revises: 37a4458bb72c
Create Date: 2022-03-29 18:49:45.022146
"""
import sqlalchemy as sa
from alembic import op

# revision identifiers, used by Alembic.
revision = "11060779bb3a"
down_revision = "37a4458bb72c"
branch_labels = None
depends_on = None


def upgrade():
connection = op.get_bind()
connection.execute(
"""
begin;
CREATE TABLE IF NOT EXISTS audius_data_txs (
signature VARCHAR PRIMARY KEY,
slot INTEGER NOT NULL
);
ALTER TABLE users DROP CONSTRAINT IF EXISTS users_pkey;
UPDATE users
SET txhash = ('unset_' || substr(md5(random()::text), 0, 10))
WHERE txhash='';
ALTER TABLE users ADD PRIMARY KEY (is_current, user_id, txhash);
ALTER TABLE users
ADD COLUMN IF NOT EXISTS slot INTEGER,
ADD COLUMN IF NOT EXISTS user_storage_account VARCHAR,
ADD COLUMN IF NOT EXISTS user_authority_account VARCHAR;
-- Drop NOT NULL Constraint on POA blockhash and tx hash columns
ALTER TABLE users ALTER COLUMN blockhash DROP NOT NULL;
ALTER TABLE users ALTER COLUMN blocknumber DROP NOT NULL;
ALTER TABLE tracks DROP CONSTRAINT IF EXISTS tracks_pkey;
UPDATE tracks
SET txhash = ('unset_' || substr(md5(random()::text), 0, 10))
WHERE txhash='';
ALTER TABLE tracks ADD PRIMARY KEY (is_current, track_id, txhash);
ALTER TABLE tracks ADD COLUMN IF NOT EXISTS slot INTEGER;
-- Drop NOT NULL Constraint on POA blockhash and tx hash columns
ALTER TABLE tracks ALTER COLUMN blockhash DROP NOT NULL;
ALTER TABLE tracks ALTER COLUMN blocknumber DROP NOT NULL;
ALTER TABLE playlists DROP CONSTRAINT IF EXISTS playlists_pkey;
UPDATE playlists
SET txhash = ('unset_' || substr(md5(random()::text), 0, 10))
WHERE txhash='';
ALTER TABLE playlists ADD PRIMARY KEY (is_current, playlist_id, txhash);
ALTER TABLE playlists ADD COLUMN IF NOT EXISTS slot INTEGER;
-- Drop NOT NULL Constraint on POA blockhash and tx hash columns
ALTER TABLE playlists ALTER COLUMN blockhash DROP NOT NULL;
ALTER TABLE playlists ALTER COLUMN blocknumber DROP NOT NULL;
ALTER TABLE reposts DROP CONSTRAINT IF EXISTS reposts_pkey;
UPDATE reposts
SET txhash = ('unset_' || substr(md5(random()::text), 0, 10))
WHERE txhash='';
ALTER TABLE reposts ADD PRIMARY KEY (is_current, user_id, repost_item_id, repost_type, txhash);
ALTER TABLE reposts ADD COLUMN IF NOT EXISTS slot INTEGER;
-- Drop NOT NULL Constraint on POA blockhash and tx hash columns
ALTER TABLE reposts ALTER COLUMN blockhash DROP NOT NULL;
ALTER TABLE reposts ALTER COLUMN blocknumber DROP NOT NULL;
ALTER TABLE saves DROP CONSTRAINT IF EXISTS saves_pkey;
UPDATE saves
SET txhash = ('unset_' || substr(md5(random()::text), 0, 10))
WHERE txhash='';
ALTER TABLE saves ADD PRIMARY KEY (is_current, user_id, save_item_id, save_type, txhash);
ALTER TABLE saves ADD COLUMN IF NOT EXISTS slot INTEGER;
-- Drop NOT NULL Constraint on POA blockhash and tx hash columns
ALTER TABLE saves ALTER COLUMN blockhash DROP NOT NULL;
ALTER TABLE saves ALTER COLUMN blocknumber DROP NOT NULL;
ALTER TABLE ursm_content_nodes DROP CONSTRAINT IF EXISTS ursm_content_nodes_pkey;
UPDATE ursm_content_nodes
SET txhash = ('unset_' || substr(md5(random()::text), 0, 10))
WHERE txhash='';
ALTER TABLE ursm_content_nodes ADD PRIMARY KEY (is_current, cnode_sp_id, txhash);
ALTER TABLE ursm_content_nodes ADD COLUMN IF NOT EXISTS slot INTEGER;
-- Drop NOT NULL Constraint on POA blockhash and tx hash columns
ALTER TABLE ursm_content_nodes ALTER COLUMN blockhash DROP NOT NULL;
ALTER TABLE ursm_content_nodes ALTER COLUMN blocknumber DROP NOT NULL;
ALTER TABLE follows DROP CONSTRAINT IF EXISTS follows_pkey;
UPDATE follows
SET txhash = ('unset_' || substr(md5(random()::text), 0, 10))
WHERE txhash='';
ALTER TABLE follows ADD PRIMARY KEY (is_current, follower_user_id, followee_user_id, txhash);
ALTER TABLE follows ADD COLUMN IF NOT EXISTS slot INTEGER;
-- Drop NOT NULL Constraint on POA blockhash and tx hash columns
ALTER TABLE follows ALTER COLUMN blockhash DROP NOT NULL;
ALTER TABLE follows ALTER COLUMN blocknumber DROP NOT NULL;
-- Drop NOT NULL Constraint on POA blockhash and tx hash columns
ALTER TABLE user_events ADD COLUMN IF NOT EXISTS slot INTEGER;
ALTER TABLE user_events ALTER COLUMN blockhash DROP NOT NULL;
ALTER TABLE user_events ALTER COLUMN blocknumber DROP NOT NULL;
commit;
"""
)


def downgrade():
connection = op.get_bind()
connection.execute(
"""
begin;
DROP TABLE IF EXISTS audius_data_txs;
ALTER TABLE users DROP CONSTRAINT IF EXISTS users_pkey;
ALTER TABLE users ADD PRIMARY KEY (is_current, user_id, blockhash, txhash);
ALTER TABLE users
DROP COLUMN IF EXISTS slot,
DROP COLUMN IF EXISTS user_storage_account,
DROP COLUMN IF EXISTS user_authority_account;
-- Add NOT NULL Constraint on POA blockhash and tx hash columns
DELETE FROM users where blockhash IS NULL or blocknumber IS NULL;
ALTER TABLE users ALTER COLUMN blockhash SET NOT NULL;
ALTER TABLE users ALTER COLUMN blocknumber SET NOT NULL;
ALTER TABLE tracks DROP CONSTRAINT IF EXISTS tracks_pkey;
ALTER TABLE tracks ADD PRIMARY KEY (is_current, track_id, blockhash, txhash);
ALTER TABLE tracks DROP COLUMN IF EXISTS slot;
-- Add NOT NULL Constraint on POA blockhash and tx hash columns
DELETE FROM tracks where blockhash IS NULL or blocknumber IS NULL;
ALTER TABLE tracks ALTER COLUMN blockhash SET NOT NULL;
ALTER TABLE tracks ALTER COLUMN blocknumber SET NOT NULL;
ALTER TABLE playlists DROP CONSTRAINT IF EXISTS playlists_pkey;
ALTER TABLE playlists ADD PRIMARY KEY (is_current, playlist_id, playlist_owner_id, blockhash, txhash);
ALTER TABLE playlists DROP COLUMN IF EXISTS slot;
-- Add NOT NULL Constraint on POA blockhash and tx hash columns
DELETE FROM playlists where blockhash IS NULL or blocknumber IS NULL;
ALTER TABLE playlists ALTER COLUMN blockhash SET NOT NULL;
ALTER TABLE playlists ALTER COLUMN blocknumber SET NOT NULL;
ALTER TABLE reposts DROP CONSTRAINT IF EXISTS reposts_pkey;
ALTER TABLE reposts ADD PRIMARY KEY (is_current, user_id, repost_item_id, repost_type, blockhash, txhash);
ALTER TABLE reposts DROP COLUMN IF EXISTS slot;
-- Add NOT NULL Constraint on POA blockhash and tx hash columns
DELETE FROM reposts where blockhash IS NULL or blocknumber IS NULL;
ALTER TABLE reposts ALTER COLUMN blockhash SET NOT NULL;
ALTER TABLE reposts ALTER COLUMN blocknumber SET NOT NULL;
ALTER TABLE saves DROP CONSTRAINT IF EXISTS saves_pkey;
ALTER TABLE saves ADD PRIMARY KEY (is_current, user_id, save_item_id, save_type, blockhash, txhash);
ALTER TABLE saves DROP COLUMN IF EXISTS slot;
-- Add NOT NULL Constraint on POA blockhash and tx hash columns
DELETE FROM saves where blockhash IS NULL or blocknumber IS NULL;
ALTER TABLE saves ALTER COLUMN blockhash SET NOT NULL;
ALTER TABLE saves ALTER COLUMN blocknumber SET NOT NULL;
ALTER TABLE ursm_content_nodes DROP CONSTRAINT IF EXISTS ursm_content_nodes_pkey;
ALTER TABLE ursm_content_nodes ADD PRIMARY KEY (is_current, cnode_sp_id, blockhash, txhash);
ALTER TABLE ursm_content_nodes DROP COLUMN IF EXISTS slot;
-- Add NOT NULL Constraint on POA blockhash and tx hash columns
DELETE FROM ursm_content_nodes where blockhash IS NULL or blocknumber IS NULL;
ALTER TABLE ursm_content_nodes ALTER COLUMN blockhash SET NOT NULL;
ALTER TABLE ursm_content_nodes ALTER COLUMN blocknumber SET NOT NULL;
ALTER TABLE follows DROP CONSTRAINT IF EXISTS follows_pkey;
ALTER TABLE follows ADD PRIMARY KEY (is_current, follower_user_id, followee_user_id, blockhash, txhash);
ALTER TABLE follows DROP COLUMN IF EXISTS slot;
-- Add NOT NULL Constraint on POA blockhash and tx hash columns
ALTER TABLE follows ALTER COLUMN blockhash SET NOT NULL;
ALTER TABLE follows ALTER COLUMN blocknumber SET NOT NULL;
-- Drop NOT NULL Constraint on POA blockhash and tx hash columns
ALTER TABLE user_events DROP COLUMN IF EXISTS slot;
ALTER TABLE user_events ALTER COLUMN blockhash SET NOT NULL;
ALTER TABLE user_events ALTER COLUMN blocknumber SET NOT NULL;
commit;
"""
)
7 changes: 6 additions & 1 deletion discovery-provider/integration_tests/utils.py
Original file line number Diff line number Diff line change
Expand Up @@ -127,6 +127,7 @@ def populate_mock_db(db, entities, block_offset=None):
track = models.Track(
blockhash=hex(i + block_offset),
blocknumber=i + block_offset,
txhash=track_meta.get("txhash", str(i + block_offset)),
track_id=track_id,
title=track_meta.get("title", f"track_{i}"),
is_current=track_meta.get("is_current", True),
Expand All @@ -146,6 +147,7 @@ def populate_mock_db(db, entities, block_offset=None):
playlist = models.Playlist(
blockhash=hex(i + block_offset),
blocknumber=i + block_offset,
txhash=playlist_meta.get("txhash", str(i + block_offset)),
playlist_id=playlist_meta.get("playlist_id", i),
is_current=playlist_meta.get("is_current", True),
is_delete=playlist_meta.get("is_delete", False),
Expand Down Expand Up @@ -173,6 +175,7 @@ def populate_mock_db(db, entities, block_offset=None):
user = models.User(
blockhash=hex(i + block_offset),
blocknumber=i + block_offset,
txhash=user_meta.get("txhash", str(i + block_offset)),
user_id=user_meta.get("user_id", i),
is_current=True,
handle=user_meta.get("handle", str(i)),
Expand Down Expand Up @@ -210,6 +213,7 @@ def populate_mock_db(db, entities, block_offset=None):
repost = models.Repost(
blockhash=hex(i + block_offset),
blocknumber=repost_meta.get("blocknumber", i + block_offset),
txhash=repost_meta.get("txhash", str(i + block_offset)),
user_id=repost_meta.get("user_id", i + 1),
repost_item_id=repost_meta.get("repost_item_id", i),
repost_type=repost_meta.get("repost_type", "track"),
Expand All @@ -222,6 +226,7 @@ def populate_mock_db(db, entities, block_offset=None):
save = models.Save(
blockhash=hex(i + block_offset),
blocknumber=save_meta.get("blocknumber", i + block_offset),
txhash=save_meta.get("txhash", str(i + block_offset)),
user_id=save_meta.get("user_id", i + 1),
save_item_id=save_meta.get("save_item_id", i),
save_type=save_meta.get("save_type", "track"),
Expand Down Expand Up @@ -318,7 +323,7 @@ def populate_mock_db(db, entities, block_offset=None):
owner_id=route_meta.get("owner_id", i + 1),
track_id=route_meta.get("track_id", i + 1),
is_current=route_meta.get("is_current", True),
txhash=route_meta.get("txhash", ""),
txhash=route_meta.get("txhash", str(i + 1)),
collision_id=route_meta.get("collision_id", 0),
)
session.add(route)
Expand Down

0 comments on commit 6deac71

Please sign in to comment.