modify sql functions

This commit is contained in:
2024-11-11 20:20:49 +01:00
parent e5a7906cdf
commit 9af2a9408c
12 changed files with 159 additions and 59 deletions

View File

@ -1,8 +1,10 @@
CREATE OR REPLACE FUNCTION convert_artist_name(artist_name text) RETURNS text AS $$
CREATE OR REPLACE FUNCTION public.convert_artist_name(artist_name text) RETURNS text
LANGUAGE plpgsql IMMUTABLE STRICT
AS $$
BEGIN
artist_name = trim(artist_name);
-- partially deal with url encoding
-- only partially deal with url encoding
artist_name = regexp_replace(artist_name, '%(20|21|22|23|24|26|27|28|29|2A|2C|2E|2F|3B|3C|3E|3F|5B|5C|5D|5E|60|7B|7C|7D|7E)|artist', '', 'g');
artist_name = regexp_replace(artist_name, '%25', '%', 'g');
artist_name = regexp_replace(artist_name, '%2B', '+', 'g');
@ -16,14 +18,12 @@ BEGIN
-- check if any other url encoding still exists
IF regexp_count(artist_name, '%[0-9A-Fa-f]{2}') <> 0 THEN
RAISE EXCEPTION 'Artist % contains unconvertable percent-encoded Unicode', artist_name;
RETURN NULL;
END IF;
artist_name = rtrim(artist_name, '-_');
-- lower has to be last, because it can and will fuck everything else up
artist_name = lower(artist_name);
RETURN artist_name;
END;
$$ LANGUAGE plpgsql;
$$;

View File

@ -1,4 +1,6 @@
CREATE OR REPLACE PROCEDURE create_tables() AS $$
CREATE OR REPLACE PROCEDURE public.create_tables()
LANGUAGE SQL
AS $$
DROP TABLE IF EXISTS artist_website;
DROP TABLE IF EXISTS website;
DROP TABLE IF EXISTS artist;
@ -26,4 +28,4 @@ CREATE OR REPLACE PROCEDURE create_tables() AS $$
CONSTRAINT aw_artist FOREIGN KEY (artist_id) REFERENCES artist (ID),
CONSTRAINT aw_website FOREIGN KEY (website_id) REFERENCES website (ID)
);
$$ LANGUAGE SQL;
$$;

View File

@ -0,0 +1,24 @@
CREATE OR REPLACE FUNCTION public.get_all_convertable_paths() RETURNS Table (bad_path text, good_path text)
LANGUAGE plpgsql STRICT
AS $$
DECLARE
url text;
artist_name text;
temp_bad_path text;
temp_good_path text;
BEGIN
FOR url IN
SELECT aw.url FROM artist_website aw
LOOP
artist_name = get_artist_name(url);
temp_bad_path = concat('Artists/', artist_name);
temp_good_path = concat('Artists/', convert_artist_name(artist_name));
PERFORM * FROM artist WHERE artist.name = artist_name;
IF NOT FOUND THEN
RETURN QUERY SELECT temp_bad_path,temp_good_path;
END IF;
END LOOP;
END;
$$;

View File

@ -1,4 +1,6 @@
CREATE OR REPLACE FUNCTION get_artist_name(in_url text) RETURNS text AS $$
CREATE OR REPLACE FUNCTION public.get_artist_name(in_url text) RETURNS text
LANGUAGE plpgsql IMMUTABLE STRICT
AS $$
DECLARE
artist_name text;
BEGIN
@ -17,9 +19,9 @@ BEGIN
ELSIF regexp_like(in_url, 'konachan\.com') THEN
artist_name = substring(in_url from 32);
ELSE
RAISE EXCEPTION 'Cannot extract usable artist_name from url: %', in_url;
RETURN NULL;
END IF;
RETURN artist_name;
END;
$$ LANGUAGE plpgsql IMMUTABLE STRICT;
$$;

View File

