chore(*.psql): update functions; add update_artist_key.psql for merging artists flow

This commit is contained in:
Cory Dransfeldt 2025-04-18 19:51:33 -07:00
parent 15982f220a
commit 678384d8d9
No known key found for this signature in database
8 changed files with 48 additions and 19 deletions

4
package-lock.json generated
View file

@ -1,12 +1,12 @@
{ {
"name": "coryd.dev", "name": "coryd.dev",
"version": "2.0.2", "version": "2.1.2",
"lockfileVersion": 3, "lockfileVersion": 3,
"requires": true, "requires": true,
"packages": { "packages": {
"": { "": {
"name": "coryd.dev", "name": "coryd.dev",
"version": "2.0.2", "version": "2.1.2",
"license": "MIT", "license": "MIT",
"dependencies": { "dependencies": {
"html-minifier-terser": "7.2.0", "html-minifier-terser": "7.2.0",

View file

@ -1,6 +1,6 @@
{ {
"name": "coryd.dev", "name": "coryd.dev",
"version": "2.0.2", "version": "2.1.2",
"description": "The source for my personal site. Built using 11ty (and other tools).", "description": "The source for my personal site. Built using 11ty (and other tools).",
"type": "module", "type": "module",
"engines": { "engines": {

View file

@ -1,14 +1,21 @@
CREATE OR REPLACE FUNCTION normalize_country_field(countryField TEXT)
RETURNS TEXT AS $$
DECLARE DECLARE
delimiters TEXT[] := ARRAY[',', '/', '&', 'and']; delimiters TEXT[] := ARRAY[',', '/', '&', 'and'];
countries TEXT[]; countries TEXT[];
temp TEXT[];
result TEXT := ''; result TEXT := '';
i INTEGER;
BEGIN BEGIN
countries := string_to_array(countryField, ','); countries := string_to_array(countryField, ',');
FOR i IN 1..array_length(delimiters, 1) LOOP 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; END LOOP;
result := array_to_string(countries, ' '); result := array_to_string(countries, ' ');
RETURN trim(result); RETURN trim(result);
END END;
$$ LANGUAGE plpgsql;

View file

@ -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( RETURNS TABLE(
result_id integer, result_id integer,
url text, url text,

View file

@ -1,4 +1,13 @@
SELECT lower(regexp_replace( CREATE OR REPLACE FUNCTION slugify(input TEXT)
unaccent(regexp_replace($1, '[^\\w\\s-]', '', 'g')), RETURNS TEXT AS $$
'\\s+', '-', 'g' BEGIN
)); RETURN lower(
regexp_replace(
unaccent(
regexp_replace(input, '[^\w\s-]', '', 'g')
),
'\s+', '-', 'g'
)
);
END;
$$ LANGUAGE plpgsql IMMUTABLE;

View file

@ -1,5 +1,8 @@
CREATE OR REPLACE FUNCTION update_album_key(old_album_key TEXT, new_album_key TEXT)
RETURNS void AS $$
BEGIN BEGIN
UPDATE listens UPDATE listens
SET album_key = new_album_key SET album_key = new_album_key
WHERE album_key = old_album_key; WHERE album_key = old_album_key;
END; END;
$$ LANGUAGE plpgsql;

View 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;

View file

@ -1,6 +1,8 @@
CREATE OR REPLACE FUNCTION update_listen_totals()
RETURNS void AS $$
BEGIN BEGIN
WITH artist_plays AS ( WITH artist_plays AS (
SELECT artist_name, COUNT(*)::integer as total_plays SELECT artist_name, COUNT(*)::integer AS total_plays
FROM listens FROM listens
GROUP BY artist_name GROUP BY artist_name
) )
@ -8,9 +10,8 @@ BEGIN
SET total_plays = COALESCE(ap.total_plays, 0) SET total_plays = COALESCE(ap.total_plays, 0)
FROM artist_plays ap FROM artist_plays ap
WHERE artists.name_string = ap.artist_name; WHERE artists.name_string = ap.artist_name;
WITH album_plays AS ( 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 FROM listens
GROUP BY album_key, artist_name GROUP BY album_key, artist_name
) )
@ -19,9 +20,8 @@ BEGIN
FROM album_plays ap FROM album_plays ap
WHERE albums.key = ap.album_key WHERE albums.key = ap.album_key
AND albums.artist_name = ap.artist_name; AND albums.artist_name = ap.artist_name;
WITH genre_plays AS ( WITH genre_plays AS (
SELECT g.id, COUNT(*)::integer as total_plays SELECT g.id, COUNT(*)::integer AS total_plays
FROM listens l FROM listens l
JOIN artists a ON l.artist_name = a.name_string JOIN artists a ON l.artist_name = a.name_string
JOIN genres g ON a.genres::text = g.id::text JOIN genres g ON a.genres::text = g.id::text
@ -31,6 +31,5 @@ BEGIN
SET total_plays = COALESCE(gp.total_plays, 0) SET total_plays = COALESCE(gp.total_plays, 0)
FROM genre_plays gp FROM genre_plays gp
WHERE genres.id = gp.id; WHERE genres.id = gp.id;
RAISE NOTICE 'All listen totals are up to date';
END; END;
$$ LANGUAGE plpgsql;