modify sql functions
This commit is contained in:
@ -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
|
BEGIN
|
||||||
artist_name = trim(artist_name);
|
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, '%(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, '%25', '%', 'g');
|
||||||
artist_name = regexp_replace(artist_name, '%2B', '+', 'g');
|
artist_name = regexp_replace(artist_name, '%2B', '+', 'g');
|
||||||
@ -16,14 +18,12 @@ BEGIN
|
|||||||
|
|
||||||
-- check if any other url encoding still exists
|
-- check if any other url encoding still exists
|
||||||
IF regexp_count(artist_name, '%[0-9A-Fa-f]{2}') <> 0 THEN
|
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;
|
END IF;
|
||||||
|
|
||||||
artist_name = rtrim(artist_name, '-_');
|
artist_name = rtrim(artist_name, '-_');
|
||||||
|
|
||||||
-- lower has to be last, because it can and will fuck everything else up
|
|
||||||
artist_name = lower(artist_name);
|
artist_name = lower(artist_name);
|
||||||
|
|
||||||
RETURN artist_name;
|
RETURN artist_name;
|
||||||
END;
|
END;
|
||||||
$$ LANGUAGE plpgsql;
|
$$;
|
||||||
|
@ -1,20 +1,22 @@
|
|||||||
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 artist_website;
|
||||||
DROP TABLE IF EXISTS website;
|
DROP TABLE IF EXISTS website;
|
||||||
DROP TABLE IF EXISTS artist;
|
DROP TABLE IF EXISTS artist;
|
||||||
|
|
||||||
CREATE TABLE IF NOT EXISTS artist (
|
CREATE TABLE IF NOT EXISTS artist (
|
||||||
id serial PRIMARY KEY,
|
id serial PRIMARY KEY,
|
||||||
name text NOT NULL,
|
name text NOT NULL,
|
||||||
CONSTRAINT a_name UNIQUE(name)
|
CONSTRAINT a_name UNIQUE(name)
|
||||||
);
|
);
|
||||||
|
|
||||||
CREATE TABLE IF NOT EXISTS website (
|
CREATE TABLE IF NOT EXISTS website (
|
||||||
id serial PRIMARY KEY,
|
id serial PRIMARY KEY,
|
||||||
name text NOT NULL,
|
name text NOT NULL,
|
||||||
CONSTRAINT w_name UNIQUE(name)
|
CONSTRAINT w_name UNIQUE(name)
|
||||||
);
|
);
|
||||||
|
|
||||||
CREATE TABLE IF NOT EXISTS artist_website (
|
CREATE TABLE IF NOT EXISTS artist_website (
|
||||||
id serial PRIMARY KEY,
|
id serial PRIMARY KEY,
|
||||||
url text NOT NULL,
|
url text NOT NULL,
|
||||||
@ -26,4 +28,4 @@ CREATE OR REPLACE PROCEDURE create_tables() AS $$
|
|||||||
CONSTRAINT aw_artist FOREIGN KEY (artist_id) REFERENCES artist (ID),
|
CONSTRAINT aw_artist FOREIGN KEY (artist_id) REFERENCES artist (ID),
|
||||||
CONSTRAINT aw_website FOREIGN KEY (website_id) REFERENCES website (ID)
|
CONSTRAINT aw_website FOREIGN KEY (website_id) REFERENCES website (ID)
|
||||||
);
|
);
|
||||||
$$ LANGUAGE SQL;
|
$$;
|
||||||
|
24
sql/get_all_convertable_paths.sql
Normal file
24
sql/get_all_convertable_paths.sql
Normal 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;
|
||||||
|
$$;
|
@ -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
|
DECLARE
|
||||||
artist_name text;
|
artist_name text;
|
||||||
BEGIN
|
BEGIN
|
||||||
@ -17,9 +19,9 @@ BEGIN
|
|||||||
ELSIF regexp_like(in_url, 'konachan\.com') THEN
|
ELSIF regexp_like(in_url, 'konachan\.com') THEN
|
||||||
artist_name = substring(in_url from 32);
|
artist_name = substring(in_url from 32);
|
||||||
ELSE
|
ELSE
|
||||||
RAISE EXCEPTION 'Cannot extract usable artist_name from url: %', in_url;
|
RETURN NULL;
|
||||||
END IF;
|
END IF;
|
||||||
|
|
||||||
RETURN artist_name;
|
RETURN artist_name;
|
||||||
END;
|
END;
|
||||||
$$ LANGUAGE plpgsql IMMUTABLE STRICT;
|
$$;
|
||||||
|
@ -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;
|
|
@ -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
|
DECLARE
|
||||||
website_name text;
|
website_name text;
|
||||||
BEGIN
|
BEGIN
|
||||||
@ -27,9 +29,9 @@ BEGIN
|
|||||||
ELSIF regexp_like(in_url, 'fantia\.jp') THEN
|
ELSIF regexp_like(in_url, 'fantia\.jp') THEN
|
||||||
website_name = 'Fantia';
|
website_name = 'Fantia';
|
||||||
ELSE
|
ELSE
|
||||||
RAISE EXCEPTION 'Domain % is currently not supported', in_url;
|
RETURN NULL;
|
||||||
END IF;
|
END IF;
|
||||||
|
|
||||||
RETURN website_name;
|
RETURN website_name;
|
||||||
END;
|
END;
|
||||||
$$ LANGUAGE plpgsql IMMUTABLE STRICT;
|
$$;
|
||||||
|
@ -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
|
BEGIN
|
||||||
PERFORM * FROM artist_website aw
|
PERFORM * FROM artist_website aw
|
||||||
WHERE aw.url = in_url;
|
WHERE aw.url = in_url;
|
||||||
@ -9,10 +13,24 @@ BEGIN
|
|||||||
|
|
||||||
INSERT INTO artist_website (url) VALUES (in_url);
|
INSERT INTO artist_website (url) VALUES (in_url);
|
||||||
|
|
||||||
CALL set_artist_name(in_url);
|
SELECT * INTO ret_value FROM set_artist_name(in_url);
|
||||||
CALL set_website_name(in_url);
|
IF ret_value <> 0 THEN
|
||||||
CALL set_folder_path(in_url);
|
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;
|
RETURN 0;
|
||||||
END;
|
END;
|
||||||
$$ LANGUAGE plpgsql STRICT;
|
$$;
|
||||||
|
45
sql/insert_url_with_custom_artist.sql
Normal file
45
sql/insert_url_with_custom_artist.sql
Normal 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;
|
||||||
|
$$;
|
@ -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
|
DECLARE
|
||||||
temp_artist_id integer;
|
temp_artist_id integer;
|
||||||
temp_artist_name text;
|
temp_artist_name text;
|
||||||
temp_artist artist%ROWTYPE;
|
|
||||||
BEGIN
|
BEGIN
|
||||||
temp_artist_name = get_artist_name(in_url);
|
temp_artist_name = get_artist_name(in_url);
|
||||||
temp_artist_name = convert_artist_name(temp_artist_name);
|
temp_artist_name = convert_artist_name(temp_artist_name);
|
||||||
|
|
||||||
SELECT * INTO temp_artist FROM artist
|
IF temp_artist_name IS NULL THEN
|
||||||
WHERE artist.name = temp_artist_name;
|
RETURN 1;
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
PERFORM * FROM artist WHERE artist.name = temp_artist_name;
|
||||||
|
|
||||||
IF NOT FOUND THEN
|
IF NOT FOUND THEN
|
||||||
INSERT INTO artist (name) VALUES (temp_artist_name);
|
INSERT INTO artist (name) VALUES (temp_artist_name);
|
||||||
@ -19,5 +23,7 @@ BEGIN
|
|||||||
|
|
||||||
UPDATE artist_website SET artist_id = temp_artist_id
|
UPDATE artist_website SET artist_id = temp_artist_id
|
||||||
WHERE url = in_url;
|
WHERE url = in_url;
|
||||||
|
|
||||||
|
RETURN 0;
|
||||||
END;
|
END;
|
||||||
$$ LANGUAGE plpgsql;
|
$$;
|
||||||
|
@ -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
|
DECLARE
|
||||||
temp_folder_path text;
|
temp_folder_path text;
|
||||||
aw_artist_id integer;
|
aw_artist_id integer;
|
||||||
@ -9,18 +11,28 @@ BEGIN
|
|||||||
SELECT aw.artist_id INTO aw_artist_id FROM artist_website aw
|
SELECT aw.artist_id INTO aw_artist_id FROM artist_website aw
|
||||||
WHERE aw.url = in_url;
|
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
|
SELECT aw.website_id INTO aw_website_id FROM artist_website aw
|
||||||
WHERE aw.url = in_url;
|
WHERE aw.url = in_url;
|
||||||
|
|
||||||
|
IF aw_website_id IS NULL THEN
|
||||||
|
RETURN 1;
|
||||||
|
END IF;
|
||||||
|
|
||||||
SELECT artist.name INTO artist_name FROM artist
|
SELECT artist.name INTO artist_name FROM artist
|
||||||
WHERE artist.id = aw_artist_id;
|
WHERE artist.id = aw_artist_id;
|
||||||
|
|
||||||
SELECT website.name INTO website_name FROM website
|
SELECT website.name INTO website_name FROM website
|
||||||
WHERE website.id = aw_website_id;
|
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
|
UPDATE artist_website SET folder_path = temp_folder_path
|
||||||
WHERE url = in_url;
|
WHERE url = in_url;
|
||||||
|
|
||||||
|
RETURN 0;
|
||||||
END;
|
END;
|
||||||
$$ LANGUAGE plpgsql;
|
$$;
|
||||||
|
@ -1,22 +1,28 @@
|
|||||||
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
|
DECLARE
|
||||||
temp_website_id integer;
|
temp_website_id integer;
|
||||||
temp_website_name text;
|
temp_website_name text;
|
||||||
temp_website website%ROWTYPE;
|
|
||||||
BEGIN
|
BEGIN
|
||||||
temp_website_name = get_website_name(in_url);
|
temp_website_name = get_website_name(in_url);
|
||||||
|
|
||||||
SELECT * INTO temp_website FROM website
|
IF temp_website_name IS NULL THEN
|
||||||
WHERE website.name = temp_website_name;
|
RETURN 1;
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
PERFORM * FROM website WHERE website.name = temp_website_name;
|
||||||
|
|
||||||
IF NOT FOUND THEN
|
IF NOT FOUND THEN
|
||||||
INSERT INTO website (name) VALUES (temp_website_name);
|
INSERT INTO website (name) VALUES (temp_website_name);
|
||||||
END IF;
|
END IF;
|
||||||
|
|
||||||
SELECT website.id INTO temp_website_id FROM website
|
SELECT website.id INTO temp_website_id FROM website
|
||||||
WHERE website.name = temp_website_name;
|
WHERE website.name = temp_website_name;
|
||||||
|
|
||||||
UPDATE artist_website SET website_id = temp_website_id
|
UPDATE artist_website SET website_id = temp_website_id
|
||||||
WHERE url = in_url;
|
WHERE url = in_url;
|
||||||
|
|
||||||
|
RETURN 0;
|
||||||
END;
|
END;
|
||||||
$$ LANGUAGE plpgsql;
|
$$;
|
||||||
|
@ -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
|
BEGIN
|
||||||
PERFORM * FROM website w
|
PERFORM * FROM website w
|
||||||
WHERE w.name = in_website_name;
|
WHERE w.name = in_website_name;
|
||||||
@ -9,4 +11,4 @@ BEGIN
|
|||||||
RETURN 0;
|
RETURN 0;
|
||||||
END IF;
|
END IF;
|
||||||
END;
|
END;
|
||||||
$$ LANGUAGE plpgsql STRICT;
|
$$;
|
||||||
|
Reference in New Issue
Block a user