@ -1,19 +0,0 @@
CREATE OR REPLACE FUNCTION get_urls_and_paths(website_name text)
RETURNS TABLE (
out_url text,
out_website_name text
) AS
$$
BEGIN
RETURN QUERY SELECT aw.url, aw.folder_path
FROM artist_website aw
INNER JOIN website w ON aw.website_id = w.id
WHERE w.name ILIKE website_name;
IF NOT FOUND THEN
RAISE EXCEPTION 'No urls and paths found for website: %', website_name;
END IF;
RETURN;
END;
$$ LANGUAGE plpgsql;

View File

@ -1,4 +1,6 @@
CREATE OR REPLACE FUNCTION get_website_name(in_url text) RETURNS text AS $$
CREATE OR REPLACE FUNCTION public.get_website_name(in_url text) RETURNS text
LANGUAGE plpgsql IMMUTABLE STRICT
AS $$
DECLARE
website_name text;
BEGIN
@ -27,9 +29,9 @@ BEGIN
ELSIF regexp_like(in_url, 'fantia\.jp') THEN
website_name = 'Fantia';
ELSE
RAISE EXCEPTION 'Domain % is currently not supported', in_url;
RETURN NULL;
END IF;
RETURN website_name;
END;
$$ LANGUAGE plpgsql IMMUTABLE STRICT;
$$;

View File

@ -1,4 +1,8 @@
CREATE OR REPLACE FUNCTION insert_url(in_url text) RETURNS integer AS $$
CREATE OR REPLACE FUNCTION public.insert_url(in_url text) RETURNS integer
LANGUAGE plpgsql STRICT
AS $$
DECLARE
ret_value integer;
BEGIN
PERFORM * FROM artist_website aw
WHERE aw.url = in_url;
@ -9,10 +13,24 @@ BEGIN
INSERT INTO artist_website (url) VALUES (in_url);
CALL set_artist_name(in_url);
CALL set_website_name(in_url);
CALL set_folder_path(in_url);
SELECT * INTO ret_value FROM set_artist_name(in_url);
IF ret_value <> 0 THEN
DELETE FROM artist_website WHERE url = in_url;
RETURN 1;
END IF;
SELECT * INTO ret_value FROM set_website_name(in_url);
IF ret_value <> 0 THEN
DELETE FROM artist_website WHERE url = in_url;
RETURN 1;
END IF;
SELECT * INTO ret_value FROM set_folder_path(in_url);
IF ret_value <> 0 THEN
DELETE FROM artist_website WHERE url = in_url;
RETURN 1;
END IF;
RETURN 0;
END;
$$ LANGUAGE plpgsql STRICT;
$$;

View File

@ -0,0 +1,45 @@
CREATE OR REPLACE FUNCTION public.insert_url_with_custom_artist(in_url text, in_artist_name text) RETURNS integer
LANGUAGE plpgsql STRICT
AS $$
DECLARE
ret_value integer;
temp_artist_id integer;
BEGIN
PERFORM * FROM artist_website aw
WHERE aw.url = in_url;
IF FOUND THEN
RETURN 1;
END IF;
PERFORM * FROM artist a
WHERE a.name = in_artist_name;
IF FOUND THEN
RETURN 1;
END IF;
INSERT INTO artist_website (url) VALUES (in_url);
INSERT INTO artist (name) VALUES (in_artist_name);
SELECT artist.id INTO temp_artist_id FROM artist
WHERE artist.name = in_artist_name;
UPDATE artist_website SET artist_id = temp_artist_id
WHERE url = in_url;
SELECT * INTO ret_value FROM set_website_name(in_url);
IF ret_value <> 0 THEN
DELETE FROM artist_website WHERE url = in_url;
RETURN 1;
END IF;
SELECT * INTO ret_value FROM set_folder_path(in_url);
IF ret_value <> 0 THEN
DELETE FROM artist_website WHERE url = in_url;
RETURN 1;
END IF;
RETURN 0;
END;
$$;

