-
Notifications
You must be signed in to change notification settings - Fork 111
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
Browse files
Browse the repository at this point in the history
Co-authored-by: Saliou Diallo <saliou@audius.co>
- Loading branch information
Showing
1 changed file
with
67 additions
and
0 deletions.
There are no files selected for viewing
67 changes: 67 additions & 0 deletions
67
packages/discovery-provider/ddl/migrations/0052_update_non_existing_orig_filenames.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,67 @@ | ||
begin; | ||
|
||
-- disable triggers | ||
alter table tracks disable trigger on_track; | ||
alter table tracks disable trigger trg_tracks; | ||
|
||
-- orig_filename for non-stems i.e. full/parent tracks | ||
update tracks t | ||
set orig_filename = concat(title, ' - [', u.name, '].mp3') | ||
from ( | ||
select user_id, name from users | ||
where is_current is true | ||
) as u | ||
where t.is_current is true | ||
and t.owner_id = u.user_id | ||
and t.stem_of is null | ||
and t.orig_filename is null; | ||
|
||
-- orig_file_cid for non-stems i.e. full/parent tracks | ||
update tracks | ||
set orig_file_cid = track_cid | ||
where is_current is true | ||
and stem_of is null | ||
and orig_file_cid is null; | ||
|
||
-- orig_filename for stems | ||
update tracks tr | ||
set orig_filename = concat( | ||
sub.parent_title, | ||
' - ', | ||
initcap((sub.stem_of->>'category')::text), | ||
case when sub.row_num > 1 then concat(' ', sub.row_num) else '' end, | ||
'.mp3' | ||
) | ||
from ( | ||
select | ||
t.stem_of, | ||
t.track_id, | ||
title_tracks.title as parent_title, | ||
title_tracks.track_id as parent_track_id, | ||
row_number() over(partition by title_tracks.track_id, t.stem_of order by t.track_id) as row_num | ||
from tracks t | ||
join ( | ||
select track_id, title from tracks | ||
where is_current is true | ||
and stem_of is null | ||
) as title_tracks | ||
on (t.stem_of->>'parent_track_id')::int = title_tracks.track_id | ||
where t.is_current is true | ||
and (t.stem_of->>'category')::text != '' | ||
and t.orig_filename is null | ||
) as sub | ||
where tr.is_current is true | ||
and tr.track_id = sub.track_id; | ||
|
||
-- orig_file_cid for stems | ||
update tracks | ||
set orig_file_cid = track_cid | ||
where is_current is true | ||
and (stem_of->>'category')::text != '' | ||
and orig_file_cid is null; | ||
|
||
-- re-enable triggers | ||
alter table tracks enable trigger on_track; | ||
alter table tracks enable trigger trg_tracks; | ||
|
||
commit; |