diff --git a/hive/db/db_state.py b/hive/db/db_state.py index 5acc10f0a37d9af70183f0323571df29ca8fee7c..3ec320f77af6b9c7b49a4c14d54bd219419ed4bb 100644 --- a/hive/db/db_state.py +++ b/hive/db/db_state.py @@ -117,8 +117,8 @@ class DbState: 'hive_posts_community_id_not_is_pinned_idx', 'hive_posts_community_id_not_is_paidout_idx', 'hive_posts_payout_at_idx', - 'hive_posts_sc_trend_id_idx', - 'hive_posts_sc_hot_id_idx', + 'hive_posts_rshares_sc_trend_idx', + 'hive_posts_rshares_sc_hot_idx', 'hive_posts_block_num_created_idx', 'hive_posts_payout_plus_pending_payout_id_idx', 'hive_posts_category_id_payout_plus_pending_payout_depth_idx', diff --git a/hive/db/schema.py b/hive/db/schema.py index 36f4be802c4effb360ab87d976a813025599cf61..b975ed6461df1aa41412997d70785efa93f9e8af 100644 --- a/hive/db/schema.py +++ b/hive/db/schema.py @@ -77,18 +77,12 @@ def build_metadata(): sa.Column('is_full_power', BOOLEAN, nullable=False, server_default='0'), sa.Column('is_hidden', BOOLEAN, nullable=False, server_default='0'), # important indexes - sa.Column('sc_trend', sa.Float(precision=6), nullable=False, server_default='0'), - sa.Column('sc_hot', sa.Float(precision=6), nullable=False, server_default='0'), sa.Column('total_payout_value', sa.String(30), nullable=False, server_default='0.000 HBD'), sa.Column('author_rewards', sa.BigInteger, nullable=False, server_default='0'), sa.Column('author_rewards_hive', sa.BigInteger, nullable=False, server_default='0'), sa.Column('author_rewards_hbd', sa.BigInteger, nullable=False, server_default='0'), sa.Column('author_rewards_vests', sa.BigInteger, nullable=False, server_default='0'), - sa.Column('abs_rshares', sa.Numeric, nullable=False, server_default='0'), - sa.Column('vote_rshares', sa.Numeric, nullable=False, server_default='0'), sa.Column('total_vote_weight', sa.Numeric, nullable=False, server_default='0'), - sa.Column('total_votes', sa.BigInteger, nullable=False, server_default='0'), - sa.Column('net_votes', sa.BigInteger, nullable=False, server_default='0'), sa.Column('active', sa.DateTime, nullable=False, server_default='1970-01-01 00:00:00'), sa.Column('cashout_time', sa.DateTime, nullable=False, server_default='1970-01-01 00:00:00'), sa.Column('percent_hbd', sa.Integer, nullable=False, server_default='10000'), @@ -130,24 +124,9 @@ def build_metadata(): postgresql_where=sql_text("NOT is_paidout AND depth = 0 AND counter_deleted = 0")), sa.Index('hive_posts_payout_at_idx', 'payout_at'), - sa.Index( - 'hive_posts_sc_trend_id_idx', - 'sc_trend', - 'id', - postgresql_where=sql_text("NOT is_paidout AND counter_deleted = 0 AND depth = 0"), - ), - sa.Index( - 'hive_posts_sc_hot_id_idx', - 'sc_hot', - 'id', - postgresql_where=sql_text("NOT is_paidout AND counter_deleted = 0 AND depth = 0"), - ), sa.Index('hive_posts_author_id_created_at_id_idx', sa.text('author_id DESC, created_at DESC, id')), - # bridge_get_account_posts_by_comments, bridge_get_account_posts_by_posts - sa.Index('hive_posts_author_id_id_idx', sa.text('author_id, id DESC'), postgresql_where=sql_text('counter_deleted = 0')), sa.Index('hive_posts_author_id_id_depth0_idx', sa.text('author_id, id DESC'), postgresql_where=sql_text('depth = 0 AND counter_deleted = 0')), - sa.Index('hive_posts_block_num_idx', 'block_num'), sa.Index('hive_posts_block_num_created_idx', 'block_num_created'), sa.Index( @@ -162,6 +141,21 @@ def build_metadata(): ) ) + sa.Table( + 'hive_posts_rshares', + metadata, + sa.Column('post_id', sa.Integer, primary_key=True), + sa.Column('abs_rshares', sa.Numeric, nullable=False, server_default='0'), + sa.Column('vote_rshares', sa.Numeric, nullable=False, server_default='0'), + sa.Column('sc_hot', sa.Float(precision=6), nullable=False, server_default='0'), + sa.Column('sc_trend', sa.Float(precision=6), nullable=False, server_default='0'), + sa.Column('total_votes', sa.BigInteger, nullable=False, server_default='0'), + sa.Column('net_votes', sa.BigInteger, nullable=False, server_default='0'), + sa.ForeignKeyConstraint(['post_id'], ['hive_posts.id'], name='hive_posts_rshares_fk1', deferrable=True, postgresql_not_valid=True), + sa.Index('hive_posts_rshares_sc_trend_idx', 'sc_trend', 'post_id'), + sa.Index('hive_posts_rshares_sc_hot_idx', 'sc_hot', 'post_id'), + ) + sa.Table( 'hive_post_data', metadata, @@ -798,7 +792,12 @@ def set_fillfactor(db): """Initializes/resets FILLFACTOR for tables which are intensively updated""" # Lowered fillfactor for hive_votes table in attempt to speed up update_posts_rshares procedure - fillfactor_config = { 'hive_posts': 90, 'hive_post_data': 100, 'hive_votes': 90 } + fillfactor_config = { + 'hive_posts': 90, + 'hive_post_data': 100, + 'hive_votes': 90, + 'hive_posts_rshares': 100 # Can use higher fillfactor since it's just for updates + } for table, fillfactor in fillfactor_config.items(): sql = f"ALTER TABLE {SCHEMA_NAME}.{table} SET (FILLFACTOR = {fillfactor});" diff --git a/hive/db/sql_scripts/get_post_view_by_id.sql b/hive/db/sql_scripts/get_post_view_by_id.sql index 5292ac284d752af7f11049cdfd4f24fd7f6e5ceb..dcdf05f2daff32ccc88e9a347add0e403e5c1aa5 100644 --- a/hive/db/sql_scripts/get_post_view_by_id.sql +++ b/hive/db/sql_scripts/get_post_view_by_id.sql @@ -79,7 +79,7 @@ BEGIN IF json_metadata_as_string IS NULL OR TRIM(json_metadata_as_string) = '' THEN RETURN ''; END IF; - + -- Attempt to parse the input string as JSON BEGIN json_data := json_metadata_as_string::jsonb; @@ -150,7 +150,7 @@ $$; CREATE OR REPLACE FUNCTION hivemind_app.get_post_view_by_id(_id hivemind_app.hive_posts.id%TYPE) RETURNS SETOF hivemind_app.get_post_view_by_id_return_t AS $function$ -BEGIN +BEGIN RETURN QUERY SELECT -- get_post_view_by_id hp.id, @@ -179,10 +179,10 @@ BEGIN 0 AS active_votes, hp.created_at, hp.updated_at, - hp.vote_rshares AS rshares, - hp.abs_rshares, - hp.total_votes, - hp.net_votes, + COALESCE(hpr.vote_rshares, 0) AS rshares, + COALESCE(hpr.abs_rshares, 0) AS abs_rshares, + COALESCE(hpr.total_votes, 0) AS total_votes, + COALESCE(hpr.net_votes, 0) AS net_votes, hpd.json, ha_a.reputation AS author_rep, hp.is_hidden, @@ -210,8 +210,8 @@ BEGIN ELSE concat('#@', ha_a.name, '/', hpd_p.permlink) END) AS url, rpd.title AS root_title, - hp.sc_trend, - hp.sc_hot, + COALESCE(hpr.sc_trend, 0) AS sc_trend, + COALESCE(hpr.sc_hot, 0) AS sc_hot, hp.is_pinned, hp.is_muted, hp.is_nsfw, @@ -229,7 +229,8 @@ BEGIN JOIN hivemind_app.hive_permlink_data hpd_p ON hpd_p.id = hp.permlink_id LEFT JOIN hivemind_app.hive_communities hc ON hp.community_id = hc.id LEFT JOIN hivemind_app.hive_roles hr ON hp.author_id = hr.account_id AND hp.community_id = hr.community_id - -- parent post data + LEFT JOIN hivemind_app.hive_posts_rshares hpr ON hpr.post_id = hp.id + -- parent post data JOIN hivemind_app.hive_posts pp ON pp.id = hp.parent_id -- parent post (0 or 1 parent) JOIN hivemind_app.hive_accounts ha_pp ON ha_pp.id = pp.author_id JOIN hivemind_app.hive_permlink_data hpd_pp ON hpd_pp.id = pp.permlink_id @@ -244,7 +245,7 @@ BEGIN WHERE hp.id = _id AND hp.counter_deleted = 0; END; $function$ LANGUAGE plpgsql STABLE SET join_collapse_limit = 6; ---Changed join_collapse_limit from 1 to 6. Testing on a node with 5 million blocks showed a significant +--Changed join_collapse_limit from 1 to 6. Testing on a node with 5 million blocks showed a significant --improvement in performance for joins between hive.accounts_view and reptracker_app.account_reputations, --reducing query time from 200ms to 12ms @@ -352,7 +353,7 @@ CREATE TYPE hivemind_app.get_full_post_view_by_id_return_t AS( CREATE OR REPLACE FUNCTION hivemind_app.get_full_post_view_by_id(_id hivemind_app.hive_posts.id%TYPE, _observer_id INTEGER) RETURNS SETOF hivemind_app.get_full_post_view_by_id_return_t AS $function$ -BEGIN +BEGIN RETURN QUERY SELECT -- get_full_post_view_by_id hp.id, @@ -381,10 +382,10 @@ BEGIN 0 AS active_votes, hp.created_at, hp.updated_at, - hp.vote_rshares AS rshares, - hp.abs_rshares, - hp.total_votes, - hp.net_votes, + COALESCE(hpr.vote_rshares, 0) AS rshares, + COALESCE(hpr.abs_rshares, 0) AS abs_rshares, + COALESCE(hpr.total_votes, 0) AS total_votes, + COALESCE(hpr.net_votes, 0) AS net_votes, hpd.json, ha_a.reputation AS author_rep, hp.is_hidden, @@ -412,8 +413,8 @@ BEGIN ELSE concat('#@', ha_a.name, '/', hpd_p.permlink) END) AS url, rpd.title AS root_title, - hp.sc_trend, - hp.sc_hot, + COALESCE(hpr.sc_trend, 0) AS sc_trend, + COALESCE(hpr.sc_hot, 0) AS sc_hot, hp.is_pinned, hp.is_muted, hp.is_nsfw, @@ -432,7 +433,8 @@ BEGIN JOIN hivemind_app.hive_permlink_data hpd_p ON hpd_p.id = hp.permlink_id LEFT JOIN hivemind_app.hive_communities hc ON hp.community_id = hc.id LEFT JOIN hivemind_app.hive_roles hr ON hp.author_id = hr.account_id AND hp.community_id = hr.community_id - -- parent post data + LEFT JOIN hivemind_app.hive_posts_rshares hpr ON hpr.post_id = hp.id + -- parent post data JOIN hivemind_app.hive_posts pp ON pp.id = hp.parent_id -- parent post (0 or 1 parent) JOIN hivemind_app.hive_accounts ha_pp ON ha_pp.id = pp.author_id JOIN hivemind_app.hive_permlink_data hpd_pp ON hpd_pp.id = pp.permlink_id @@ -442,12 +444,12 @@ BEGIN JOIN hivemind_app.hive_permlink_data hpd_rp ON hpd_rp.id = rp.permlink_id JOIN hivemind_app.hive_category_data rcd ON rcd.id = rp.category_id JOIN hivemind_app.hive_post_data rpd ON rpd.id = rp.id - LEFT JOIN hivemind_app.get_blacklisted_by_observer(_observer_id) blacklist ON (blacklist.blacklisted_id = hp.author_id) + LEFT JOIN hivemind_app.get_blacklisted_by_observer(_observer_id) blacklist ON (blacklist.blacklisted_id = hp.author_id) -- largest joined data JOIN hivemind_app.hive_post_data hpd ON hpd.id = hp.id WHERE hp.id = _id AND hp.counter_deleted = 0; END; $function$ LANGUAGE plpgsql STABLE SET join_collapse_limit = 6; ---Changed join_collapse_limit from 1 to 6. Testing on a node with 5 million blocks showed a significant +--Changed join_collapse_limit from 1 to 6. Testing on a node with 5 million blocks showed a significant --improvement in performance for joins between hive.accounts_view and reptracker_app.account_reputations, --reducing query time from 200ms to 12ms diff --git a/hive/db/sql_scripts/hive_post_operations.sql b/hive/db/sql_scripts/hive_post_operations.sql index 5b59b6f783ca73a612d0c3f555cd909be428fb52..73067746aeaee309a0260ebe7dafd6a71767e94d 100644 --- a/hive/db/sql_scripts/hive_post_operations.sql +++ b/hive/db/sql_scripts/hive_post_operations.sql @@ -188,11 +188,11 @@ BEGIN WHERE pha.name = _parent_author AND phpd.permlink = _parent_permlink AND ha.name = _author AND hpd.permlink = _permlink AND php.counter_deleted = 0 ) AS s - ) + ), inserted_post AS ( INSERT INTO hivemind_app.hive_posts as hp (parent_id, depth, community_id, category_id, root_id, is_muted, is_valid, - author_id, permlink_id, created_at, updated_at, sc_hot, sc_trend, active, payout_at, cashout_time, counter_deleted, block_num, block_num_created, muted_reasons) + author_id, permlink_id, created_at, updated_at, active, payout_at, cashout_time, counter_deleted, block_num, block_num_created, muted_reasons) SELECT s.parent_id, s.depth, @@ -205,8 +205,6 @@ BEGIN s.permlink_id, s.created_at, s.updated_at, - s.sc_hot, - s.sc_trend, s.active, s.payout_at, s.cashout_time, @@ -224,7 +222,19 @@ BEGIN block_num = _block_num RETURNING (xmax = 0) as is_new_post, hp.id, hp.author_id, hp.permlink_id, (SELECT hcd.category FROM hivemind_app.hive_category_data hcd WHERE hcd.id = hp.category_id) as post_category, hp.parent_id, (SELECT s.parent_author_id FROM selected_posts AS s) AS parent_author_id, hp.community_id, hp.is_valid, hp.is_muted, hp.depth, (SELECT EXISTS (SELECT NULL::text FROM hivemind_app.muted AS m - WHERE m.follower = (SELECT s.parent_author_id FROM selected_posts AS s) AND m.following = hp.author_id)) + WHERE m.follower = (SELECT s.parent_author_id FROM selected_posts AS s) AND m.following = hp.author_id)) AS is_author_muted + ), rshares_insert AS ( + INSERT INTO hivemind_app.hive_posts_rshares as hpr (post_id, sc_hot, sc_trend) + SELECT ip.id, s.sc_hot, s.sc_trend + FROM inserted_post as ip, selected_posts as s + ON CONFLICT (post_id) DO UPDATE SET + sc_hot = EXCLUDED.sc_hot, + sc_trend = EXCLUDED.sc_trend + RETURNING post_id + ) + SELECT ip.is_new_post, ip.id, ip.author_id, ip.permlink_id, ip.post_category, ip.parent_id, ip.parent_author_id, ip.community_id, ip.is_valid, ip.is_muted, ip.depth, ip.is_author_muted + FROM inserted_post ip + LEFT JOIN rshares_insert as ri ON ri.post_id = 0 -- force execute the rshares_insert CTE ; ELSE INSERT INTO hivemind_app.hive_category_data @@ -280,7 +290,7 @@ BEGIN INSERT INTO hivemind_app.hive_posts as hp (parent_id, depth, community_id, category_id, root_id, is_muted, is_valid, - author_id, permlink_id, created_at, updated_at, sc_hot, sc_trend, + author_id, permlink_id, created_at, updated_at, active, payout_at, cashout_time, counter_deleted, block_num, block_num_created, muted_reasons) -- removed tagsids SELECT pdi.parent_id, @@ -294,8 +304,6 @@ BEGIN pdi.permlink_id, pdi.created_at, pdi.updated_at, - pdi.sc_hot, - pdi.sc_trend, pdi.active, pdi.payout_at, pdi.cashout_time, @@ -324,11 +332,21 @@ BEGIN WHERE hpt.post_id = hp.post_id AND tap.prepare_tags IS NULL RETURNING hpt.post_id ) -- WITH deleted_post_tags + , rshares_insert AS ( + INSERT INTO hivemind_app.hive_posts_rshares as hpr (post_id, sc_hot, sc_trend) + SELECT ip.id, pdi.sc_hot, pdi.sc_trend + FROM inserted_post as ip, posts_data_to_insert as pdi + ON CONFLICT (post_id) DO UPDATE SET + sc_hot = EXCLUDED.sc_hot, + sc_trend = EXCLUDED.sc_trend + RETURNING post_id + ) -- WITH rshares_insert , inserts_to_posts_and_tags AS MATERIALIZED ( INSERT INTO hivemind_app.hive_post_tags(post_id, tag_id) SELECT ip.id, tags.prepare_tags FROM inserted_post as ip LEFT JOIN deleted_post_tags as dpt ON dpt.post_id = 0 -- there is no post 0, this is only to force execute the deleted_post_tags CTE + LEFT JOIN rshares_insert as ri ON ri.post_id = 0 -- force execute the rshares_insert CTE JOIN tagsid_and_posts as tags ON TRUE ON CONFLICT DO NOTHING ) diff --git a/hive/db/sql_scripts/hive_posts_base_view.sql b/hive/db/sql_scripts/hive_posts_base_view.sql index 22f506898cc290b586f1ddbcb2a649a65929f844..a778b0cb3dc1902798c3a9dea49ab3962452488a 100644 --- a/hive/db/sql_scripts/hive_posts_base_view.sql +++ b/hive/db/sql_scripts/hive_posts_base_view.sql @@ -8,9 +8,14 @@ SELECT , hp.permlink_id , hp.payout , hp.pending_payout - , hp.abs_rshares - , hp.vote_rshares AS rshares + , COALESCE(hpr.abs_rshares, 0) AS abs_rshares + , COALESCE(hpr.vote_rshares, 0) AS rshares + , COALESCE(hpr.sc_trend, 0) AS sc_trend + , COALESCE(hpr.sc_hot, 0) AS sc_hot + , COALESCE(hpr.total_votes, 0) AS total_votes + , COALESCE(hpr.net_votes, 0) AS net_votes FROM hivemind_app.hive_posts hp +LEFT JOIN hivemind_app.hive_posts_rshares hpr ON hpr.post_id = hp.id ; DROP VIEW IF EXISTS hivemind_app.hive_posts_parent_view CASCADE; @@ -38,7 +43,7 @@ CREATE OR REPLACE VIEW hivemind_app.hive_posts_parent_view hp.created_at, hp.updated_at, hp.is_hidden, - hp.total_vote_weight, + COALESCE(hpr.total_votes, 0) AS total_vote_weight, pp.author_id AS parent_author_id, CASE hp.depth > 0 WHEN true THEN hpd_pp.permlink @@ -51,8 +56,8 @@ CREATE OR REPLACE VIEW hivemind_app.hive_posts_parent_view hp.allow_votes, hp.allow_curation_rewards, hp.beneficiaries, - hp.sc_trend, - hp.sc_hot, + COALESCE(hpr.sc_trend, 0) AS sc_trend, + COALESCE(hpr.sc_hot, 0) AS sc_hot, hp.is_pinned, hp.is_muted, hp.is_nsfw, @@ -62,5 +67,6 @@ CREATE OR REPLACE VIEW hivemind_app.hive_posts_parent_view JOIN hivemind_app.hive_posts pp ON pp.id = hp.parent_id JOIN hivemind_app.hive_permlink_data hpd_pp ON hpd_pp.id = pp.permlink_id JOIN hivemind_app.hive_category_data hcd ON hcd.id = hp.category_id + LEFT JOIN hivemind_app.hive_posts_rshares hpr ON hpr.post_id = hp.id WHERE hp.counter_deleted = 0 AND hp.id <> 0 ; diff --git a/hive/db/sql_scripts/hive_posts_view.sql b/hive/db/sql_scripts/hive_posts_view.sql index f54f7a5504dd28fbafe5e59dcfd4ee388fbcfac5..823162f8273c57d65c834da313c2319cf5bec460 100644 --- a/hive/db/sql_scripts/hive_posts_view.sql +++ b/hive/db/sql_scripts/hive_posts_view.sql @@ -1,4 +1,15 @@ -CREATE OR REPLACE VIEW hivemind_app.live_posts_comments_view AS SELECT * FROM hivemind_app.hive_posts WHERE counter_deleted = 0 ; +CREATE OR REPLACE VIEW hivemind_app.live_posts_comments_view AS +SELECT + hp.*, + COALESCE(hpr.abs_rshares, 0) AS abs_rshares, + COALESCE(hpr.vote_rshares, 0) AS vote_rshares, + COALESCE(hpr.sc_hot, 0) AS sc_hot, + COALESCE(hpr.sc_trend, 0) AS sc_trend, + COALESCE(hpr.total_votes, 0) AS total_votes, + COALESCE(hpr.net_votes, 0) AS net_votes +FROM hivemind_app.hive_posts hp +LEFT JOIN hivemind_app.hive_posts_rshares hpr ON hpr.post_id = hp.id +WHERE hp.counter_deleted = 0; CREATE OR REPLACE VIEW hivemind_app.live_posts_view AS SELECT * FROM hivemind_app.live_posts_comments_view WHERE depth = 0; diff --git a/hive/db/sql_scripts/hot_and_trends.sql b/hive/db/sql_scripts/hot_and_trends.sql index f02e49569eacd7f69d7d53b78b77e0727da75a8a..7800eb74ae5c9bf842c039f144b376b82e44d680 100644 --- a/hive/db/sql_scripts/hot_and_trends.sql +++ b/hive/db/sql_scripts/hot_and_trends.sql @@ -78,8 +78,8 @@ END; $BODY$ ; -DROP FUNCTION IF EXISTS hivemind_app.calculate_rhsares_part_of_hot_and_trend(_rshares hivemind_app.hive_posts.vote_rshares%TYPE) CASCADE; -CREATE OR REPLACE FUNCTION hivemind_app.calculate_rhsares_part_of_hot_and_trend(_rshares hivemind_app.hive_posts.vote_rshares%TYPE) +DROP FUNCTION IF EXISTS hivemind_app.calculate_rhsares_part_of_hot_and_trend(_rshares hivemind_app.hive_posts_rshares.vote_rshares%TYPE) CASCADE; +CREATE OR REPLACE FUNCTION hivemind_app.calculate_rhsares_part_of_hot_and_trend(_rshares hivemind_app.hive_posts_rshares.vote_rshares%TYPE) RETURNS double precision LANGUAGE 'plpgsql' IMMUTABLE @@ -97,11 +97,11 @@ END; $BODY$ ; -DROP FUNCTION IF EXISTS hivemind_app.calculate_hot(hive_posts.vote_rshares%TYPE, hivemind_app.hive_posts.created_at%TYPE); +DROP FUNCTION IF EXISTS hivemind_app.calculate_hot(hive_posts_rshares.vote_rshares%TYPE, hivemind_app.hive_posts.created_at%TYPE); CREATE OR REPLACE FUNCTION hivemind_app.calculate_hot( - _rshares hivemind_app.hive_posts.vote_rshares%TYPE, + _rshares hivemind_app.hive_posts_rshares.vote_rshares%TYPE, _post_created_at hivemind_app.hive_posts.created_at%TYPE) -RETURNS hivemind_app.hive_posts.sc_hot%TYPE +RETURNS hivemind_app.hive_posts_rshares.sc_hot%TYPE LANGUAGE 'plpgsql' IMMUTABLE AS $BODY$ @@ -111,11 +111,11 @@ END; $BODY$ ; -DROP FUNCTION IF EXISTS hivemind_app.calculate_trending(hive_posts.vote_rshares%TYPE, hivemind_app.hive_posts.created_at%TYPE); +DROP FUNCTION IF EXISTS hivemind_app.calculate_trending(hive_posts_rshares.vote_rshares%TYPE, hivemind_app.hive_posts.created_at%TYPE); CREATE OR REPLACE FUNCTION hivemind_app.calculate_trending( - _rshares hivemind_app.hive_posts.vote_rshares%TYPE, + _rshares hivemind_app.hive_posts_rshares.vote_rshares%TYPE, _post_created_at hivemind_app.hive_posts.created_at%TYPE) -RETURNS hivemind_app.hive_posts.sc_trend%TYPE +RETURNS hivemind_app.hive_posts_rshares.sc_trend%TYPE LANGUAGE 'plpgsql' IMMUTABLE AS $BODY$ diff --git a/hive/db/sql_scripts/notifications_view.sql b/hive/db/sql_scripts/notifications_view.sql index abb3b778b370d9e56683820e87dd16c69d989591..0b24cadf1176486fcb9b5869ae4851f5ba15d114 100644 --- a/hive/db/sql_scripts/notifications_view.sql +++ b/hive/db/sql_scripts/notifications_view.sql @@ -1,6 +1,6 @@ -DROP FUNCTION IF EXISTS hivemind_app.calculate_notify_vote_score(_payout hivemind_app.hive_posts.payout%TYPE, _abs_rshares hivemind_app.hive_posts.abs_rshares%TYPE, _rshares hivemind_app.hive_votes.rshares%TYPE) CASCADE +DROP FUNCTION IF EXISTS hivemind_app.calculate_notify_vote_score(_payout hivemind_app.hive_posts.payout%TYPE, _abs_rshares hivemind_app.hive_posts_rshares.abs_rshares%TYPE, _rshares hivemind_app.hive_votes.rshares%TYPE) CASCADE ; -CREATE OR REPLACE FUNCTION hivemind_app.calculate_notify_vote_score(_payout hivemind_app.hive_posts.payout%TYPE, _abs_rshares hivemind_app.hive_posts.abs_rshares%TYPE, _rshares hivemind_app.hive_votes.rshares%TYPE) +CREATE OR REPLACE FUNCTION hivemind_app.calculate_notify_vote_score(_payout hivemind_app.hive_posts.payout%TYPE, _abs_rshares hivemind_app.hive_posts_rshares.abs_rshares%TYPE, _rshares hivemind_app.hive_votes.rshares%TYPE) RETURNS INT LANGUAGE 'sql' IMMUTABLE @@ -17,7 +17,7 @@ $BODY$; DROP FUNCTION IF EXISTS hivemind_app.calculate_value_of_vote_on_post CASCADE; CREATE OR REPLACE FUNCTION hivemind_app.calculate_value_of_vote_on_post( _post_payout hivemind_app.hive_posts.payout%TYPE - , _post_rshares hivemind_app.hive_posts.vote_rshares%TYPE + , _post_rshares hivemind_app.hive_posts_rshares.vote_rshares%TYPE , _vote_rshares hivemind_app.hive_votes.rshares%TYPE) RETURNS FLOAT LANGUAGE 'sql' diff --git a/hive/db/sql_scripts/postgrest/utilities/get_ranked_posts.sql b/hive/db/sql_scripts/postgrest/utilities/get_ranked_posts.sql index 7545f698266a5aabbc55704097466a024c19ab4d..044f1de44e5b9501afee4a32902edfa3db81a9d0 100644 --- a/hive/db/sql_scripts/postgrest/utilities/get_ranked_posts.sql +++ b/hive/db/sql_scripts/postgrest/utilities/get_ranked_posts.sql @@ -9,7 +9,7 @@ STABLE AS $$ DECLARE -_extract_pinned_posts BOOLEAN DEFAULT False; +_extract_pinned_posts BOOLEAN DEFAULT False; _result JSONB; BEGIN IF _called_from_bridge_api AND _sort_type = ANY(ARRAY['trending'::hivemind_postgrest_utilities.ranked_post_sort_type, 'created'::hivemind_postgrest_utilities.ranked_post_sort_type]) @@ -25,7 +25,7 @@ BEGIN WITH pinned_post AS -- get_ranked_posts_for_communities pinned ( - SELECT + SELECT hp.id FROM hivemind_app.live_posts_view hp WHERE @@ -119,9 +119,12 @@ BEGIN IF _post_id <> 0 AND (SELECT is_pinned FROM hivemind_app.hive_posts WHERE id = _post_id LIMIT 1) THEN _post_id = 0; ELSE - SELECT sc_trend INTO _trending_limit FROM hivemind_app.hive_posts WHERE id = _post_id; + SELECT COALESCE(hpr.sc_trend, 0) INTO _trending_limit + FROM hivemind_app.hive_posts hp + LEFT JOIN hivemind_app.hive_posts_rshares hpr ON hpr.post_id = hp.id + WHERE hp.id = _post_id; END IF; - + _result = ( SELECT jsonb_agg ( ( @@ -132,12 +135,12 @@ BEGIN ) ) FROM ( WITH -- get_trending_ranked_posts_for_communities - ranked_community_posts as + ranked_community_posts as ( - SELECT hp.id + SELECT hp.id FROM hivemind_app.live_posts_view hp JOIN hivemind_app.hive_communities hc ON hp.community_id = hc.id - WHERE + WHERE hc.name = _tag AND NOT hp.is_paidout --use index hive_posts_community_id_is_paidout_idx AND NOT(_called_from_bridge_api AND hp.is_pinned) @@ -219,7 +222,7 @@ BEGIN _result = ( SELECT jsonb_agg ( - ( + ( CASE WHEN _called_from_bridge_api THEN hivemind_postgrest_utilities.create_bridge_post_object(row, _truncate_body, NULL, row.is_pinned, True) ELSE hivemind_postgrest_utilities.create_condenser_post_object(row, _truncate_body, False) @@ -398,12 +401,15 @@ _hot_limit FLOAT; _result JSONB; BEGIN IF _post_id <> 0 THEN - SELECT sc_hot INTO _hot_limit FROM hivemind_app.hive_posts hp WHERE hp.id = _post_id; + SELECT hpr.sc_hot INTO _hot_limit + FROM hivemind_app.hive_posts hp + LEFT JOIN hivemind_app.hive_posts_rshares hpr ON hpr.post_id = hp.id + WHERE hp.id = _post_id; END IF; _result = ( SELECT jsonb_agg ( - ( + ( CASE WHEN _called_from_bridge_api THEN hivemind_postgrest_utilities.create_bridge_post_object(row, _truncate_body, NULL, row.is_pinned, True) ELSE hivemind_postgrest_utilities.create_condenser_post_object(row, _truncate_body, False) @@ -679,7 +685,10 @@ BEGIN _tag_id = hivemind_postgrest_utilities.find_tag_id( _tag, True ); IF _post_id <> 0 THEN - SELECT sc_trend INTO __trending_limit FROM hivemind_app.hive_posts hp WHERE hp.id = _post_id; + SELECT COALESCE(hpr.sc_trend, 0) INTO __trending_limit + FROM hivemind_app.hive_posts hp + LEFT JOIN hivemind_app.hive_posts_rshares hpr ON hpr.post_id = hp.id + WHERE hp.id = _post_id; END IF; _result = ( @@ -772,7 +781,10 @@ BEGIN _tag_id = hivemind_postgrest_utilities.find_tag_id( _tag, True ); IF _post_id <> 0 THEN - SELECT sc_hot INTO _hot_limit FROM hivemind_app.hive_posts hp WHERE hp.id = _post_id; + SELECT COALESCE(hpr.sc_hot, 0) INTO _hot_limit + FROM hivemind_app.hive_posts hp + LEFT JOIN hivemind_app.hive_posts_rshares hpr ON hpr.post_id = hp.id + WHERE hp.id = _post_id; END IF; _result = ( @@ -864,7 +876,7 @@ BEGIN _result = ( SELECT jsonb_agg ( - ( + ( CASE WHEN _called_from_bridge_api THEN hivemind_postgrest_utilities.create_bridge_post_object(row, _truncate_body, NULL, row.is_pinned, True) ELSE hivemind_postgrest_utilities.create_condenser_post_object(row, _truncate_body, False) @@ -1055,7 +1067,7 @@ BEGIN _result = ( SELECT jsonb_agg ( - ( + ( CASE WHEN _called_from_bridge_api THEN hivemind_postgrest_utilities.create_bridge_post_object(row, _truncate_body, NULL, row.is_pinned, True) ELSE hivemind_postgrest_utilities.create_condenser_post_object(row, _truncate_body, False) @@ -1231,7 +1243,10 @@ _trending_limit FLOAT; _result JSONB; BEGIN IF _post_id <> 0 THEN - SELECT sc_trend INTO _trending_limit FROM hivemind_app.hive_posts WHERE id = _post_id; + SELECT COALESCE(hpr.sc_trend, 0) INTO _trending_limit + FROM hivemind_app.hive_posts hp + LEFT JOIN hivemind_app.hive_posts_rshares hpr ON hpr.post_id = hp.id + WHERE hp.id = _post_id; END IF; _result = ( @@ -1245,7 +1260,7 @@ BEGIN hp.id FROM hivemind_app.live_posts_view hp JOIN hivemind_app.hive_subscriptions hs ON hp.community_id = hs.community_id - WHERE hs.account_id = _observer_id + WHERE hs.account_id = _observer_id AND NOT hp.is_paidout AND (_post_id = 0 OR hp.sc_trend < _trending_limit OR (hp.sc_trend = _trending_limit AND hp.id < _post_id)) AND (_observer_id = 0 OR NOT EXISTS (SELECT 1 FROM hivemind_app.muted_accounts_by_id_view WHERE observer_id = _observer_id AND muted_id = hp.author_id)) @@ -1317,7 +1332,10 @@ _hot_limit FLOAT; _result JSONB; BEGIN IF _post_id <> 0 THEN - SELECT sc_hot INTO _hot_limit FROM hivemind_app.hive_posts hp WHERE hp.id = _post_id; + SELECT COALESCE(hpr.sc_hot, 0) INTO _hot_limit + FROM hivemind_app.hive_posts hp + LEFT JOIN hivemind_app.hive_posts_rshares hpr ON hpr.post_id = hp.id + WHERE hp.id = _post_id; END IF; _result = ( @@ -1760,7 +1778,10 @@ _trending_limit FLOAT; _result JSONB; BEGIN IF _post_id <> 0 THEN - SELECT sc_trend INTO _trending_limit FROM hivemind_app.hive_posts hp WHERE hp.id = _post_id; + SELECT COALESCE(hpr.sc_trend, 0) INTO _trending_limit + FROM hivemind_app.hive_posts hp + LEFT JOIN hivemind_app.hive_posts_rshares hpr ON hpr.post_id = hp.id + WHERE hp.id = _post_id; END IF; _result = ( @@ -1850,7 +1871,10 @@ _hot_limit FLOAT; _result JSONB; BEGIN IF _post_id <> 0 THEN - SELECT sc_hot INTO _hot_limit FROM hivemind_app.hive_posts hp WHERE hp.id = _post_id; + SELECT COALESCE(hpr.sc_hot, 0) INTO _hot_limit + FROM hivemind_app.hive_posts hp + LEFT JOIN hivemind_app.hive_posts_rshares hpr ON hpr.post_id = hp.id + WHERE hp.id = _post_id; END IF; _result = ( diff --git a/hive/db/sql_scripts/update_posts_rshares.sql b/hive/db/sql_scripts/update_posts_rshares.sql index ec6203cf2caacfce314a3ff7b6766e898be3ff1d..9fdd7660161a898072a7cacf33aa74af0fa81535 100644 --- a/hive/db/sql_scripts/update_posts_rshares.sql +++ b/hive/db/sql_scripts/update_posts_rshares.sql @@ -11,14 +11,15 @@ BEGIN SET LOCAL work_mem='4GB'; SET LOCAL enable_seqscan = off; - UPDATE hivemind_app.hive_posts hp - SET - abs_rshares = votes_rshares.abs_rshares - ,vote_rshares = votes_rshares.rshares - ,sc_hot = CASE hp.is_paidout OR hp.parent_id > 0 WHEN True Then 0 ELSE hivemind_app.calculate_hot( votes_rshares.rshares, hp.created_at) END - ,sc_trend = CASE hp.is_paidout OR hp.parent_id > 0 WHEN True Then 0 ELSE hivemind_app.calculate_trending( votes_rshares.rshares, hp.created_at) END - ,total_votes = votes_rshares.total_votes - ,net_votes = votes_rshares.net_votes + INSERT INTO hivemind_app.hive_posts_rshares (post_id, abs_rshares, vote_rshares, sc_hot, sc_trend, total_votes, net_votes) + SELECT + votes_rshares.post_id, + votes_rshares.abs_rshares, + votes_rshares.rshares, + CASE hp.is_paidout OR hp.parent_id > 0 WHEN True Then 0 ELSE hivemind_app.calculate_hot( votes_rshares.rshares, hp.created_at) END, + CASE hp.is_paidout OR hp.parent_id > 0 WHEN True Then 0 ELSE hivemind_app.calculate_trending( votes_rshares.rshares, hp.created_at) END, + votes_rshares.total_votes, + votes_rshares.net_votes FROM ( SELECT @@ -35,14 +36,20 @@ SET LOCAL enable_seqscan = off; WHERE hv.post_id = ANY(_post_ids) GROUP BY hv.post_id ) as votes_rshares - WHERE hp.id = votes_rshares.post_id - AND hp.counter_deleted = 0 - AND ( - hp.abs_rshares != votes_rshares.abs_rshares - OR hp.vote_rshares != votes_rshares.rshares - OR hp.total_votes != votes_rshares.total_votes - OR hp.net_votes != votes_rshares.net_votes - ); + JOIN hivemind_app.hive_posts hp ON hp.id = votes_rshares.post_id + WHERE hp.counter_deleted = 0 + ON CONFLICT (post_id) DO UPDATE SET + abs_rshares = EXCLUDED.abs_rshares, + vote_rshares = EXCLUDED.vote_rshares, + sc_hot = EXCLUDED.sc_hot, + sc_trend = EXCLUDED.sc_trend, + total_votes = EXCLUDED.total_votes, + net_votes = EXCLUDED.net_votes + WHERE + hive_posts_rshares.abs_rshares != EXCLUDED.abs_rshares + OR hive_posts_rshares.vote_rshares != EXCLUDED.vote_rshares + OR hive_posts_rshares.total_votes != EXCLUDED.total_votes + OR hive_posts_rshares.net_votes != EXCLUDED.net_votes; RESET enable_seqscan; RESET work_mem; diff --git a/hive/indexer/notification_cache.py b/hive/indexer/notification_cache.py index 1f0fa52db2bdb8f5cb4da43188ac818a3fa9cc70..c51c3834a98b1f3cce4a80d6c69c1d29c4929adc 100644 --- a/hive/indexer/notification_cache.py +++ b/hive/indexer/notification_cache.py @@ -64,8 +64,11 @@ class NotificationCache(DbAdapterHolder): JOIN {SCHEMA_NAME}.hive_accounts AS ha ON n.author = ha.name JOIN {SCHEMA_NAME}.hive_permlink_data AS pd ON n.permlink = pd.permlink JOIN ( - SELECT hpvi.id, hpvi.permlink_id, hpvi.author_id, hpvi.payout, hpvi.pending_payout, hpvi.abs_rshares, hpvi.vote_rshares as rshares + SELECT hpvi.id, hpvi.permlink_id, hpvi.author_id, hpvi.payout, hpvi.pending_payout, + COALESCE(hpr.abs_rshares, 0) as abs_rshares, + COALESCE(hpr.vote_rshares, 0) as rshares FROM {SCHEMA_NAME}.hive_posts hpvi + LEFT JOIN {SCHEMA_NAME}.hive_posts_rshares hpr ON hpr.post_id = hpvi.id WHERE hpvi.block_num > {SCHEMA_NAME}.block_before_head('97 days'::interval) AND hpvi.counter_deleted = 0 ) AS hpv ON pd.id = hpv.permlink_id AND ha.id = hpv.author_id diff --git a/hive/indexer/posts.py b/hive/indexer/posts.py index 055c34090c98a8c40ec1cdf50c5f65af03e133c0..d306b8f4ed02a99ad97e7815858d53b8ecd7ac2a 100644 --- a/hive/indexer/posts.py +++ b/hive/indexer/posts.py @@ -187,7 +187,6 @@ class Posts(DbAdapterHolder): for chunk in chunks(cls._comment_payout_ops, 1000): cls.beginTx() - cls.db.query_no_return('SELECT pg_advisory_xact_lock(777)') # synchronise with update_posts_rshares in votes values_str = ','.join(chunk) actual_query = sql.format(values_str) cls.db.query_prepared(actual_query) diff --git a/hive/indexer/votes.py b/hive/indexer/votes.py index 4044b52ff8c74750412bb93b82eed0f85ca8bdff..95bef20611d958e13759ec618c0fde0cf27c3f6c 100644 --- a/hive/indexer/votes.py +++ b/hive/indexer/votes.py @@ -193,7 +193,6 @@ class Votes(DbAdapterHolder): ) actual_query = sql.format(values_str) post_ids = cls.db.query_prepared_all(actual_query) - cls.db.query_no_return('SELECT pg_advisory_xact_lock(777)') # synchronise with update hive_posts in posts cls.db.query_no_return("SELECT * FROM hivemind_app.update_posts_rshares(:post_ids)", post_ids=[id[0] for id in post_ids]) cls.commitTx()