View File

@ -1,14 +1,18 @@
CREATE OR REPLACE PROCEDURE set_artist_name(in_url text) AS $$
CREATE OR REPLACE FUNCTION public.set_artist_name(in_url text) RETURNS integer
LANGUAGE plpgsql STRICT
AS $$
DECLARE
temp_artist_id integer;
temp_artist_name text;
temp_artist artist%ROWTYPE;
BEGIN
temp_artist_name = get_artist_name(in_url);
temp_artist_name = convert_artist_name(temp_artist_name);
SELECT * INTO temp_artist FROM artist
WHERE artist.name = temp_artist_name;
IF temp_artist_name IS NULL THEN
RETURN 1;
END IF;
PERFORM * FROM artist WHERE artist.name = temp_artist_name;
IF NOT FOUND THEN
INSERT INTO artist (name) VALUES (temp_artist_name);
@ -19,5 +23,7 @@ BEGIN
UPDATE artist_website SET artist_id = temp_artist_id
WHERE url = in_url;
RETURN 0;
END;
$$ LANGUAGE plpgsql;
$$;

View File

@ -1,4 +1,6 @@
CREATE OR REPLACE PROCEDURE set_folder_path(in_url text) AS $$
CREATE OR REPLACE FUNCTION public.set_folder_path(in_url text) RETURNS integer
LANGUAGE plpgsql STRICT
AS $$
DECLARE
temp_folder_path text;
aw_artist_id integer;
@ -9,18 +11,28 @@ BEGIN
SELECT aw.artist_id INTO aw_artist_id FROM artist_website aw
WHERE aw.url = in_url;
IF aw_artist_id IS NULL THEN
RETURN 1;
END IF;
SELECT aw.website_id INTO aw_website_id FROM artist_website aw
WHERE aw.url = in_url;
IF aw_website_id IS NULL THEN
RETURN 1;
END IF;
SELECT artist.name INTO artist_name FROM artist
WHERE artist.id = aw_artist_id;
SELECT website.name INTO website_name FROM website
WHERE website.id = aw_website_id;
temp_folder_path = concat('Artist/', artist_name, '/', website_name);
temp_folder_path = concat('Artists/', artist_name, '/', website_name);
UPDATE artist_website SET folder_path = temp_folder_path
WHERE url = in_url;
RETURN 0;
END;
$$ LANGUAGE plpgsql;
$$;

View File

@ -1,13 +1,17 @@
CREATE OR REPLACE PROCEDURE set_website_name(in_url text) AS $$
CREATE OR REPLACE FUNCTION public.set_website_name(in_url text) RETURNS integer
LANGUAGE plpgsql STRICT
AS $$
DECLARE
temp_website_id integer;
temp_website_name text;
temp_website website%ROWTYPE;
BEGIN
temp_website_name = get_website_name(in_url);
SELECT * INTO temp_website FROM website
WHERE website.name = temp_website_name;
IF temp_website_name IS NULL THEN
RETURN 1;
END IF;
PERFORM * FROM website WHERE website.name = temp_website_name;
IF NOT FOUND THEN
INSERT INTO website (name) VALUES (temp_website_name);
@ -18,5 +22,7 @@ BEGIN
UPDATE artist_website SET website_id = temp_website_id
WHERE url = in_url;
RETURN 0;
END;
$$ LANGUAGE plpgsql;
$$;

View File

@ -1,4 +1,6 @@
CREATE OR REPLACE FUNCTION website_exists(in_website_name text) RETURNS boolean AS $$
CREATE OR REPLACE FUNCTION public.website_exists(in_website_name text) RETURNS boolean
LANGUAGE plpgsql STRICT
AS $$
BEGIN
PERFORM * FROM website w
WHERE w.name = in_website_name;
@ -9,4 +11,4 @@ BEGIN
RETURN 0;
END IF;
END;
$$ LANGUAGE plpgsql STRICT;
$$;