From 5173eeb8b00fd9ab7c0d347c9e361052023faebd Mon Sep 17 00:00:00 2001 From: Astro Date: Sun, 24 Dec 2017 02:18:17 +0100 Subject: [PATCH] SQL: remove tracker --- pg_downloads.sql | 52 +------------- pg_install.sql | 1 - pg_search.sql | 3 - pg_stats.sql | 28 -------- pg_tracker.sql | 184 ----------------------------------------------- 5 files changed, 2 insertions(+), 266 deletions(-) delete mode 100644 pg_tracker.sql diff --git a/pg_downloads.sql b/pg_downloads.sql index 4dbd34c..918cb5a 100644 --- a/pg_downloads.sql +++ b/pg_downloads.sql @@ -40,36 +40,8 @@ CREATE TYPE download AS ( "downloaded" BIGINT ); -CREATE OR REPLACE FUNCTION get_popular_downloads( - INT, INT -) RETURNS SETOF download AS $$ - SELECT * - FROM (SELECT user_feeds."user", user_feeds."slug", user_feeds."feed", - enclosures.item, enclosures.url AS enclosure, - COALESCE(user_feeds.title, feeds.title) AS feed_title, user_feeds."public" AS feed_public, - torrents.info_hash, torrents.name, torrents.size, enclosures.type, - feed_items.title, feed_items.lang, feed_items.summary, feed_items.published, feed_items.homepage, feed_items.payment, feed_items.image, - COALESCE(scraped.seeders, 0) AS "seeders", COALESCE(scraped.leechers, 0) AS "leechers", - COALESCE(scraped.upspeed, 0) AS "upspeed", COALESCE(scraped.downspeed, 0) AS "downspeed", - COALESCE(downloaded_stats.downloaded, 0) AS "downloaded" - FROM (SELECT info_hash, seeders, leechers, upspeed, downspeed - FROM scraped - ORDER BY (seeders + leechers) DESC - LIMIT $1 OFFSET $2 - ) AS scraped - JOIN torrents USING (info_hash) - JOIN downloaded_stats USING (info_hash) - JOIN enclosure_torrents ON (scraped.info_hash=enclosure_torrents.info_hash AND LENGTH(enclosure_torrents.info_hash)=20) - JOIN enclosures USING (url) - JOIN feed_items ON (enclosures.feed=feed_items.feed AND enclosures.item=feed_items.id) - JOIN feeds ON (feed_items.feed=feeds.url) - JOIN user_feeds ON (feed_items.feed=user_feeds.feed) - WHERE user_feeds."public" - ) AS s - ORDER BY (seeders + leechers) DESC, downloaded DESC; -$$ LANGUAGE SQL; - +-- TODO: rm dups CREATE OR REPLACE FUNCTION get_most_downloaded( INT, INT, INT ) RETURNS SETOF download AS $$ @@ -78,8 +50,6 @@ CREATE OR REPLACE FUNCTION get_most_downloaded( COALESCE(user_feeds.title, feeds.title) AS feed_title, user_feeds."public" AS feed_public, torrents.info_hash, torrents.name, torrents.size, enclosures.type, feed_items.title, feed_items.lang, feed_items.summary, feed_items.published, feed_items.homepage, feed_items.payment, feed_items.image, - COALESCE(scraped.seeders, 0) AS "seeders", COALESCE(scraped.leechers, 0) AS "leechers", - COALESCE(scraped.upspeed, 0) AS "upspeed", COALESCE(scraped.downspeed, 0) AS "downspeed", COALESCE(downloaded_stats.downloaded, 0) AS "downloaded" FROM (SELECT info_hash, downloaded FROM downloaded_stats @@ -96,7 +66,6 @@ CREATE OR REPLACE FUNCTION get_most_downloaded( JOIN feed_items ON (enclosures.feed=feed_items.feed AND enclosures.item=feed_items.id) JOIN feeds ON (feed_items.feed=feeds.url) JOIN user_feeds ON (feed_items.feed=user_feeds.feed) - LEFT JOIN scraped USING (info_hash) WHERE user_feeds."public"; $$ LANGUAGE SQL; @@ -110,9 +79,7 @@ CREATE OR REPLACE FUNCTION get_torrent_download( COALESCE(user_feeds.title, feeds.title) AS feed_title, user_feeds."public" AS feed_public, torrents.info_hash, torrents.name, torrents.size, enclosures.type, feed_items.title, feed_items.lang, feed_items.summary, feed_items.published, feed_items.homepage, feed_items.payment, feed_items.image, - -- TODO: delete this - 0 as "seeders", 0 as "leechers", 0 :: bigint as "upspeed", 0 :: bigint as "downspeed", - COALESCE(downloaded_stats.downloaded :: bigint, 0) :: bigint AS "downloaded" + COALESCE(downloaded_stats.downloaded, 0) AS "downloaded" FROM torrents LEFT JOIN downloaded_stats USING (info_hash) JOIN enclosure_torrents USING (info_hash) @@ -136,8 +103,6 @@ CREATE OR REPLACE FUNCTION get_recent_downloads( COALESCE(user_feeds.title, feeds.title) AS feed_title, user_feeds."public" AS feed_public, torrents.info_hash, torrents.name, torrents.size, enclosures.type, feed_items.title, feed_items.lang, feed_items.summary, feed_items.published, feed_items.homepage, feed_items.payment, feed_items.image, - COALESCE(scraped.seeders, 0) AS "seeders", COALESCE(scraped.leechers, 0) AS "leechers", - COALESCE(scraped.upspeed, 0) AS "upspeed", COALESCE(scraped.downspeed, 0) AS "downspeed", COALESCE(downloaded_stats.downloaded, 0) AS "downloaded" FROM (SELECT feed, id, title, lang, summary, published, homepage, payment, image FROM feed_items @@ -149,7 +114,6 @@ CREATE OR REPLACE FUNCTION get_recent_downloads( JOIN torrents ON (enclosure_torrents.info_hash=torrents.info_hash) JOIN feeds ON (feed_items.feed=feeds.url) JOIN user_feeds ON (feed_items.feed=user_feeds.feed) - LEFT JOIN scraped ON (enclosure_torrents.info_hash=scraped.info_hash) LEFT JOIN downloaded_stats ON (enclosure_torrents.info_hash=downloaded_stats.info_hash) WHERE user_feeds."public" ) AS s @@ -165,8 +129,6 @@ CREATE OR REPLACE FUNCTION get_recent_downloads( COALESCE(user_feeds.title, feeds.title) AS feed_title, user_feeds."public" AS feed_public, torrents.info_hash, torrents.name, torrents.size, enclosures.type, feed_items.title, feed_items.lang, feed_items.summary, feed_items.published, feed_items.homepage, feed_items.payment, feed_items.image, - COALESCE(scraped.seeders, 0) AS "seeders", COALESCE(scraped.leechers, 0) AS "leechers", - COALESCE(scraped.upspeed, 0) AS "upspeed", COALESCE(scraped.downspeed, 0) AS "downspeed", COALESCE(downloaded_stats.downloaded, 0) AS "downloaded" FROM (SELECT feed, id, title, lang, summary, published, homepage, payment, image FROM feed_items @@ -179,7 +141,6 @@ CREATE OR REPLACE FUNCTION get_recent_downloads( JOIN torrents ON (enclosure_torrents.info_hash=torrents.info_hash) JOIN feeds ON (feed_items.feed=feeds.url) JOIN user_feeds ON (feed_items.feed=user_feeds.feed) - LEFT JOIN scraped ON (enclosure_torrents.info_hash=scraped.info_hash) LEFT JOIN downloaded_stats ON (enclosure_torrents.info_hash=downloaded_stats.info_hash) ) AS s ORDER BY published DESC; @@ -194,8 +155,6 @@ CREATE OR REPLACE FUNCTION get_user_recent_downloads( COALESCE(user_feeds.title, feeds.title) AS feed_title, user_feeds."public" AS feed_public, torrents.info_hash, torrents.name, torrents.size, enclosures.type, feed_items.title, feed_items.lang, feed_items.summary, feed_items.published, feed_items.homepage, feed_items.payment, feed_items.image, - COALESCE(scraped.seeders, 0) AS "seeders", COALESCE(scraped.leechers, 0) AS "leechers", - COALESCE(scraped.upspeed, 0) AS "upspeed", COALESCE(scraped.downspeed, 0) AS "downspeed", COALESCE(downloaded_stats.downloaded, 0) AS "downloaded" FROM (SELECT feed, id, title, lang, summary, published, homepage, payment, image FROM feed_items @@ -208,7 +167,6 @@ CREATE OR REPLACE FUNCTION get_user_recent_downloads( JOIN torrents ON (enclosure_torrents.info_hash=torrents.info_hash) JOIN feeds ON (feed_items.feed=feeds.url) JOIN user_feeds ON (feed_items.feed=user_feeds.feed) - LEFT JOIN scraped ON (enclosure_torrents.info_hash=scraped.info_hash) LEFT JOIN downloaded_stats ON (enclosure_torrents.info_hash=downloaded_stats.info_hash) WHERE user_feeds."public" ) AS s @@ -223,8 +181,6 @@ CREATE OR REPLACE FUNCTION get_enclosure_downloads( COALESCE(user_feeds.title, feeds.title) AS feed_title, user_feeds."public" AS feed_public, torrents.info_hash, torrents.name, torrents.size, enclosures.type, feed_items.title, feed_items.lang, feed_items.summary, feed_items.published, feed_items.homepage, feed_items.payment, feed_items.image, - COALESCE(scraped.seeders, 0) AS "seeders", COALESCE(scraped.leechers, 0) AS "leechers", - COALESCE(scraped.upspeed, 0) AS "upspeed", COALESCE(scraped.downspeed, 0) AS "downspeed", COALESCE(downloaded_stats.downloaded, 0) AS "downloaded" FROM (SELECT url, info_hash FROM enclosure_torrents WHERE url=$1 AND LENGTH(info_hash)=20 @@ -234,7 +190,6 @@ CREATE OR REPLACE FUNCTION get_enclosure_downloads( JOIN feed_items ON (enclosures.feed=feed_items.feed AND enclosures.item=feed_items.id) JOIN feeds ON (feed_items.feed=feeds.url) JOIN user_feeds ON (feed_items.feed=user_feeds.feed) - LEFT JOIN scraped ON (enclosure_torrents.info_hash=scraped.info_hash) LEFT JOIN downloaded_stats ON (enclosure_torrents.info_hash=downloaded_stats.info_hash); $$ LANGUAGE SQL; @@ -246,8 +201,6 @@ CREATE OR REPLACE FUNCTION get_guid_downloads( COALESCE(user_feeds.title, feeds.title) AS feed_title, user_feeds."public" AS feed_public, torrents.info_hash, torrents.name, torrents.size, enclosures.type, feed_items.title, feed_items.lang, feed_items.summary, feed_items.published, feed_items.homepage, feed_items.payment, feed_items.image, - COALESCE(scraped.seeders, 0) AS "seeders", COALESCE(scraped.leechers, 0) AS "leechers", - COALESCE(scraped.upspeed, 0) AS "upspeed", COALESCE(scraped.downspeed, 0) AS "downspeed", COALESCE(downloaded_stats.downloaded, 0) AS "downloaded" FROM (SELECT feed, item, url, type FROM enclosures WHERE guid=$1 @@ -257,7 +210,6 @@ CREATE OR REPLACE FUNCTION get_guid_downloads( JOIN feed_items ON (enclosures.feed=feed_items.feed AND enclosures.item=feed_items.id) JOIN feeds ON (feed_items.feed=feeds.url) JOIN user_feeds ON (feed_items.feed=user_feeds.feed) - LEFT JOIN scraped ON (enclosure_torrents.info_hash=scraped.info_hash) LEFT JOIN downloaded_stats ON (enclosure_torrents.info_hash=downloaded_stats.info_hash) WHERE LENGTH(enclosure_torrents.info_hash)=20; $$ LANGUAGE SQL; diff --git a/pg_install.sql b/pg_install.sql index cd3a466..b94afd3 100644 --- a/pg_install.sql +++ b/pg_install.sql @@ -2,7 +2,6 @@ SET default_tablespace = safe; \i pg_meta.sql SET default_tablespace = fast; \i pg_var.sql -\i pg_tracker.sql \i pg_downloads.sql \i pg_stats.sql \i pg_search.sql diff --git a/pg_search.sql b/pg_search.sql index a89552a..ddba03c 100644 --- a/pg_search.sql +++ b/pg_search.sql @@ -99,8 +99,6 @@ CREATE OR REPLACE FUNCTION search_feed_items( COALESCE(user_feeds.title, feeds.title) AS feed_title, user_feeds."public" AS feed_public, torrents.info_hash, torrents.name, torrents.size, enclosures.type, feed_items.title, feed_items.lang, feed_items.summary, feed_items.published, feed_items.homepage, feed_items.payment, feed_items.image, - COALESCE(scraped.seeders, 0) AS "seeders", COALESCE(scraped.leechers, 0) AS "leechers", - COALESCE(scraped.upspeed, 0) AS "upspeed", COALESCE(scraped.downspeed, 0) AS "downspeed", COALESCE(downloaded_stats.downloaded, 0) AS "downloaded" FROM (SELECT * FROM feed_items WHERE "search" @@ "query" @@ -112,7 +110,6 @@ CREATE OR REPLACE FUNCTION search_feed_items( JOIN enclosures ON (enclosures.feed=feed_items.feed AND enclosures.item=feed_items.id) JOIN enclosure_torrents ON (enclosure_torrents.url=enclosures.url) JOIN torrents USING (info_hash) - LEFT JOIN scraped ON (enclosure_torrents.info_hash=scraped.info_hash) LEFT JOIN downloaded_stats ON (enclosure_torrents.info_hash=downloaded_stats.info_hash) WHERE user_feeds."public"; END; diff --git a/pg_stats.sql b/pg_stats.sql index 19dcb0a..8ec56ff 100644 --- a/pg_stats.sql +++ b/pg_stats.sql @@ -34,34 +34,6 @@ CREATE OR REPLACE FUNCTION set_gauge( $$ LANGUAGE plpgsql; -CREATE OR REPLACE FUNCTION scraped_set_gauges() RETURNS trigger AS $$ - DECLARE - s_info_hash BYTEA; - s_seeders INT; - s_leechers INT; - BEGIN - IF TG_OP != 'DELETE' THEN - s_info_hash := NEW.info_hash; - s_seeders := NEW.seeders; - s_leechers := NEW.leechers; - ELSE - s_info_hash := OLD.info_hash; - s_seeders := 0; - s_leechers := 0; - END IF; - - PERFORM set_gauge('seeders', s_info_hash, s_seeders); - PERFORM set_gauge('leechers', s_info_hash, s_leechers); - - RETURN NEW; - END; -$$ LANGUAGE plpgsql; - --- Obtain up/down deltas when a tracked peer is updated -CREATE TRIGGER scraped_set_gauges AFTER INSERT OR UPDATE OR DELETE ON scraped - FOR EACH ROW EXECUTE PROCEDURE scraped_set_gauges(); - - -- Counters -- -- For adding values (up, down, up_seeder) diff --git a/pg_tracker.sql b/pg_tracker.sql deleted file mode 100644 index 5703625..0000000 --- a/pg_tracker.sql +++ /dev/null @@ -1,184 +0,0 @@ --- fkey ensures we only track for known torrents: -CREATE TABLE tracked ("info_hash" BYTEA NOT NULL REFERENCES torrents("info_hash") ON DELETE CASCADE, - "peer_id" BYTEA NOT NULL, - "host" BYTEA NOT NULL, - "port" INT NOT NULL, - "uploaded" BIGINT, - "downloaded" BIGINT, - "downspeed" BIGINT, - "upspeed" BIGINT, - "left" BIGINT, - "last_request" TIMESTAMP NOT NULL, - "completed" BOOL, - PRIMARY KEY ("info_hash", "peer_id") - ); - --- For leechers: -CREATE OR REPLACE VIEW tracker AS - SELECT "info_hash", "peer_id", "host", "port" - FROM tracked - ORDER BY "left" ASC, "last_request" DESC; - --- For seeders: -CREATE OR REPLACE VIEW tracker_leechers AS - SELECT "info_hash", "peer_id", "host", "port" - FROM tracked - WHERE "left">0 - ORDER BY "left" ASC, "last_request" DESC; - -CREATE OR REPLACE FUNCTION set_peer( - "p_info_hash" BYTEA, "p_host" BYTEA, "p_port" INT, "p_peer_id" BYTEA, - "p_uploaded" BIGINT, "p_downloaded" BIGINT, "p_left" BIGINT, - "p_event" TEXT, - OUT "up" BIGINT, OUT "down" BIGINT - ) RETURNS RECORD AS $$ - DECLARE - "old" RECORD; - "old_age" FLOAT; - "p_upspeed" BIGINT := 0; - "p_downspeed" BIGINT := 0; - "p_completed" BOOL; - BEGIN - SELECT * INTO "old" - FROM tracked - WHERE "info_hash"="p_info_hash" AND "peer_id"="p_peer_id" - FOR UPDATE; - IF "old" IS NULL THEN - p_completed := "p_event" = 'completed'; - BEGIN - -- No concurrent data change - INSERT INTO tracked ("info_hash", "peer_id", "host", "port", - "uploaded", "downloaded", "left", "last_request", "completed") - VALUES ("p_info_hash", "p_peer_id", "p_host", "p_port", - "p_uploaded", "p_downloaded", "p_left", - now(), "p_completed"); - IF "p_event" = 'completed' THEN - PERFORM add_counter('complete', "p_info_hash", 1); - END IF; - EXCEPTION - WHEN integrity_constraint_violation - THEN - -- Data has appeared in the meantime, retry: - RAISE WARNING 'set_peer insert conflict'; - END; - ELSE - "old_age" := EXTRACT(EPOCH FROM (now() - old.last_request)); - -- Estimate speeds, with sanity checks first: - IF "old_age" <= 30 * 60 AND - "p_uploaded" >= old.uploaded AND - "p_downloaded" >= old.downloaded AND - "p_left" <= old."left" THEN - "up" := "p_uploaded" - old.uploaded; - "down" := "p_downloaded" - old.downloaded; - PERFORM add_counter('up', p_info_hash, "up"); - PERFORM add_counter('down', p_info_hash, "down"); - - "p_upspeed" := ("up" / "old_age")::BIGINT; - "p_downspeed" := ("down" / "old_age")::BIGINT; - END IF; - - -- If this peer hadn't completed before: - -- - -- Recognize its "completed" event, or - -- - -- try to recognize completed event when it has been - -- sent to a different tracker. - p_completed := old.completed; - IF "p_completed" != TRUE AND - ("p_event" = 'completed' OR - (old."left" > 0 AND "p_left" = 0)) THEN - - PERFORM add_counter('complete', "p_info_hash", 1); - p_completed := TRUE; - END IF; - - UPDATE tracked SET "host"="p_host", "port"="p_port", - "uploaded"="p_uploaded", "downloaded"="p_downloaded", - "left"="p_left", "last_request"=now(), "completed"="p_completed", - "upspeed"="p_upspeed", "downspeed"="p_downspeed" - WHERE "info_hash"="p_info_hash" AND "peer_id"="p_peer_id"; - END IF; - END; -$$ LANGUAGE plpgsql; - --- periodic "tracked" cleaner -CREATE OR REPLACE FUNCTION clear_peers(maxage INTERVAL) RETURNS void AS $$ - DECLARE - "t_info_hash" BYTEA; - "t_peer_id" BYTEA; - BEGIN - FOR t_info_hash, t_peer_id IN - SELECT info_hash, peer_id - FROM tracked - WHERE "last_request" <= CURRENT_TIMESTAMP - maxage - LOOP - DELETE FROM tracked - WHERE info_hash=t_info_hash - AND peer_id=t_peer_id; - PERFORM update_scraped(t_info_hash); - END LOOP; - END; -$$ LANGUAGE plpgsql; - --- Caches "tracked" sums by info_hash -CREATE TABLE scraped ( - "info_hash" BYTEA NOT NULL PRIMARY KEY, - "seeders" INT, - "leechers" INT, - "upspeed" BIGINT, - "downspeed" BIGINT -); -CREATE INDEX scraped_popularity ON scraped (("seeders" + "leechers") DESC); - -CREATE OR REPLACE FUNCTION update_scraped( - "t_info_hash" BYTEA -) RETURNS void AS $$ - DECLARE - "t_seeders" BIGINT; - "t_leechers" BIGINT; - "t_upspeed" BIGINT; - "t_downspeed" BIGINT; - BEGIN - -- Collect data - SELECT SUM(CASE "left" - WHEN 0 THEN 1 - ELSE 0 - END), - SUM(CASE "left" - WHEN 0 THEN 0 - ELSE 1 - END), - SUM("upspeed"), - SUM("downspeed") - INTO "t_seeders", "t_leechers", "t_upspeed", "t_downspeed" - FROM tracked - WHERE "info_hash"="t_info_hash"; - - "t_seeders" := COALESCE("t_seeders", 0); - "t_leechers" := COALESCE("t_leechers", 0); - "t_upspeed" := COALESCE("t_upspeed", 0); - "t_downspeed" := COALESCE("t_downspeed", 0); - - -- Is worth an entry? - IF "t_leechers" > 0 OR "t_seeders" > 0 THEN - UPDATE scraped - SET "seeders"="t_seeders", - "leechers"="t_leechers", - "upspeed"="t_upspeed", - "downspeed"="t_downspeed" - WHERE scraped.info_hash="t_info_hash"; - - -- Row didn't exist? Create: - IF NOT FOUND THEN - INSERT INTO scraped - ("info_hash", "seeders", "leechers", "upspeed", "downspeed") - VALUES (t_info_hash, t_seeders, t_leechers, t_upspeed, t_downspeed); - END IF; - ELSE - -- Discard on idle - DELETE FROM scraped - WHERE "info_hash"="t_info_hash"; - END IF; - END; -$$ LANGUAGE plpgsql; -