diff --git a/hive/db/schema.py b/hive/db/schema.py index 01c60aa5adc0008974ed21c48b3d78a54c393bdf..7b04e94b266ec57ca7da3fa3b576c78efefacb8f 100644 --- a/hive/db/schema.py +++ b/hive/db/schema.py @@ -33,7 +33,7 @@ def build_metadata(): sa.Table( 'hive_accounts', metadata, sa.Column('id', sa.Integer, primary_key=True), - sa.Column('name', VARCHAR(16), nullable=False), + sa.Column('name', VARCHAR(16, collation='C'), nullable=False), sa.Column('created_at', sa.DateTime, nullable=False), #sa.Column('block_num', sa.Integer, nullable=False), sa.Column('reputation', sa.Float(precision=6), nullable=False, server_default='25'), @@ -68,7 +68,8 @@ def build_metadata(): sa.Table( 'hive_posts', metadata, sa.Column('id', sa.Integer, primary_key=True), - sa.Column('parent_id', sa.Integer), + sa.Column('root_id', sa.Integer), # Null means = id + sa.Column('parent_id', sa.Integer, nullable=False), sa.Column('author_id', sa.Integer, nullable=False), sa.Column('permlink_id', sa.BigInteger, nullable=False), sa.Column('category_id', sa.Integer, nullable=False), @@ -86,13 +87,12 @@ def build_metadata(): # basic/extended-stats sa.Column('author_rep', sa.Float(precision=6), nullable=False, server_default='0'), sa.Column('flag_weight', sa.Float(precision=6), nullable=False, server_default='0'), - sa.Column('total_votes', sa.Integer, nullable=False, server_default='0'), - sa.Column('up_votes', sa.Integer, nullable=False, server_default='0'), # core stats/indexes sa.Column('payout', sa.types.DECIMAL(10, 3), nullable=False, server_default='0'), sa.Column('pending_payout', sa.types.DECIMAL(10, 3), nullable=False, server_default='0'), sa.Column('payout_at', sa.DateTime, nullable=False, server_default='1970-01-01'), + sa.Column('last_payout_at', sa.DateTime, nullable=False, server_default='1970-01-01'), sa.Column('updated_at', sa.DateTime, nullable=False, server_default='1970-01-01'), sa.Column('is_paidout', BOOLEAN, nullable=False, server_default='0'), @@ -117,20 +117,14 @@ def build_metadata(): sa.Column('children_abs_rshares', sa.BigInteger, nullable=False, server_default='0'), sa.Column('abs_rshares', sa.BigInteger, nullable=False, server_default='0'), sa.Column('vote_rshares', sa.BigInteger, nullable=False, server_default='0'), - sa.Column('net_votes', sa.Integer, nullable=False, server_default='0'), + sa.Column('total_vote_weight', sa.Numeric, 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('max_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'), sa.Column('reward_weight', sa.Integer, nullable=False, server_default='10000'), # Seems to be always 10000 - sa.Column('parent_author_id', sa.Integer, nullable=False), - sa.Column('parent_permlink_id', sa.BigInteger, nullable=False), sa.Column('curator_payout_value', sa.String(30), nullable=False, server_default=''), - sa.Column('root_author_id', sa.Integer, nullable=False), - sa.Column('root_permlink_id', sa.BigInteger, nullable=False), sa.Column('max_accepted_payout', sa.String(30), nullable=False, server_default='1000000.000 HBD'), - sa.Column('allow_replies', BOOLEAN, nullable=False, server_default='1'), sa.Column('allow_votes', BOOLEAN, nullable=False, server_default='1'), sa.Column('allow_curation_rewards', BOOLEAN, nullable=False, server_default='1'), sa.Column('beneficiaries', sa.JSON, nullable=False, server_default='[]'), @@ -138,11 +132,13 @@ def build_metadata(): sa.Column('root_title', sa.String(255), nullable=False, server_default=''), sa.ForeignKeyConstraint(['author_id'], ['hive_accounts.id'], name='hive_posts_fk1'), + sa.ForeignKeyConstraint(['root_id'], ['hive_posts.id'], name='hive_posts_fk2'), sa.ForeignKeyConstraint(['parent_id'], ['hive_posts.id'], name='hive_posts_fk3'), sa.UniqueConstraint('author_id', 'permlink_id', 'counter_deleted', name='hive_posts_ux1'), sa.Index('hive_posts_permlink_id', 'permlink_id'), sa.Index('hive_posts_depth_idx', 'depth'), + sa.Index('hive_posts_root_id_idx', sa.func.coalesce('root_id','id')), sa.Index('hive_posts_parent_id_idx', 'parent_id'), sa.Index('hive_posts_community_id_idx', 'community_id'), sa.Index('hive_posts_author_id', 'author_id'), @@ -153,12 +149,7 @@ def build_metadata(): sa.Index('hive_posts_promoted_idx', 'promoted'), sa.Index('hive_posts_sc_trend_idx', 'sc_trend'), sa.Index('hive_posts_sc_hot_idx', 'sc_hot'), - sa.Index('hive_posts_created_at_idx', 'created_at'), - - sa.Index('hive_posts_root_author_id', 'root_author_id'), - sa.Index('hive_posts_root_permlink_id', 'root_permlink_id'), - sa.Index('hive_posts_parent_author_id', 'parent_author_id'), - sa.Index('hive_posts_parent_permlink_id', 'parent_permlink_id') + sa.Index('hive_posts_created_at_idx', 'created_at') ) sa.Table( @@ -174,14 +165,14 @@ def build_metadata(): sa.Table( 'hive_permlink_data', metadata, sa.Column('id', sa.BigInteger, primary_key=True), - sa.Column('permlink', sa.String(255), nullable=False), + sa.Column('permlink', sa.String(255, collation='C'), nullable=False), sa.UniqueConstraint('permlink', name='hive_permlink_data_permlink') ) sa.Table( 'hive_category_data', metadata, sa.Column('id', sa.Integer, primary_key=True), - sa.Column('category', sa.String(255), nullable=False), + sa.Column('category', sa.String(255, collation='C'), nullable=False), sa.UniqueConstraint('category', name='hive_category_data_category') ) @@ -198,6 +189,7 @@ def build_metadata(): sa.Column('last_update', sa.DateTime, nullable=False, server_default='1970-01-01 00:00:00'), sa.Column('num_changes', sa.Integer, server_default='0'), sa.Column('block_num', sa.Integer, nullable=False ), + sa.Column('is_effective', BOOLEAN, nullable=False, server_default='0'), sa.UniqueConstraint('voter_id', 'author_id', 'permlink_id', name='hive_votes_ux1'), @@ -219,7 +211,7 @@ def build_metadata(): sa.Table( 'hive_tag_data', metadata, sa.Column('id', sa.Integer, nullable=False, primary_key=True), - sa.Column('tag', VARCHAR(64), nullable=False, server_default=''), + sa.Column('tag', VARCHAR(64, collation='C'), nullable=False, server_default=''), sa.UniqueConstraint('tag', name='hive_tag_data_ux1') ) @@ -313,7 +305,7 @@ def build_metadata_community(metadata=None): sa.Column('id', sa.Integer, primary_key=True, autoincrement=False), sa.Column('type_id', SMALLINT, nullable=False), sa.Column('lang', CHAR(2), nullable=False, server_default='en'), - sa.Column('name', VARCHAR(16), nullable=False), + sa.Column('name', VARCHAR(16, collation='C'), nullable=False), sa.Column('title', sa.String(32), nullable=False, server_default=''), sa.Column('created_at', sa.DateTime, nullable=False), sa.Column('sum_pending', sa.Integer, nullable=False, server_default='0'), @@ -408,12 +400,11 @@ def setup(db): """ INSERT INTO - public.hive_posts(id, parent_id, author_id, permlink_id, category_id, - community_id, parent_author_id, parent_permlink_id, root_author_id, - root_permlink_id, created_at, depth + public.hive_posts(id, root_id, parent_id, author_id, permlink_id, category_id, + community_id, created_at, depth ) VALUES - (0, 0, 0, 0, 0, 0, 0, 0, 0, 0, now(), 0); + (0, 0, 0, 0, 0, 0, 0, now(), 0); """] for sql in sqls: db.query(sql) @@ -433,8 +424,7 @@ def setup(db): in _community_support_start_date hive_posts.created_at%TYPE) RETURNS TABLE (is_new_post boolean, id hive_posts.id%TYPE, author_id hive_posts.author_id%TYPE, permlink_id hive_posts.permlink_id%TYPE, post_category hive_category_data.category%TYPE, parent_id hive_posts.parent_id%TYPE, community_id hive_posts.community_id%TYPE, - is_valid hive_posts.is_valid%TYPE, is_muted hive_posts.is_muted%TYPE, depth hive_posts.depth%TYPE, - is_edited boolean) + is_valid hive_posts.is_valid%TYPE, is_muted hive_posts.is_muted%TYPE, depth hive_posts.depth%TYPE) LANGUAGE plpgsql AS $function$ @@ -450,33 +440,30 @@ def setup(db): ; if _parent_author != '' THEN RETURN QUERY INSERT INTO hive_posts as hp - (parent_id, parent_author_id, parent_permlink_id, depth, community_id, - category_id, - root_author_id, root_permlink_id, - is_muted, is_valid, - author_id, permlink_id, created_at, updated_at, sc_hot, sc_trend,active, payout_at, cashout_time, counter_deleted) - SELECT php.id AS parent_id, php.author_id as parent_author_id, - php.permlink_id as parent_permlink_id, php.depth + 1 as depth, + (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) + SELECT php.id AS parent_id, php.depth + 1 AS depth, (CASE - WHEN _date > _community_support_start_date THEN - COALESCE(php.community_id, (select hc.id from hive_communities hc where hc.name = _parent_permlink)) - ELSE NULL - END) as community_id, - COALESCE(php.category_id, (select hcg.id from hive_category_data hcg where hcg.category = _parent_permlink)) as category_id, - php.root_author_id as root_author_id, - php.root_permlink_id as root_permlink_id, - php.is_muted as is_muted, php.is_valid as is_valid, - ha.id as author_id, hpd.id as permlink_id, _date as created_at, - _date as updated_at, calculate_time_part_of_hot(_date) as sc_hot, - calculate_time_part_of_trending(_date) as sc_trend, - _date as active, (_date + INTERVAL '7 days') as payout_at, (_date + INTERVAL '7 days') as cashout_time, 0 + WHEN _date > _community_support_start_date THEN + COALESCE(php.community_id, (select hc.id from hive_communities hc where hc.name = _parent_permlink)) + ELSE NULL + END) AS community_id, + COALESCE(php.category_id, (select hcg.id from hive_category_data hcg where hcg.category = _parent_permlink)) AS category_id, + COALESCE(php.root_id, php.id) AS root_id, + php.is_muted AS is_muted, php.is_valid AS is_valid, + ha.id AS author_id, hpd.id AS permlink_id, _date AS created_at, + _date AS updated_at, + calculate_time_part_of_hot(_date) AS sc_hot, + calculate_time_part_of_trending(_date) AS sc_trend, + _date AS active, (_date + INTERVAL '7 days') AS payout_at, (_date + INTERVAL '7 days') AS cashout_time, 0 FROM hive_accounts ha, hive_permlink_data hpd, hive_posts php INNER JOIN hive_accounts pha ON pha.id = php.author_id INNER JOIN hive_permlink_data phpd ON phpd.id = php.permlink_id - WHERE pha.name = _parent_author and phpd.permlink = _parent_permlink AND - ha.name = _author and hpd.permlink = _permlink and php.counter_deleted = 0 + WHERE pha.name = _parent_author AND phpd.permlink = _parent_permlink AND + ha.name = _author AND hpd.permlink = _permlink AND php.counter_deleted = 0 ON CONFLICT ON CONSTRAINT hive_posts_ux1 DO UPDATE SET --- During post update it is disallowed to change: parent-post, category, community-id @@ -484,7 +471,7 @@ def setup(db): --- post edit part updated_at = _date, active = _date - RETURNING (xmax = 0) as is_new_post, hp.id, hp.author_id, hp.permlink_id, (SELECT hcd.category FROM hive_category_data hcd WHERE hcd.id = hp.category_id) as post_category, hp.parent_id, hp.community_id, hp.is_valid, hp.is_muted, hp.depth, (hp.updated_at > hp.created_at) as is_edited + RETURNING (xmax = 0) as is_new_post, hp.id, hp.author_id, hp.permlink_id, (SELECT hcd.category FROM hive_category_data hcd WHERE hcd.id = hp.category_id) as post_category, hp.parent_id, hp.community_id, hp.is_valid, hp.is_muted, hp.depth ; ELSE INSERT INTO hive_category_data @@ -494,25 +481,23 @@ def setup(db): ; RETURN QUERY INSERT INTO hive_posts as hp - (parent_id, parent_author_id, parent_permlink_id, depth, community_id, - category_id, - root_author_id, root_permlink_id, - is_muted, is_valid, + (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) - SELECT 0 AS parent_id, 0 as parent_author_id, 0 as parent_permlink_id, 0 as depth, + SELECT 0 AS parent_id, 0 AS depth, (CASE WHEN _date > _community_support_start_date THEN - (select hc.id from hive_communities hc where hc.name = _parent_permlink) + (select hc.id FROM hive_communities hc WHERE hc.name = _parent_permlink) ELSE NULL - END) as community_id, - (select hcg.id from hive_category_data hcg where hcg.category = _parent_permlink) as category_id, - ha.id as root_author_id, -- use author_id as root one if no parent - hpd.id as root_permlink_id, -- use perlink_id as root one if no parent - false as is_muted, true as is_valid, - ha.id as author_id, hpd.id as permlink_id, _date as created_at, - _date as updated_at, calculate_time_part_of_hot(_date) as sc_hot, - calculate_time_part_of_trending(_date) as sc_trend, - _date as active, (_date + INTERVAL '7 days') as payout_at, (_date + INTERVAL '7 days') as cashout_time, 0 + END) AS community_id, + (SELECT hcg.id FROM hive_category_data hcg WHERE hcg.category = _parent_permlink) AS category_id, + Null as root_id, -- will use id as root one if no parent + false AS is_muted, true AS is_valid, + ha.id AS author_id, hpd.id AS permlink_id, _date AS created_at, + _date AS updated_at, + calculate_time_part_of_hot(_date) AS sc_hot, + calculate_time_part_of_trending(_date) AS sc_trend, + _date AS active, (_date + INTERVAL '7 days') AS payout_at, (_date + INTERVAL '7 days') AS cashout_time, 0 FROM hive_accounts ha, hive_permlink_data hpd WHERE ha.name = _author and hpd.permlink = _permlink @@ -524,7 +509,7 @@ def setup(db): updated_at = _date, active = _date - RETURNING (xmax = 0) as is_new_post, hp.id, hp.author_id, hp.permlink_id, _parent_permlink as post_category, hp.parent_id, hp.community_id, hp.is_valid, hp.is_muted, hp.depth, (hp.updated_at > hp.created_at) as is_edited + RETURNING (xmax = 0) as is_new_post, hp.id, hp.author_id, hp.permlink_id, _parent_permlink as post_category, hp.parent_id, hp.community_id, hp.is_valid, hp.is_muted, hp.depth ; END IF; END @@ -569,6 +554,7 @@ def setup(db): AS SELECT hp.id, hp.community_id, + COALESCE( hp.root_id, hp.id ) AS root_id, hp.parent_id, ha_a.name AS author, hp.active, @@ -585,6 +571,8 @@ def setup(db): hp.payout, hp.pending_payout, hp.payout_at, + hp.last_payout_at, + hp.cashout_time, hp.is_paidout, hp.children, 0 AS votes, @@ -603,25 +591,42 @@ def setup(db): ha_a.reputation AS author_rep, hp.is_hidden, hp.is_grayed, - hp.total_votes, + COALESCE( + ( + SELECT COUNT( 1 ) + FROM hive_votes v + WHERE v.post_id = hp.id AND v.is_effective + GROUP BY v.post_id + ), 0 + ) AS total_votes, + COALESCE( + ( + SELECT SUM( CASE v.rshares > 0 WHEN True THEN 1 ELSE -1 END ) + FROM hive_votes v + WHERE v.post_id = hp.id AND NOT v.rshares = 0 + GROUP BY v.post_id + ), 0 + ) AS net_votes, + hp.total_vote_weight, hp.flag_weight, - ha_pa.name AS parent_author, + ha_pp.name AS parent_author, hpd_pp.permlink AS parent_permlink, hp.curator_payout_value, - ha_ra.name AS root_author, + ha_rp.name AS root_author, hpd_rp.permlink AS root_permlink, rcd.category as root_category, hp.max_accepted_payout, hp.percent_hbd, - hp.allow_replies, + True AS allow_replies, hp.allow_votes, hp.allow_curation_rewards, hp.beneficiaries, - concat('/', rcd.category, '/@', ha_ra.name, '/', hpd_rp.permlink, - case (rp.id) - when hp.id then '' - else concat('#@', ha_a.name, '/', hpd_p.permlink) - end ) as url, + CONCAT('/', rcd.category, '/@', ha_rp.name, '/', hpd_rp.permlink, + CASE (rp.id) + WHEN hp.id THEN '' + ELSE CONCAT('#@', ha_a.name, '/', hpd_p.permlink) + END + ) AS url, rpd.title AS root_title, hp.sc_trend, hp.sc_hot, @@ -634,22 +639,29 @@ def setup(db): hr.role_id AS role_id, hc.title AS community_title, hc.name AS community_name, - hp.abs_rshares, - hp.cashout_time, - hp.max_cashout_time, + COALESCE( + ( + SELECT SUM( CASE v.rshares >= 0 WHEN True THEN v.rshares ELSE -v.rshares END ) + FROM hive_votes v + WHERE v.post_id = hp.id AND NOT v.rshares = 0 + GROUP BY v.post_id + ), 0 + ) AS abs_rshares, + '1969-12-31T23:59:59'::timestamp AS max_cashout_time, hp.reward_weight FROM hive_posts hp - JOIN hive_posts rp ON rp.author_id = hp.root_author_id AND rp.permlink_id = hp.root_permlink_id - JOIN hive_post_data rpd ON rp.id = rpd.id + JOIN hive_posts pp ON pp.id = hp.parent_id + JOIN hive_posts rp ON rp.id = COALESCE( hp.root_id, hp.id ) JOIN hive_accounts ha_a ON ha_a.id = hp.author_id JOIN hive_permlink_data hpd_p ON hpd_p.id = hp.permlink_id JOIN hive_post_data hpd ON hpd.id = hp.id + JOIN hive_accounts ha_pp ON ha_pp.id = pp.author_id + JOIN hive_permlink_data hpd_pp ON hpd_pp.id = pp.permlink_id + JOIN hive_accounts ha_rp ON ha_rp.id = rp.author_id + JOIN hive_permlink_data hpd_rp ON hpd_rp.id = rp.permlink_id + JOIN hive_post_data rpd ON rpd.id = rp.id LEFT JOIN hive_category_data hcd ON hcd.id = hp.category_id LEFT JOIN hive_category_data rcd ON rcd.id = rp.category_id - JOIN hive_accounts ha_pa ON ha_pa.id = hp.parent_author_id - JOIN hive_permlink_data hpd_pp ON hpd_pp.id = hp.parent_permlink_id - JOIN hive_accounts ha_ra ON ha_ra.id = hp.root_author_id - JOIN hive_permlink_data hpd_rp ON hpd_rp.id = hp.root_permlink_id LEFT OUTER JOIN hive_communities hc ON (hp.community_id = hc.id) LEFT OUTER JOIN hive_roles hr ON (hp.author_id = hr.account_id AND hp.community_id = hr.community_id) ; @@ -712,7 +724,8 @@ def setup(db): weight, num_changes, hpd.id as permlink_id, - post_id + post_id, + is_effective FROM hive_votes hv INNER JOIN hive_accounts ha_v ON ha_v.id = hv.voter_id @@ -722,6 +735,26 @@ def setup(db): """ db.query_no_return(sql) + sql = """ + DROP FUNCTION IF EXISTS find_comment_id(character varying, character varying) + ; + CREATE OR REPLACE FUNCTION find_comment_id( + in _author hive_accounts.name%TYPE, + in _permlink hive_permlink_data.permlink%TYPE) + RETURNS INT AS + $function$ + SELECT COALESCE( (SELECT hp.id + FROM hive_posts hp + JOIN hive_accounts ha ON ha.id = hp.author_id + JOIN hive_permlink_data hpd ON hpd.id = hp.permlink_id + WHERE ha.name = _author AND hpd.permlink = _permlink + ), 0 ); + $function$ + LANGUAGE sql + ; + """ + db.query_no_return(sql) + sql = """ DROP TYPE IF EXISTS database_api_post CASCADE; CREATE TYPE database_api_post AS ( @@ -735,7 +768,8 @@ def setup(db): depth SMALLINT, promoted DECIMAL(10,3), payout DECIMAL(10,3), - payout_at TIMESTAMP, + last_payout_at TIMESTAMP, + cashout_time TIMESTAMP, is_paidout BOOLEAN, children INT, votes INT, @@ -745,7 +779,9 @@ def setup(db): json TEXT, is_hidden BOOLEAN, is_grayed BOOLEAN, - total_votes INT, + total_votes BIGINT, + net_votes BIGINT, + total_vote_weight NUMERIC, flag_weight REAL, parent_author VARCHAR(16), parent_permlink VARCHAR(255), @@ -760,7 +796,7 @@ def setup(db): beneficiaries JSON, url TEXT, root_title VARCHAR(512), - abs_rshares BIGINT, + abs_rshares NUMERIC, active TIMESTAMP, author_rewards BIGINT, max_cashout_time TIMESTAMP, @@ -778,14 +814,17 @@ def setup(db): RETURNS SETOF database_api_post AS $function$ + DECLARE + __post_id INT; BEGIN + __post_id = find_comment_id(_author,_permlink); RETURN QUERY SELECT hp.id, hp.community_id, hp.author, hp.permlink, hp.title, hp.body, - hp.category, hp.depth, hp.promoted, hp.payout, hp.payout_at, hp.is_paidout, + hp.category, hp.depth, hp.promoted, hp.payout, hp.last_payout_at, hp.cashout_time, hp.is_paidout, hp.children, hp.votes, hp.created_at, hp.updated_at, hp.rshares, hp.json, - hp.is_hidden, hp.is_grayed, hp.total_votes, hp.flag_weight, hp.parent_author, - hp.parent_permlink, hp.curator_payout_value, hp.root_author, hp.root_permlink, + hp.is_hidden, hp.is_grayed, hp.total_votes, hp.net_votes, hp.total_vote_weight, hp.flag_weight, + hp.parent_author, hp.parent_permlink, hp.curator_payout_value, hp.root_author, hp.root_permlink, hp.max_accepted_payout, hp.percent_hbd, hp.allow_replies, hp.allow_votes, hp.allow_curation_rewards, hp.beneficiaries, hp.url, hp.root_title, hp.abs_rshares, hp.active, hp.author_rewards, hp.max_cashout_time, hp.reward_weight @@ -793,10 +832,9 @@ def setup(db): hive_posts_view hp WHERE NOT hp.is_muted AND - hp.counter_deleted == 0 AND - -- ABW: wrong! fat node required _author+_permlink to exist (when given) and sorted by ( cashout_time, comment_id ) - hp.cashout_time >= _cashout_time AND - hp.id >= (SELECT id FROM hive_posts_view hp1 WHERE hp1.author >= _author AND hp1.permlink >= _permlink ORDER BY id LIMIT 1) + hp.counter_deleted = 0 AND + hp.cashout_time > _cashout_time OR + hp.cashout_time = _cashout_time AND hp.id >= __post_id ORDER BY hp.cashout_time ASC, hp.id ASC @@ -821,10 +859,10 @@ def setup(db): RETURN QUERY SELECT hp.id, hp.community_id, hp.author, hp.permlink, hp.title, hp.body, - hp.category, hp.depth, hp.promoted, hp.payout, hp.payout_at, hp.is_paidout, + hp.category, hp.depth, hp.promoted, hp.payout, hp.last_payout_at, hp.cashout_time, hp.is_paidout, hp.children, hp.votes, hp.created_at, hp.updated_at, hp.rshares, hp.json, - hp.is_hidden, hp.is_grayed, hp.total_votes, hp.flag_weight, hp.parent_author, - hp.parent_permlink, hp.curator_payout_value, hp.root_author, hp.root_permlink, + hp.is_hidden, hp.is_grayed, hp.total_votes, hp.net_votes, hp.total_vote_weight, hp.flag_weight, + hp.parent_author, hp.parent_permlink, hp.curator_payout_value, hp.root_author, hp.root_permlink, hp.max_accepted_payout, hp.percent_hbd, hp.allow_replies, hp.allow_votes, hp.allow_curation_rewards, hp.beneficiaries, hp.url, hp.root_title, hp.abs_rshares, hp.active, hp.author_rewards, hp.max_cashout_time, hp.reward_weight @@ -833,11 +871,11 @@ def setup(db): WHERE NOT hp.is_muted AND hp.counter_deleted = 0 AND - hp.author > _author COLLATE "C" OR - hp.author = _author AND hp.permlink >= _permlink COLLATE "C" + hp.author > _author OR + hp.author = _author AND hp.permlink >= _permlink ORDER BY - hp.author COLLATE "C" ASC, - hp.permlink COLLATE "C" ASC + hp.author ASC, + hp.permlink ASC LIMIT _limit ; @@ -857,14 +895,19 @@ def setup(db): RETURNS SETOF database_api_post AS $function$ + DECLARE + __root_id INT; + __post_id INT; BEGIN + __root_id = find_comment_id(_root_author,_root_permlink); + __post_id = find_comment_id(_start_post_author,_start_post_permlink); RETURN QUERY SELECT hp.id, hp.community_id, hp.author, hp.permlink, hp.title, hp.body, - hp.category, hp.depth, hp.promoted, hp.payout, hp.payout_at, hp.is_paidout, + hp.category, hp.depth, hp.promoted, hp.payout, hp.last_payout_at, hp.cashout_time, hp.is_paidout, hp.children, hp.votes, hp.created_at, hp.updated_at, hp.rshares, hp.json, - hp.is_hidden, hp.is_grayed, hp.total_votes, hp.flag_weight, hp.parent_author, - hp.parent_permlink, hp.curator_payout_value, hp.root_author, hp.root_permlink, + hp.is_hidden, hp.is_grayed, hp.total_votes, hp.net_votes, hp.total_vote_weight, hp.flag_weight, + hp.parent_author, hp.parent_permlink, hp.curator_payout_value, hp.root_author, hp.root_permlink, hp.max_accepted_payout, hp.percent_hbd, hp.allow_replies, hp.allow_votes, hp.allow_curation_rewards, hp.beneficiaries, hp.url, hp.root_title, hp.abs_rshares, hp.active, hp.author_rewards, hp.max_cashout_time, hp.reward_weight @@ -873,14 +916,11 @@ def setup(db): WHERE NOT hp.is_muted AND hp.counter_deleted = 0 AND - -- ABW: wrong! fat node required both _root_author+_root_permlink and _start_post_author+start_post_permlink to exist (when given) - -- and sorted by ( root_id, comment_id ) - root_author >= _root_author AND - root_permlink >= _root_permlink AND - hp.id >= (SELECT id FROM hive_posts_view hp1 WHERE hp1.author >= _start_post_author AND hp1.permlink >= _start_post_permlink ORDER BY id LIMIT 1) + hp.root_id > __root_id OR + hp.root_id = __root_id AND + hp.id >= __post_id ORDER BY - root_author ASC, - root_permlink ASC, + root_id ASC, id ASC LIMIT _limit @@ -901,14 +941,17 @@ def setup(db): RETURNS SETOF database_api_post AS $function$ + DECLARE + __post_id INT; BEGIN + __post_id = find_comment_id(_start_post_author,_start_post_permlink); RETURN QUERY SELECT hp.id, hp.community_id, hp.author, hp.permlink, hp.title, hp.body, - hp.category, hp.depth, hp.promoted, hp.payout, hp.payout_at, hp.is_paidout, + hp.category, hp.depth, hp.promoted, hp.payout, hp.last_payout_at, hp.cashout_time, hp.is_paidout, hp.children, hp.votes, hp.created_at, hp.updated_at, hp.rshares, hp.json, - hp.is_hidden, hp.is_grayed, hp.total_votes, hp.flag_weight, hp.parent_author, - hp.parent_permlink, hp.curator_payout_value, hp.root_author, hp.root_permlink, + hp.is_hidden, hp.is_grayed, hp.total_votes, hp.net_votes, hp.total_vote_weight, hp.flag_weight, + hp.parent_author, hp.parent_permlink, hp.curator_payout_value, hp.root_author, hp.root_permlink, hp.max_accepted_payout, hp.percent_hbd, hp.allow_replies, hp.allow_votes, hp.allow_curation_rewards, hp.beneficiaries, hp.url, hp.root_title, hp.abs_rshares, hp.active, hp.author_rewards, hp.max_cashout_time, hp.reward_weight @@ -917,11 +960,9 @@ def setup(db): WHERE NOT hp.is_muted AND hp.counter_deleted = 0 AND - -- ABW: wrong! fat node required _start_post_author+_start_port_permlink to exist (when given) and sorted by ( parent_author, parent_permlink, comment_id ) - parent_author > _parent_author COLLATE "C" OR - parent_author = _parent_author AND ( parent_permlink > _parent_permlink COLLATE "C" OR - parent_permlink = _parent_permlink AND - hp.id >= (SELECT id FROM hive_posts_view hp1 WHERE hp1.author >= _start_post_author AND hp1.permlink >= _start_post_permlink ORDER BY id LIMIT 1) ) + parent_author > _parent_author OR + parent_author = _parent_author AND ( parent_permlink > _parent_permlink OR + parent_permlink = _parent_permlink AND hp.id >= __post_id ) ORDER BY parent_author ASC, parent_permlink ASC, @@ -945,14 +986,17 @@ def setup(db): RETURNS SETOF database_api_post AS $function$ + DECLARE + __post_id INT; BEGIN + __post_id = find_comment_id(_start_post_author,_start_post_permlink); RETURN QUERY SELECT hp.id, hp.community_id, hp.author, hp.permlink, hp.title, hp.body, - hp.category, hp.depth, hp.promoted, hp.payout, hp.payout_at, hp.is_paidout, + hp.category, hp.depth, hp.promoted, hp.payout, hp.last_payout_at, hp.cashout_time, hp.is_paidout, hp.children, hp.votes, hp.created_at, hp.updated_at, hp.rshares, hp.json, - hp.is_hidden, hp.is_grayed, hp.total_votes, hp.flag_weight, hp.parent_author, - hp.parent_permlink, hp.curator_payout_value, hp.root_author, hp.root_permlink, + hp.is_hidden, hp.is_grayed, hp.total_votes, hp.net_votes, hp.total_vote_weight, hp.flag_weight, + hp.parent_author, hp.parent_permlink, hp.curator_payout_value, hp.root_author, hp.root_permlink, hp.max_accepted_payout, hp.percent_hbd, hp.allow_replies, hp.allow_votes, hp.allow_curation_rewards, hp.beneficiaries, hp.url, hp.root_title, hp.abs_rshares, hp.active, hp.author_rewards, hp.max_cashout_time, hp.reward_weight @@ -961,10 +1005,9 @@ def setup(db): WHERE NOT hp.is_muted AND hp.counter_deleted = 0 AND - -- ABW: wrong! fat node required _start_post_author+_start_port_permlink to exist (when given) and sorted by ( _parent_author, updated_at, comment_id ) - hp.parent_author > _parent_author COLLATE "C" OR - hp.parent_author = _parent_author AND hp.updated_at >= _updated_at AND - hp.id >= (SELECT id FROM hive_posts_view hp1 WHERE hp1.author >= _start_post_author AND hp1.permlink >= _start_post_permlink ORDER BY id LIMIT 1) + hp.parent_author > _parent_author OR + hp.parent_author = _parent_author AND ( hp.updated_at > _updated_at OR + hp.updated_at = _updated_at AND hp.id >= __post_id ) ORDER BY hp.parent_author ASC, hp.updated_at ASC, @@ -976,6 +1019,7 @@ def setup(db): $function$ LANGUAGE plpgsql ; + DROP FUNCTION IF EXISTS list_comments_by_author_last_update(character varying, timestamp, character varying, character varying, int) ; CREATE OR REPLACE FUNCTION list_comments_by_author_last_update( @@ -987,14 +1031,17 @@ def setup(db): RETURNS SETOF database_api_post AS $function$ + DECLARE + __post_id INT; BEGIN + __post_id = find_comment_id(_start_post_author,_start_post_permlink); RETURN QUERY SELECT hp.id, hp.community_id, hp.author, hp.permlink, hp.title, hp.body, - hp.category, hp.depth, hp.promoted, hp.payout, hp.payout_at, hp.is_paidout, + hp.category, hp.depth, hp.promoted, hp.payout, hp.last_payout_at, hp.cashout_time, hp.is_paidout, hp.children, hp.votes, hp.created_at, hp.updated_at, hp.rshares, hp.json, - hp.is_hidden, hp.is_grayed, hp.total_votes, hp.flag_weight, hp.parent_author, - hp.parent_permlink, hp.curator_payout_value, hp.root_author, hp.root_permlink, + hp.is_hidden, hp.is_grayed, hp.total_votes, hp.net_votes, hp.total_vote_weight, hp.flag_weight, + hp.parent_author, hp.parent_permlink, hp.curator_payout_value, hp.root_author, hp.root_permlink, hp.max_accepted_payout, hp.percent_hbd, hp.allow_replies, hp.allow_votes, hp.allow_curation_rewards, hp.beneficiaries, hp.url, hp.root_title, hp.abs_rshares, hp.active, hp.author_rewards, hp.max_cashout_time, hp.reward_weight @@ -1004,12 +1051,12 @@ def setup(db): NOT hp.is_muted AND hp.counter_deleted = 0 AND -- ABW: wrong! fat node required _start_post_author+_start_post_permlink to exist (when given) and sorted just like - -- in case of by_last_update (but in fat node) but should by ( _author, updated_at, comment_id ) - hp.author > _author COLLATE "C" OR - hp.author = _author AND hp.updated_at >= _updated_at AND - hp.id >= (SELECT id FROM hive_posts_view hp1 WHERE hp1.author > _start_post_author COLLATE "C" OR hp1.author = _start_post_author AND hp1.permlink >= _start_post_permlink COLLATE "C" ORDER BY id LIMIT 1) + -- in case of by_last_update (bug in fat node) but should by ( _author, updated_at, comment_id ) + hp.author > _author OR + hp.author = _author AND ( hp.updated_at > _updated_at OR + hp.updated_at = _updated_at AND hp.id >= __post_id ) ORDER BY - hp.parent_author ASC, + hp.author ASC, hp.updated_at ASC, hp.id ASC LIMIT @@ -1112,41 +1159,41 @@ def setup(db): db.query_no_return(sql) sql = """ - DROP FUNCTION IF EXISTS public.calculate_rhsares_part_of_hot_and_trend(_rshares hive_votes.rshares%TYPE) CASCADE - ; - CREATE OR REPLACE FUNCTION public.calculate_rhsares_part_of_hot_and_trend(_rshares hive_votes.rshares%TYPE) - RETURNS double precision - LANGUAGE 'plpgsql' - IMMUTABLE - AS $BODY$ - DECLARE - mod_score double precision; - BEGIN - mod_score := _rshares / 10000000.0; - IF ( mod_score > 0 ) - THEN - return log( greatest( abs(mod_score), 1 ) ); - END IF; - return -1.0 * log( greatest( abs(mod_score), 1 ) ); - END; - $BODY$; + DROP FUNCTION IF EXISTS public.calculate_rhsares_part_of_hot_and_trend(_rshares hive_votes.rshares%TYPE) CASCADE + ; + CREATE OR REPLACE FUNCTION public.calculate_rhsares_part_of_hot_and_trend(_rshares hive_votes.rshares%TYPE) + RETURNS double precision + LANGUAGE 'plpgsql' + IMMUTABLE + AS $BODY$ + DECLARE + mod_score double precision; + BEGIN + mod_score := _rshares / 10000000.0; + IF ( mod_score > 0 ) + THEN + return log( greatest( abs(mod_score), 1 ) ); + END IF; + return -1.0 * log( greatest( abs(mod_score), 1 ) ); + END; + $BODY$; """ db.query_no_return(sql) sql = """ - DROP FUNCTION IF EXISTS public.calculate_hot(hive_votes.rshares%TYPE, hive_posts.created_at%TYPE) - ; - CREATE OR REPLACE FUNCTION public.calculate_hot( - _rshares hive_votes.rshares%TYPE, - _post_created_at hive_posts.created_at%TYPE) - RETURNS hive_posts.sc_hot%TYPE - LANGUAGE 'plpgsql' - IMMUTABLE - AS $BODY$ - BEGIN - return calculate_rhsares_part_of_hot_and_trend(_rshares) + calculate_time_part_of_hot( _post_created_at ); - END; - $BODY$; + DROP FUNCTION IF EXISTS public.calculate_hot(hive_votes.rshares%TYPE, hive_posts.created_at%TYPE) + ; + CREATE OR REPLACE FUNCTION public.calculate_hot( + _rshares hive_votes.rshares%TYPE, + _post_created_at hive_posts.created_at%TYPE) + RETURNS hive_posts.sc_hot%TYPE + LANGUAGE 'plpgsql' + IMMUTABLE + AS $BODY$ + BEGIN + return calculate_rhsares_part_of_hot_and_trend(_rshares) + calculate_time_part_of_hot( _post_created_at ); + END; + $BODY$; """ db.query_no_return(sql) @@ -1161,19 +1208,19 @@ def setup(db): db.query_no_return(sql) sql = """ - DROP FUNCTION IF EXISTS public.calculate_tranding(hive_votes.rshares%TYPE, hive_posts.created_at%TYPE) - ; - CREATE OR REPLACE FUNCTION public.calculate_tranding( - _rshares hive_votes.rshares%TYPE, - _post_created_at hive_posts.created_at%TYPE) - RETURNS hive_posts.sc_trend%TYPE - LANGUAGE 'plpgsql' - IMMUTABLE - AS $BODY$ - BEGIN - return calculate_rhsares_part_of_hot_and_trend(_rshares) + calculate_time_part_of_trending( _post_created_at ); - END; - $BODY$; + DROP FUNCTION IF EXISTS public.calculate_tranding(hive_votes.rshares%TYPE, hive_posts.created_at%TYPE) + ; + CREATE OR REPLACE FUNCTION public.calculate_tranding( + _rshares hive_votes.rshares%TYPE, + _post_created_at hive_posts.created_at%TYPE) + RETURNS hive_posts.sc_trend%TYPE + LANGUAGE 'plpgsql' + IMMUTABLE + AS $BODY$ + BEGIN + return calculate_rhsares_part_of_hot_and_trend(_rshares) + calculate_time_part_of_trending( _post_created_at ); + END; + $BODY$; """ db.query_no_return(sql) diff --git a/hive/indexer/blocks.py b/hive/indexer/blocks.py index 8c0e26d82ac3bebfb7009b8bc130aa37946e2c22..cf5e085aeac22f5d672f1ac9385e38af419a07b8 100644 --- a/hive/indexer/blocks.py +++ b/hive/indexer/blocks.py @@ -105,7 +105,7 @@ class Blocks: def prepare_vops(comment_payout_ops, vopsList, date, block_num): vote_ops = {} - inefficient_deleted_ops = {} + ineffective_deleted_ops = {} registered_ops_stats = [ 'author_reward_operation', 'comment_reward_operation', 'effective_comment_vote_operation', 'comment_payout_update_operation', 'ineffective_delete_comment_operation'] for vop in vopsList: @@ -147,12 +147,12 @@ class Blocks: comment_payout_ops[key][op_type] = op_value elif op_type == 'ineffective_delete_comment_operation': - inefficient_deleted_ops[key] = {} + ineffective_deleted_ops[key] = {} if op_type in registered_ops_stats: OPSM.op_stats(op_type, OPSM.stop(start)) - return (vote_ops, inefficient_deleted_ops) + return (vote_ops, ineffective_deleted_ops) @classmethod @@ -172,14 +172,14 @@ class Blocks: vote_ops = None comment_payout_stats = None - inefficient_deleted_ops = None + ineffective_deleted_ops = None if is_initial_sync: if num in virtual_operations: - (vote_ops, inefficient_deleted_ops ) = Blocks.prepare_vops(Posts.comment_payout_ops, virtual_operations[num], cls._current_block_date, num) + (vote_ops, ineffective_deleted_ops ) = Blocks.prepare_vops(Posts.comment_payout_ops, virtual_operations[num], cls._current_block_date, num) else: vops = hived.get_virtual_operations(num) - (vote_ops, inefficient_deleted_ops ) = Blocks.prepare_vops(Posts.comment_payout_ops, vops, cls._current_block_date, num) + (vote_ops, ineffective_deleted_ops ) = Blocks.prepare_vops(Posts.comment_payout_ops, vops, cls._current_block_date, num) json_ops = [] for tx_idx, tx in enumerate(block['transactions']): @@ -221,8 +221,8 @@ class Blocks: Accounts.dirty(op['author']) # lite - stats elif op_type == 'delete_comment_operation': key = "{}/{}".format(op['author'], op['permlink']) - if ( inefficient_deleted_ops is None ) or ( key not in inefficient_deleted_ops ): - Posts.delete_op(op) + if ( ineffective_deleted_ops is None ) or ( key not in ineffective_deleted_ops ): + Posts.delete_op(op) elif op_type == 'comment_options_operation': Posts.comment_options_op(op) elif op_type == 'vote_operation': diff --git a/hive/indexer/posts.py b/hive/indexer/posts.py index 4f2b5350f08146194db8117c43c899c2e78d0396..329ce40a28ae3d38a1b76f45bc5a6fd22c0f7b7c 100644 --- a/hive/indexer/posts.py +++ b/hive/indexer/posts.py @@ -89,7 +89,7 @@ class Posts: """Register new/edited/undeleted posts; insert into feed cache.""" sql = """ - SELECT is_new_post, id, author_id, permlink_id, post_category, parent_id, community_id, is_valid, is_muted, depth, is_edited + SELECT is_new_post, id, author_id, permlink_id, post_category, parent_id, community_id, is_valid, is_muted, depth FROM process_hive_post_operation((:author)::varchar, (:permlink)::varchar, (:parent_author)::varchar, (:parent_permlink)::varchar, (:date)::timestamp, (:community_support_start_date)::timestamp); """ @@ -155,15 +155,17 @@ class Posts: UPDATE hive_posts AS ihp SET total_payout_value = COALESCE( data_source.total_payout_value, ihp.total_payout_value ), curator_payout_value = COALESCE( data_source.curator_payout_value, ihp.curator_payout_value ), - author_rewards = COALESCE( CAST( data_source.author_rewards as INT8 ), ihp.author_rewards ), - author_rewards_hive = COALESCE( CAST( data_source.author_rewards_hive as INT8 ), ihp.author_rewards_hive ), - author_rewards_hbd = COALESCE( CAST( data_source.author_rewards_hbd as INT8 ), ihp.author_rewards_hbd ), - author_rewards_vests = COALESCE( CAST( data_source.author_rewards_vests as INT8 ), ihp.author_rewards_vests ), + author_rewards = COALESCE( CAST( data_source.author_rewards as BIGINT ), ihp.author_rewards ), + author_rewards_hive = COALESCE( CAST( data_source.author_rewards_hive as BIGINT ), ihp.author_rewards_hive ), + author_rewards_hbd = COALESCE( CAST( data_source.author_rewards_hbd as BIGINT ), ihp.author_rewards_hbd ), + author_rewards_vests = COALESCE( CAST( data_source.author_rewards_vests as BIGINT ), ihp.author_rewards_vests ), payout = COALESCE( CAST( data_source.payout as DECIMAL ), ihp.payout ), pending_payout = COALESCE( CAST( data_source.pending_payout as DECIMAL ), ihp.pending_payout ), payout_at = COALESCE( CAST( data_source.payout_at as TIMESTAMP ), ihp.payout_at ), + last_payout_at = COALESCE( CAST( data_source.last_payout_at as TIMESTAMP ), ihp.last_payout_at ), cashout_time = COALESCE( CAST( data_source.cashout_time as TIMESTAMP ), ihp.cashout_time ), - is_paidout = COALESCE( CAST( data_source.is_paidout as BOOLEAN ), ihp.is_paidout ) + is_paidout = COALESCE( CAST( data_source.is_paidout as BOOLEAN ), ihp.is_paidout ), + total_vote_weight = COALESCE( CAST( data_source.total_vote_weight as NUMERIC ), ihp.total_vote_weight ) FROM ( SELECT ha_a.id as author_id, hpd_p.id as permlink_id, @@ -176,8 +178,10 @@ class Posts: t.payout, t.pending_payout, t.payout_at, + t.last_payout_at, t.cashout_time, - t.is_paidout + t.is_paidout, + t.total_vote_weight from ( VALUES @@ -193,11 +197,13 @@ class Posts: payout, pending_payout, payout_at, + last_payout_at, cashout_time, - is_paidout) + is_paidout, + total_vote_weight) INNER JOIN hive_accounts ha_a ON ha_a.name = t.author INNER JOIN hive_permlink_data hpd_p ON hpd_p.permlink = t.permlink - ) as data_source(author_id, permlink_id, total_payout_value) + ) as data_source WHERE ihp.permlink_id = data_source.permlink_id and ihp.author_id = data_source.author_id """ @@ -241,10 +247,13 @@ class Posts: pending_payout = None payout_at = None + last_payout_at = None cashout_time = None is_paidout = None + total_vote_weight = None + date = v[ 'date' ] if v[ 'author_reward_operation' ] is not None: @@ -267,6 +276,7 @@ class Posts: payout = sum([ sbd_amount(total_payout_value), sbd_amount(curator_payout_value) ]) pending_payout = 0 + last_payout_at = date if author is None: author = value['author'] @@ -274,7 +284,8 @@ class Posts: if v[ 'effective_comment_vote_operation' ] is not None: value = v[ 'effective_comment_vote_operation' ] - pending_payout = sbd_amount( value['pending_payout'] ) + pending_payout = sbd_amount( value['pending_payout'] ) + total_vote_weight = value['total_vote_weight'] if author is None: author = value['author'] permlink = value['permlink'] @@ -299,9 +310,10 @@ class Posts: #Calculations of all dates if ( is_paidout is not None ): payout_at = date + last_payout_at = date cashout_time = "1969-12-31T23:59:59" - cls._comment_payout_ops.append("('{}', '{}', {}, {}, {}, {}, {}, {}, {}, {}, {}, {}, {})".format( + cls._comment_payout_ops.append("('{}', '{}', {}, {}, {}, {}, {}, {}, {}, {}, {}, {}, {}, {}, {})".format( author, permlink, "NULL" if ( total_payout_value is None ) else ( "'{}'".format( legacy_amount(total_payout_value) ) ), @@ -314,9 +326,13 @@ class Posts: "NULL" if ( pending_payout is None ) else pending_payout, "NULL" if ( payout_at is None ) else ( "'{}'::timestamp".format( payout_at ) ), + "NULL" if ( last_payout_at is None ) else ( "'{}'::timestamp".format( last_payout_at ) ), "NULL" if ( cashout_time is None ) else ( "'{}'::timestamp".format( cashout_time ) ), - "NULL" if ( is_paidout is None ) else is_paidout )) + "NULL" if ( is_paidout is None ) else is_paidout, + + "NULL" if ( total_vote_weight is None ) else total_vote_weight )) + n = len(cls.comment_payout_ops) cls.comment_payout_ops.clear() diff --git a/hive/indexer/votes.py b/hive/indexer/votes.py index 955fa31a9cf4162e5ba8376feaff200158f9759d..e01006c72c3eaf6cddd9a47623cb269ca8a88bee 100644 --- a/hive/indexer/votes.py +++ b/hive/indexer/votes.py @@ -1,206 +1,131 @@ -""" Votes indexing and processing """ - -import logging - -from hive.db.db_state import DbState -from hive.db.adapter import Db -from hive.utils.trends import update_hot_and_tranding_for_block_range - -log = logging.getLogger(__name__) -DB = Db.instance() - -class Votes: - """ Class for managing posts votes """ - _votes_data = {} - - @classmethod - def get_vote_count(cls, author, permlink): - """ Get vote count for given post """ - sql = """ - SELECT count(1) - FROM hive_votes_accounts_permlinks_view hv - WHERE hv.author = :author AND hv.permlink = :permlink - """ - ret = DB.query_row(sql, author=author, permlink=permlink) - return 0 if ret is None else int(ret.count) - - @classmethod - def get_upvote_count(cls, author, permlink): - """ Get vote count for given post """ - sql = """ - SELECT count(1) - FROM hive_votes_accounts_permlinks_view hv - WHERE hv.author = :author AND hv.permlink = :permlink - AND hv.percent > 0 - """ - ret = DB.query_row(sql, author=author, permlink=permlink) - return 0 if ret is None else int(ret.count) - - @classmethod - def get_downvote_count(cls, author, permlink): - """ Get vote count for given post """ - sql = """ - SELECT count(1) - FROM hive_votes_accounts_permlinks_view hv - WHERE hv.author = :author AND hv.permlink = :permlink - AND hv.percent < 0 - """ - ret = DB.query_row(sql, author=author, permlink=permlink) - return 0 if ret is None else int(ret.count) - - @classmethod - def get_total_vote_weight(cls, author, permlink): - """ Get total vote weight for selected post """ - sql = """ - SELECT - sum(weight) - FROM - hive_votes_accounts_permlinks_view hv - WHERE - hv.author = :author AND - hv.permlink = :permlink - """ - ret = DB.query_row(sql, author=author, permlink=permlink) - return 0 if ret is None else int(0 if ret.sum is None else ret.sum) - - @classmethod - def get_total_vote_rshares(cls, author, permlink): - """ Get total vote rshares for selected post """ - sql = """ - SELECT - sum(rshares) - FROM - hive_votes_accounts_permlinks_view hv - WHERE - hv.author = :author AND - hv.permlink = :permlink - """ - ret = DB.query_row(sql, author=author, permlink=permlink) - return 0 if ret is None else int(0 if ret.sum is None else ret.sum) - - inside_flush = False - - @classmethod - def vote_op(cls, vote_operation, date): - """ Process vote_operation """ - voter = vote_operation['voter'] - author = vote_operation['author'] - permlink = vote_operation['permlink'] - weight = vote_operation['weight'] - block_num = vote_operation['block_num'] - - if cls.inside_flush: - log.exception("Adding new vote-info into '_votes_data' dict") - raise RuntimeError("Fatal error") - - key = voter + "/" + author + "/" + permlink - - if key in cls._votes_data: - cls._votes_data[key]["vote_percent"] = weight - cls._votes_data[key]["last_update"] = date - cls._votes_data[key]["block_num"] = block_num - else: - cls._votes_data[key] = dict(voter=voter, - author=author, - permlink=permlink, - vote_percent=weight, - weight=0, - rshares=0, - last_update=date, - is_effective=False, - block_num=block_num) - - @classmethod - def effective_comment_vote_op(cls, key, vop): - """ Process effective_comment_vote_operation """ - - if cls.inside_flush: - log.exception("Updating data in '_votes_data' using effective comment") - raise RuntimeError("Fatal error") - - assert key in cls._votes_data - - cls._votes_data[key]["weight"] = vop["weight"] - cls._votes_data[key]["rshares"] = vop["rshares"] - cls._votes_data[key]["is_effective"] = True - cls._votes_data[key]["block_num"] = vop['block_num'] - - @classmethod - def flush(cls): - """ Flush vote data from cache to database """ - cls.inside_flush = True - n = 0 - if cls._votes_data: - sql = """ - INSERT INTO hive_votes - (post_id, voter_id, author_id, permlink_id, weight, rshares, vote_percent, last_update, block_num) - SELECT hp.id as post_id, ha_v.id as voter_id, ha_a.id as author_id, hpd_p.id as permlink_id, t.weight, t.rshares, t.vote_percent, t.last_update, t.block_num - FROM - ( - VALUES - -- voter, author, permlink, weight, rshares, vote_percent, last_update, block_num - {} - ) AS T(voter, author, permlink, weight, rshares, vote_percent, last_update, block_num) - INNER JOIN hive_accounts ha_v ON ha_v.name = t.voter - INNER JOIN hive_accounts ha_a ON ha_a.name = t.author - INNER JOIN hive_permlink_data hpd_p ON hpd_p.permlink = t.permlink - INNER JOIN hive_posts hp ON hp.author_id = ha_a.id AND hp.permlink_id = hpd_p.id - WHERE hp.counter_deleted = 0 - ON CONFLICT ON CONSTRAINT hive_votes_ux1 DO - UPDATE - SET - weight = {}.weight, - rshares = {}.rshares, - vote_percent = EXCLUDED.vote_percent, - last_update = EXCLUDED.last_update, - num_changes = hive_votes.num_changes + 1 - WHERE hive_votes.voter_id = EXCLUDED.voter_id and hive_votes.author_id = EXCLUDED.author_id and hive_votes.permlink_id = EXCLUDED.permlink_id; - """ - # WHERE clause above seems superfluous (and works all the same without it, at least up to 5mln) - - values_skip = [] - values_override = [] - values_limit = 1000 - first_block = 0 - last_block = 0 - - for _, vd in cls._votes_data.items(): - values = None - on_conflict_data_source = None - first_block = min( first_block, vd['block_num'] ) - last_block = max( last_block, vd['block_num'] ) - - if vd['is_effective']: - values = values_override - on_conflict_data_source = 'EXCLUDED' - else: - values = values_skip - on_conflict_data_source = 'hive_votes' - - values.append("('{}', '{}', '{}', {}, {}, {}, '{}'::timestamp, {})".format( - vd['voter'], vd['author'], vd['permlink'], vd['weight'], vd['rshares'], vd['vote_percent'], vd['last_update'], vd['block_num'])) - - if len(values) >= values_limit: - values_str = ','.join(values) - actual_query = sql.format(values_str, on_conflict_data_source, on_conflict_data_source) - DB.query(actual_query) - values.clear() - - if len(values_skip) > 0: - values_str = ','.join(values_skip) - actual_query = sql.format(values_str, 'hive_votes', 'hive_votes') - DB.query(actual_query) - values_skip.clear() - if len(values_override) > 0: - values_str = ','.join(values_override) - actual_query = sql.format(values_str, 'EXCLUDED', 'EXCLUDED') - DB.query(actual_query) - values_override.clear() - - n = len(cls._votes_data) - if not DbState.is_initial_sync(): - update_hot_and_tranding_for_block_range( first_block, last_block ) - cls._votes_data.clear() - cls.inside_flush = False - return n - +""" Votes indexing and processing """ + +import logging + +from hive.db.db_state import DbState +from hive.db.adapter import Db +from hive.utils.trends import update_hot_and_tranding_for_block_range + +log = logging.getLogger(__name__) +DB = Db.instance() + +class Votes: + """ Class for managing posts votes """ + _votes_data = {} + + inside_flush = False + + @classmethod + def vote_op(cls, vote_operation, date): + """ Process vote_operation """ + voter = vote_operation['voter'] + author = vote_operation['author'] + permlink = vote_operation['permlink'] + weight = vote_operation['weight'] + block_num = vote_operation['block_num'] + + if cls.inside_flush: + log.exception("Adding new vote-info into '_votes_data' dict") + raise RuntimeError("Fatal error") + + key = voter + "/" + author + "/" + permlink + + if key in cls._votes_data: + cls._votes_data[key]["vote_percent"] = weight + cls._votes_data[key]["last_update"] = date + cls._votes_data[key]["block_num"] = block_num + else: + cls._votes_data[key] = dict(voter=voter, + author=author, + permlink=permlink, + vote_percent=weight, + weight=0, + rshares=0, + last_update=date, + is_effective=False, + block_num=block_num) + + @classmethod + def effective_comment_vote_op(cls, key, vop): + """ Process effective_comment_vote_operation """ + + if cls.inside_flush: + log.exception("Updating data in '_votes_data' using effective comment") + raise RuntimeError("Fatal error") + + assert key in cls._votes_data + + cls._votes_data[key]["weight"] = vop["weight"] + cls._votes_data[key]["rshares"] = vop["rshares"] + cls._votes_data[key]["is_effective"] = True + cls._votes_data[key]["block_num"] = vop['block_num'] + + @classmethod + def flush(cls): + """ Flush vote data from cache to database """ + cls.inside_flush = True + n = 0 + if cls._votes_data: + sql = """ + INSERT INTO hive_votes + (post_id, voter_id, author_id, permlink_id, weight, rshares, vote_percent, last_update, block_num, is_effective) + + SELECT hp.id as post_id, ha_v.id as voter_id, ha_a.id as author_id, hpd_p.id as permlink_id, + t.weight, t.rshares, t.vote_percent, t.last_update, t.block_num, t.is_effective + FROM + ( + VALUES + -- voter, author, permlink, weight, rshares, vote_percent, last_update, block_num, is_effective + {} + ) AS T(voter, author, permlink, weight, rshares, vote_percent, last_update, block_num, is_effective) + INNER JOIN hive_accounts ha_v ON ha_v.name = t.voter + INNER JOIN hive_accounts ha_a ON ha_a.name = t.author + INNER JOIN hive_permlink_data hpd_p ON hpd_p.permlink = t.permlink + INNER JOIN hive_posts hp ON hp.author_id = ha_a.id AND hp.permlink_id = hpd_p.id + WHERE hp.counter_deleted = 0 + ON CONFLICT ON CONSTRAINT hive_votes_ux1 DO + UPDATE + SET + weight = CASE EXCLUDED.is_effective WHEN true THEN EXCLUDED.weight ELSE hive_votes.weight END, + rshares = CASE EXCLUDED.is_effective WHEN true THEN EXCLUDED.rshares ELSE hive_votes.rshares END, + vote_percent = EXCLUDED.vote_percent, + last_update = EXCLUDED.last_update, + num_changes = hive_votes.num_changes + 1 + WHERE hive_votes.voter_id = EXCLUDED.voter_id and hive_votes.author_id = EXCLUDED.author_id and hive_votes.permlink_id = EXCLUDED.permlink_id; + """ + # WHERE clause above seems superfluous (and works all the same without it, at least up to 5mln) + + values = [] + values_limit = 1000 + first_block = 0 + last_block = 0 + + for _, vd in cls._votes_data.items(): + + first_block = min( first_block, vd['block_num'] ) + last_block = max( last_block, vd['block_num'] ) + + values.append("('{}', '{}', '{}', {}, {}, {}, '{}'::timestamp, {}, {})".format( + vd['voter'], vd['author'], vd['permlink'], vd['weight'], vd['rshares'], + vd['vote_percent'], vd['last_update'], vd['block_num'], vd['is_effective'])) + + + if len(values) >= values_limit: + values_str = ','.join(values) + actual_query = sql.format(values_str) + DB.query(actual_query) + values.clear() + + if len(values) > 0: + values_str = ','.join(values) + actual_query = sql.format(values_str) + DB.query(actual_query) + values.clear() + + n = len(cls._votes_data) + if not DbState.is_initial_sync(): + update_hot_and_tranding_for_block_range( first_block, last_block ) + cls._votes_data.clear() + cls.inside_flush = False + return n + diff --git a/hive/server/bridge_api/methods.py b/hive/server/bridge_api/methods.py index 529bff990ba1ca01e8d26d42684131743ce8d5a9..9ad119184777ef15fa6e33d44153f701aea70f78 100644 --- a/hive/server/bridge_api/methods.py +++ b/hive/server/bridge_api/methods.py @@ -19,7 +19,7 @@ ROLES = {-2: 'muted', 0: 'guest', 2: 'member', 4: 'mod', 6: 'admin', 8: 'owner'} SQL_TEMPLATE = """ SELECT - hp.id, + hp.id, hp.author, hp.parent_author, hp.author_rep, @@ -34,24 +34,24 @@ SQL_TEMPLATE = """ hp.body, hp.category, hp.depth, - hp.promoted, - hp.payout, + hp.promoted, + hp.payout, hp.pending_payout, - hp.payout_at, - hp.is_paidout, - hp.children, + hp.payout_at, + hp.is_paidout, + hp.children, hp.votes, - hp.created_at, - hp.updated_at, - hp.rshares, + hp.created_at, + hp.updated_at, + hp.rshares, hp.json, - hp.is_hidden, - hp.is_grayed, - hp.total_votes, + hp.is_hidden, + hp.is_grayed, + hp.total_votes, hp.flag_weight, - hp.sc_trend, - hp.role_title, - hp.community_title, + hp.sc_trend, + hp.role_title, + hp.community_title, hp.role_id, hp.is_pinned, hp.curator_payout_value diff --git a/hive/server/bridge_api/objects.py b/hive/server/bridge_api/objects.py index 1b02dfb0afb027a2f16a41fbee3b19a45811f625..5c15878c9d6c95ddc250fcd65d3c0899f5e106f4 100644 --- a/hive/server/bridge_api/objects.py +++ b/hive/server/bridge_api/objects.py @@ -254,7 +254,7 @@ def _bridge_post_object(row, truncate_body=0): post['stats'] = { 'hide': row['is_hidden'], 'gray': row['is_grayed'], - 'total_votes': Votes.get_vote_count(row['author'], row['permlink']), + 'total_votes': row['total_votes'], 'flag_weight': float(row['flag_weight'])} # TODO: down_weight diff --git a/hive/server/condenser_api/objects.py b/hive/server/condenser_api/objects.py index a238d01aed8527cbec473e2fc8b84e0a52ce769d..f4218a8a08f548a35ef130d2e9dc05c188692466 100644 --- a/hive/server/condenser_api/objects.py +++ b/hive/server/condenser_api/objects.py @@ -123,7 +123,7 @@ async def load_posts(db, ids, truncate_body=0): hive_posts hp INNER JOIN hive_accounts ha_a ON ha_a.id = hp.author_id INNER JOIN hive_permlink_data hpd_p ON hpd_p.id = hp.permlink_id - WHERE id = :id and counter_deleted = 0 """ + WHERE id = :id AND counter_deleted = 0 """ post = await db.query_row(sql, id=_id) if post is None: # TODO: This should never happen. See #173 for analysis diff --git a/hive/server/database_api/methods.py b/hive/server/database_api/methods.py index 2fcdf7a6ea14dfba134a6e991743600228c316f3..640a6f97ee6f90a8a7e3bd987011669c754dcd07 100644 --- a/hive/server/database_api/methods.py +++ b/hive/server/database_api/methods.py @@ -83,7 +83,8 @@ async def find_comments(context, comments: list): hp.depth, hp.promoted, hp.payout, - hp.payout_at, + hp.last_payout_at, + hp.cashout_time, hp.is_paidout, hp.children, hp.votes, @@ -94,6 +95,8 @@ async def find_comments(context, comments: list): hp.is_hidden, hp.is_grayed, hp.total_votes, + hp.net_votes, + hp.total_vote_weight, hp.flag_weight, hp.parent_author, hp.parent_permlink, diff --git a/hive/server/database_api/objects.py b/hive/server/database_api/objects.py index 0f68a1e7026b4d766ab6a226a0e87accce152817..4e45fc6a8e981ee51a174a299b36d117278785c3 100644 --- a/hive/server/database_api/objects.py +++ b/hive/server/database_api/objects.py @@ -28,11 +28,9 @@ def database_post_object(row, truncate_body=0): post['last_update'] = json_date(row['updated_at']) post['depth'] = row['depth'] post['children'] = row['children'] - post['children_abs_rshares'] = 0 # TODO - post['net_rshares'] = row['rshares'] - post['last_payout'] = json_date(row['payout_at'] if paid else None) - post['cashout_time'] = json_date(None if paid else row['payout_at']) + post['last_payout'] = json_date(row['last_payout_at']) + post['cashout_time'] = json_date(row['cashout_time']) post['max_cashout_time'] = json_date(row['max_cashout_time']) post['total_payout_value'] = to_nai(_amount(row['payout'] if paid else 0)) post['curator_payout_value'] = to_nai(_amount(0)) @@ -56,15 +54,22 @@ def database_post_object(row, truncate_body=0): post['beneficiaries'] = row['beneficiaries'] post['max_accepted_payout'] = to_nai(row['max_accepted_payout']) post['percent_hbd'] = row['percent_hbd'] - post['abs_rshares'] = row['abs_rshares'] - post['net_votes'] = Votes.get_vote_count(row['author'], row['permlink']) + post['net_votes'] = row['net_votes'] if paid: curator_payout = sbd_amount(row['curator_payout_value']) post['curator_payout_value'] = to_nai(_amount(curator_payout)) post['total_payout_value'] = to_nai(_amount(row['payout'] - curator_payout)) - - post['total_vote_weight'] = Votes.get_total_vote_weight(row['author'], row['permlink']) - post['vote_rshares'] = Votes.get_total_vote_rshares(row['author'], row['permlink']) + post['total_vote_weight'] = 0 + post['vote_rshares'] = 0 + post['net_rshares'] = 0 if row['rshares'] > 0 else row['rshares'] + post['abs_rshares'] = 0 + post['children_abs_rshares'] = 0 + else: + post['total_vote_weight'] = row['total_vote_weight'] + post['vote_rshares'] = ( row['rshares'] + row['abs_rshares'] ) // 2 # effectively sum of all positive rshares + post['net_rshares'] = row['rshares'] + post['abs_rshares'] = row['abs_rshares'] + post['children_abs_rshares'] = 0 # TODO return post diff --git a/hive/utils/post.py b/hive/utils/post.py index 9c3b8f1a176ef3aaa69e58354b4941c060c2b642..d074086819631c8292bd3f9ca1aeb97df9a1fdb7 100644 --- a/hive/utils/post.py +++ b/hive/utils/post.py @@ -100,7 +100,7 @@ def post_to_internal(post, post_id, level='insert', promoted=None): ('sc_trend', payout['sc_trend']), ('sc_hot', payout['sc_hot']), ('flag_weight', stats['flag_weight']), - ('total_votes', Votes.get_vote_count(post['author'], post['permlink']),), + ('total_votes', stats['total_votes']), ('up_votes', stats['up_votes']), ('is_hidden', stats['hide']), ('is_grayed', stats['gray']), diff --git a/hive/version.py b/hive/version.py index b9a41939d7cd1ddc97fcafb0bea311b46886a120..5a0e4fa19d68f4133a10465401cc87f4cf5c9fed 100644 --- a/hive/version.py +++ b/hive/version.py @@ -1,4 +1,4 @@ -# generated by setup.py -# contents will be overwritten -VERSION = '0.0.1' -GIT_REVISION = '90c2ecd' \ No newline at end of file +# generated by setup.py +# contents will be overwritten +VERSION = '0.0.1' +GIT_REVISION = '10bc3ad' \ No newline at end of file diff --git a/scripts/run_tests.sh b/scripts/run_tests.sh index 729d33d6456d49b4304e301dd32efa745e5859fe..0bf8a31e0e5d42019243c93a34fbd42dc0c9273a 100755 --- a/scripts/run_tests.sh +++ b/scripts/run_tests.sh @@ -55,7 +55,7 @@ fi check_address $1 check_port $2 -cd .. +#cd .. set -e diff --git a/tests/tests_api b/tests/tests_api index d23060b52e4e773308f7bafa666bef231c0e49ed..bae23397a6538852645dc8f3c4f08eca06f18144 160000 --- a/tests/tests_api +++ b/tests/tests_api @@ -1 +1 @@ -Subproject commit d23060b52e4e773308f7bafa666bef231c0e49ed +Subproject commit bae23397a6538852645dc8f3c4f08eca06f18144