From 490dd79fd94532ad559aac3865bf4da9d2963ef9 Mon Sep 17 00:00:00 2001 From: Marcin Ickiewicz <mickiewicz@syncad.com> Date: Thu, 10 Sep 2020 13:51:24 +0200 Subject: [PATCH] faster query for trending posts with bridge api --- hive/db/schema.py | 105 +++++++++++++++++++++++++++++- hive/server/bridge_api/methods.py | 26 ++++++-- scripts/upgrade.sql | 92 ++++++++++++++++++++++++++ 3 files changed, 213 insertions(+), 10 deletions(-) create mode 100644 scripts/upgrade.sql diff --git a/hive/db/schema.py b/hive/db/schema.py index c2945ec73..fe8a6a0bd 100644 --- a/hive/db/schema.py +++ b/hive/db/schema.py @@ -777,7 +777,7 @@ def setup(db): LANGUAGE 'plpgsql' AS $function$ - DECLARE + DECLARE post_id INT; BEGIN SELECT INTO post_id COALESCE( (SELECT hp.id @@ -948,7 +948,7 @@ def setup(db): hp.allow_curation_rewards, hp.beneficiaries, hp.url, hp.root_title, hp.abs_rshares, hp.active, hp.author_rewards FROM hive_posts_view hp - INNER JOIN + INNER JOIN ( SELECT hp2.id, hp2.root_id FROM hive_posts hp2 WHERE NOT hp2.is_muted @@ -973,7 +973,7 @@ def setup(db): in _start_post_author hive_accounts.name%TYPE, in _start_post_permlink hive_permlink_data.permlink%TYPE, in _limit INT) - RETURNS SETOF database_api_post + RETURNS SETOF database_api_post LANGUAGE sql COST 100 STABLE @@ -1308,6 +1308,105 @@ def setup(db): """ db.query_no_return(sql) + sql = """ + DROP TYPE IF EXISTS bridge_api_post CASCADE; + CREATE TYPE bridge_api_post AS ( + id INTEGER, + author VARCHAR, + parent_author VARCHAR, + author_rep FLOAT4, + root_title VARCHAR, + beneficiaries JSON, + max_accepted_payout VARCHAR, + percent_hbd INTEGER, + url TEXT, + permlink VARCHAR, + parent_permlink_or_category VARCHAR, + title VARCHAR, + body TEXT, + category VARCHAR, + depth SMALLINT, + promoted DECIMAL(10,3), + payout DECIMAL(10,3), + pending_payout DECIMAL(10,3), + payout_at TIMESTAMP, + is_paidout BOOLEAN, + children INTEGER, + votes INTEGER, + created_at TIMESTAMP, + updated_at TIMESTAMP, + rshares NUMERIC, + abs_rshares NUMERIC, + json TEXT, + is_hidden BOOLEAN, + is_grayed BOOLEAN, + total_votes BIGINT, + sc_trend FLOAT4, + role_title VARCHAR, + community_title VARCHAR, + role_id SMALLINT, + is_pinned BOOLEAN, + curator_payout_value VARCHAR + ); + """ + db.query_no_return(sql) + + sql = """ + DROP FUNCTION IF EXISTS bridge_get_ranked_post_by_trends; + CREATE FUNCTION bridge_get_ranked_post_by_trends( in _limit SMALLINT ) + RETURNS SETOF bridge_api_post + AS + $function$ + SELECT + hp.id, + hp.author, + hp.parent_author, + hp.author_rep, + hp.root_title, + hp.beneficiaries, + hp.max_accepted_payout, + hp.percent_hbd, + hp.url, + hp.permlink, + hp.parent_permlink_or_category, + hp.title, + hp.body, + hp.category, + hp.depth, + hp.promoted, + hp.payout, + hp.pending_payout, + hp.payout_at, + hp.is_paidout, + hp.children, + hp.votes, + hp.created_at, + hp.updated_at, + hp.rshares, + hp.abs_rshares, + hp.json, + hp.is_hidden, + hp.is_grayed, + hp.total_votes, + hp.sc_trend, + hp.role_title, + hp.community_title, + hp.role_id, + hp.is_pinned, + hp.curator_payout_value + FROM + ( + SELECT + hp1.id + , hp1.sc_trend as trend + FROM hive_posts hp1 WHERE NOT hp1.is_paidout AND hp1.depth = 0 ORDER BY hp1.sc_trend DESC LIMIT _limit + ) as trends + JOIN hive_posts_view hp ON hp.id = trends.id ORDER BY trends.trend DESC + $function$ + language sql + """ + db.query_no_return(sql) + def reset_autovac(db): """Initializes/resets per-table autovacuum/autoanalyze params. diff --git a/hive/server/bridge_api/methods.py b/hive/server/bridge_api/methods.py index 913459495..c72e6f16c 100644 --- a/hive/server/bridge_api/methods.py +++ b/hive/server/bridge_api/methods.py @@ -128,6 +128,18 @@ async def get_ranked_posts(context, sort, start_author='', start_permlink='', db = context['db'] + if sort == 'trending' and not ( start_author and start_permlink ) and ( not tag or tag == 'all' ): + sql = "SELECT * FROM bridge_get_ranked_post_by_trends( (:limit)::SMALLINT )" + posts = [] + sql_result = await db.query_all(sql, limit=limit ) + for row in sql_result: + post = _bridge_post_object(row) + post['active_votes'] = await find_votes({'db':db}, {'author':row['author'], 'permlink':row['permlink']}, VotesPresentation.BridgeApi) + post = await append_statistics_to_post(post, row, False, None) + posts.append(post) + return posts + + sql = '' pinned_sql = '' @@ -158,7 +170,7 @@ async def get_ranked_posts(context, sort, start_author='', start_permlink='', if start_author and start_permlink: if sort == 'trending': - sql = sql % """ AND hp.sc_trend <= (SELECT sc_trend FROM hive_posts WHERE author_id = (SELECT id FROM hive_accounts WHERE name = :author) AND permlink_id = (SELECT id FROM hive_permlink_data WHERE permlink = :permlink)) + sql = sql % """ AND hp.sc_trend <= (SELECT sc_trend FROM hive_posts WHERE author_id = (SELECT id FROM hive_accounts WHERE name = :author) AND permlink_id = (SELECT id FROM hive_permlink_data WHERE permlink = :permlink)) AND hp.id != (SELECT id FROM hive_posts WHERE author_id = (SELECT id FROM hive_accounts WHERE name = :author) AND permlink_id = (SELECT id FROM hive_permlink_data WHERE permlink = :permlink)) %s """ elif sort == 'hot': sql = sql % """ AND hp.sc_hot <= (SELECT sc_hot FROM hive_posts WHERE author_id = (SELECT id FROM hive_accounts WHERE name = :author) AND permlink_id = (SELECT id FROM hive_permlink_data WHERE permlink = :permlink)) @@ -206,6 +218,7 @@ async def get_ranked_posts(context, sort, start_author='', start_permlink='', pinned_post_ids = [] blacklists_for_user = None + if observer and context: blacklists_for_user = await Mutes.get_blacklists_for_observer(observer, context) @@ -278,9 +291,9 @@ async def get_account_posts(context, sort, account, start_author='', start_perml # pylint: disable=unused-variable observer_id = await get_account_id(db, observer) if observer else None # TODO - + sql = "---bridge_api.get_account_posts\n " + SQL_TEMPLATE + """ %s """ - + if sort == 'blog': ids = await cursor.pids_by_blog(db, account, *start, limit) posts = await load_posts(context['db'], ids) @@ -306,7 +319,7 @@ async def get_account_posts(context, sort, account, start_author='', start_perml sql = sql % """ AND hp.id < (SELECT id FROM hive_posts WHERE author_id = (SELECT id FROM hive_accounts WHERE name = :author) AND permlink_id = (SELECT id FROM hive_permlink_data WHERE permlink = :permlink)) """ else: sql = sql % """ """ - + posts = [] blacklists_for_user = None if observer: @@ -328,7 +341,7 @@ async def get_relationship_between_accounts(context, account1, account2, observe sql = """ SELECT state, blacklisted, follow_blacklists FROM hive_follows WHERE - follower = (SELECT id FROM hive_accounts WHERE name = :account1) AND + follower = (SELECT id FROM hive_accounts WHERE name = :account1) AND following = (SELECT id FROM hive_accounts WHERE name = :account2) """ @@ -347,11 +360,10 @@ async def get_relationship_between_accounts(context, account1, account2, observe result['follows'] = True elif state == 2: result['ignores'] = True - + if row['blacklisted']: result['is_blacklisted'] = True if row['follow_blacklists']: result['follows_blacklists'] = True return result - diff --git a/scripts/upgrade.sql b/scripts/upgrade.sql new file mode 100644 index 000000000..e2e3cd536 --- /dev/null +++ b/scripts/upgrade.sql @@ -0,0 +1,92 @@ +DROP TYPE IF EXISTS bridge_api_post CASCADE; +CREATE TYPE bridge_api_post AS ( + id INTEGER, + author VARCHAR, + parent_author VARCHAR, + author_rep FLOAT4, + root_title VARCHAR, + beneficiaries JSON, + max_accepted_payout VARCHAR, + percent_hbd INTEGER, + url TEXT, + permlink VARCHAR, + parent_permlink_or_category VARCHAR, + title VARCHAR, + body TEXT, + category VARCHAR, + depth SMALLINT, + promoted DECIMAL(10,3), + payout DECIMAL(10,3), + pending_payout DECIMAL(10,3), + payout_at TIMESTAMP, + is_paidout BOOLEAN, + children INTEGER, + votes INTEGER, + created_at TIMESTAMP, + updated_at TIMESTAMP, + rshares NUMERIC, + abs_rshares NUMERIC, + json TEXT, + is_hidden BOOLEAN, + is_grayed BOOLEAN, + total_votes BIGINT, + sc_trend FLOAT4, + role_title VARCHAR, + community_title VARCHAR, + role_id SMALLINT, + is_pinned BOOLEAN, + curator_payout_value VARCHAR +); + +DROP FUNCTION IF EXISTS bridge_get_ranked_post_by_trends; +CREATE FUNCTION bridge_get_ranked_post_by_trends( in _limit SMALLINT ) +RETURNS SETOF bridge_api_post +AS +$function$ + SELECT + hp.id, + hp.author, + hp.parent_author, + hp.author_rep, + hp.root_title, + hp.beneficiaries, + hp.max_accepted_payout, + hp.percent_hbd, + hp.url, + hp.permlink, + hp.parent_permlink_or_category, + hp.title, + hp.body, + hp.category, + hp.depth, + hp.promoted, + hp.payout, + hp.pending_payout, + hp.payout_at, + hp.is_paidout, + hp.children, + hp.votes, + hp.created_at, + hp.updated_at, + hp.rshares, + hp.abs_rshares, + hp.json, + hp.is_hidden, + hp.is_grayed, + hp.total_votes, + hp.sc_trend, + hp.role_title, + hp.community_title, + hp.role_id, + hp.is_pinned, + hp.curator_payout_value + FROM + ( + SELECT + hp1.id + , hp1.sc_trend as trend + FROM hive_posts hp1 WHERE NOT hp1.is_paidout AND hp1.depth = 0 ORDER BY hp1.sc_trend DESC LIMIT _limit + ) as trends + JOIN hive_posts_view hp ON hp.id = trends.id ORDER BY trends.trend DESC +$function$ +language sql -- GitLab