chore(*.psql): update functions; add update_artist_key.psql for merging artists flow
This commit is contained in:
parent
15982f220a
commit
678384d8d9
8 changed files with 48 additions and 19 deletions
|
@ -1,14 +1,21 @@
|
|||
CREATE OR REPLACE FUNCTION normalize_country_field(countryField TEXT)
|
||||
RETURNS TEXT AS $$
|
||||
DECLARE
|
||||
delimiters TEXT[] := ARRAY[',', '/', '&', 'and'];
|
||||
countries TEXT[];
|
||||
temp TEXT[];
|
||||
result TEXT := '';
|
||||
i INTEGER;
|
||||
BEGIN
|
||||
countries := string_to_array(countryField, ',');
|
||||
|
||||
FOR i IN 1..array_length(delimiters, 1) LOOP
|
||||
countries := array_cat(countries, string_to_array(result, delimiters[i]));
|
||||
temp := ARRAY[]::TEXT[];
|
||||
FOREACH result IN ARRAY countries LOOP
|
||||
temp := array_cat(temp, string_to_array(result, delimiters[i]));
|
||||
END LOOP;
|
||||
countries := temp;
|
||||
END LOOP;
|
||||
|
||||
result := array_to_string(countries, ' ');
|
||||
RETURN trim(result);
|
||||
END
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
|
|
@ -1,4 +1,4 @@
|
|||
CREATE OR REPLACE FUNCTION public.search_optimized_index(search_query text, page_size integer, page_offset integer, types text[])
|
||||
CREATE OR REPLACE FUNCTION search_optimized_index(search_query text, page_size integer, page_offset integer, types text[])
|
||||
RETURNS TABLE(
|
||||
result_id integer,
|
||||
url text,
|
||||
|
|
|
@ -1,4 +1,13 @@
|
|||
SELECT lower(regexp_replace(
|
||||
unaccent(regexp_replace($1, '[^\\w\\s-]', '', 'g')),
|
||||
'\\s+', '-', 'g'
|
||||
));
|
||||
CREATE OR REPLACE FUNCTION slugify(input TEXT)
|
||||
RETURNS TEXT AS $$
|
||||
BEGIN
|
||||
RETURN lower(
|
||||
regexp_replace(
|
||||
unaccent(
|
||||
regexp_replace(input, '[^\w\s-]', '', 'g')
|
||||
),
|
||||
'\s+', '-', 'g'
|
||||
)
|
||||
);
|
||||
END;
|
||||
$$ LANGUAGE plpgsql IMMUTABLE;
|
||||
|
|
|
@ -1,5 +1,8 @@
|
|||
CREATE OR REPLACE FUNCTION update_album_key(old_album_key TEXT, new_album_key TEXT)
|
||||
RETURNS void AS $$
|
||||
BEGIN
|
||||
UPDATE listens
|
||||
SET album_key = new_album_key
|
||||
WHERE album_key = old_album_key;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
|
11
queries/functions/update_artist_key.psql
Normal file
11
queries/functions/update_artist_key.psql
Normal file
|
@ -0,0 +1,11 @@
|
|||
CREATE OR REPLACE FUNCTION update_artist_name(old_artist_name TEXT, new_artist_name TEXT)
|
||||
RETURNS void AS $$
|
||||
BEGIN
|
||||
UPDATE listens
|
||||
SET artist_name = new_artist_name
|
||||
WHERE artist_name = old_artist_name;
|
||||
UPDATE albums
|
||||
SET artist_name = new_artist_name
|
||||
WHERE artist_name = old_artist_name;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
|
@ -1,6 +1,8 @@
|
|||
CREATE OR REPLACE FUNCTION update_listen_totals()
|
||||
RETURNS void AS $$
|
||||
BEGIN
|
||||
WITH artist_plays AS (
|
||||
SELECT artist_name, COUNT(*)::integer as total_plays
|
||||
SELECT artist_name, COUNT(*)::integer AS total_plays
|
||||
FROM listens
|
||||
GROUP BY artist_name
|
||||
)
|
||||
|
@ -8,9 +10,8 @@ BEGIN
|
|||
SET total_plays = COALESCE(ap.total_plays, 0)
|
||||
FROM artist_plays ap
|
||||
WHERE artists.name_string = ap.artist_name;
|
||||
|
||||
WITH album_plays AS (
|
||||
SELECT album_key, artist_name, COUNT(*)::integer as total_plays
|
||||
SELECT album_key, artist_name, COUNT(*)::integer AS total_plays
|
||||
FROM listens
|
||||
GROUP BY album_key, artist_name
|
||||
)
|
||||
|
@ -19,9 +20,8 @@ BEGIN
|
|||
FROM album_plays ap
|
||||
WHERE albums.key = ap.album_key
|
||||
AND albums.artist_name = ap.artist_name;
|
||||
|
||||
WITH genre_plays AS (
|
||||
SELECT g.id, COUNT(*)::integer as total_plays
|
||||
SELECT g.id, COUNT(*)::integer AS total_plays
|
||||
FROM listens l
|
||||
JOIN artists a ON l.artist_name = a.name_string
|
||||
JOIN genres g ON a.genres::text = g.id::text
|
||||
|
@ -31,6 +31,5 @@ BEGIN
|
|||
SET total_plays = COALESCE(gp.total_plays, 0)
|
||||
FROM genre_plays gp
|
||||
WHERE genres.id = gp.id;
|
||||
|
||||
RAISE NOTICE 'All listen totals are up to date';
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
|
Loading…
Add table
Add a link
Reference in a new issue