From 50b54ad4ad75fc044c07d40dc00e6a367b0a522b Mon Sep 17 00:00:00 2001 From: Dariusz Kedzierski <dkedzierski@syncad.com> Date: Sun, 14 Jun 2020 22:09:42 +0200 Subject: [PATCH] [WIP] Native vote support: initial implementation. --- hive/db/schema.py | 21 ++++++++ hive/indexer/blocks.py | 5 +- hive/indexer/posts.py | 27 ++--------- hive/indexer/votes.py | 87 ++++++++++++++++++++++++++++++++++ scripts/update_hivemind_db.sql | 16 +++++++ 5 files changed, 131 insertions(+), 25 deletions(-) create mode 100644 hive/indexer/votes.py diff --git a/hive/db/schema.py b/hive/db/schema.py index cbe5f8246..605e8f4d2 100644 --- a/hive/db/schema.py +++ b/hive/db/schema.py @@ -183,6 +183,27 @@ def build_metadata(): sa.UniqueConstraint('category', name='hive_category_data_category') ) + sa.Table( + 'hive_votes', metadata, + sa.Column('id', sa.BigInteger, primary_key=True), + sa.Column('voter_id', sa.Integer, nullable=False), + sa.Column('author_id', sa.Integer, nullable=False), + sa.Column('permlink_id', sa.Integer, nullable=False), + sa.Column('weight', sa.BigInteger, nullable=False, server_default='0'), + sa.Column('rshares', sa.BigInteger, nullable=False, server_default='0'), + sa.Column('vote_percent', sa.Integer, server_default='0'), + 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.ForeignKeyConstraint(['voter_id'], ['hive_accounts.id']), + sa.ForeignKeyConstraint(['author_id'], ['hive_accounts.id']), + sa.ForeignKeyConstraint(['permlink_id'], ['hive_permlink_data.id']), + + sa.Index('hive_votes_voter_id_idx', 'voter_id'), + sa.Index('hive_votes_author_id_idx', 'author_id'), + sa.Index('hive_votes_permlink_id_idx', 'permlink_id') + ) + sa.Table( 'hive_post_tags', metadata, sa.Column('post_id', sa.Integer, nullable=False), diff --git a/hive/indexer/blocks.py b/hive/indexer/blocks.py index ffa8a6695..9ec072e1f 100644 --- a/hive/indexer/blocks.py +++ b/hive/indexer/blocks.py @@ -9,6 +9,7 @@ from hive.indexer.posts import Posts from hive.indexer.custom_op import CustomOp from hive.indexer.payments import Payments from hive.indexer.follow import Follow +from hive.indexer.votes import Votes log = logging.getLogger(__name__) @@ -105,11 +106,11 @@ class Blocks: elif op_type == 'delete_comment_operation': Posts.delete_op(op) elif op_type == 'vote_operation': + Votes.vote_op(op, date) if not is_initial_sync: Accounts.dirty(op['author']) # lite - rep Accounts.dirty(op['voter']) # lite - stats - Posts.vote_op(hived, op) - + # misc ops elif op_type == 'transfer_operation': Payments.op_transfer(op, tx_idx, num, date) diff --git a/hive/indexer/posts.py b/hive/indexer/posts.py index 67254743e..a93f7c572 100644 --- a/hive/indexer/posts.py +++ b/hive/indexer/posts.py @@ -136,28 +136,6 @@ class Posts: # post exists but was deleted. time to reinstate. cls.undelete(op, block_date, pid) - @classmethod - def vote_op(cls, hived, op): - """ Vote operation processing """ - pid = cls.get_id(op['author'], op['permlink']) - assert pid, "Post does not exists in the database" - votes = [] - # think that the comment was deleted in the future - # and since we are syncing blocks from the past and asking for current version of votes with find_votes - # we are getting error that comment does not exists - try: - votes = hived.get_votes(op['author'], op['permlink']) - except Exception: - pass - sql = """ - UPDATE - hive_post_data - SET - votes = :votes - WHERE id = :id""" - - DB.query(sql, id=pid, votes=dumps(votes)) - @classmethod def comment_payout_op(cls, ops, date, price): """ Process comment payment operations """ @@ -325,7 +303,10 @@ class Posts: """ Increase/decrease child count by 1 """ sql = """SELECT children FROM hive_posts WHERE id = :id""" query = DB.query_row(sql, id=parent_id) - children = int(query.children) + + children = 0 + if query is not None: + children = query.children if children == 32767: children = 0 diff --git a/hive/indexer/votes.py b/hive/indexer/votes.py new file mode 100644 index 000000000..9ff633d8e --- /dev/null +++ b/hive/indexer/votes.py @@ -0,0 +1,87 @@ +""" Votes indexing and processing """ + +import logging + +from hive.db.adapter import Db + +log = logging.getLogger(__name__) +DB = Db.instance() + +class Votes: + """ Class for managing posts votes """ + @classmethod + def get_id(cls, voter, author, permlink): + """ Check if vote exists, if yes return its id, else return None """ + sql = """ + SELECT + hv.id + FROM + hive_votes hv + INNER JOIN hive_accounts ha_v ON (ha_v.id = hv.voter_id) + INNER JOIN hive_accounts ha_a ON (ha_a.id = hv.author_id) + INNER JOIN hive_permlink_data hpd ON (hpd.id = hv.permlink_id) + WHERE ha_v.name = :voter AND ha_a.name = :author AND hpd.permlink = :permlink + """ + ret = DB.query_row(sql, voter=voter, author=author, permlink=permlink) + return None if ret is None else ret.id + + @classmethod + def vote_op(cls, op, date): + """ Process vote_operation """ + voter = op['voter'] + author = op['author'] + permlink = op['permlink'] + + vote_id = cls.get_id(voter, author, permlink) + # no vote so create new + if vote_id is None: + cls._insert(op, date) + else: + cls._update(vote_id, op, date) + + @classmethod + def _insert(cls, op, date): + """ Insert new vote """ + voter = op['voter'] + author = op['author'] + permlink = op['permlink'] + vote_percent = op['weight'] + sql = """ + INSERT INTO + hive_votes (voter_id, author_id, permlink_id, weight, rshares, vote_percent, last_update) + VALUES ( + (SELECT id FROM hive_accounts WHERE name = :voter), + (SELECT id FROM hive_accounts WHERE name = :author), + (SELECT id FROM hive_permlink_data WHERE permlink = :permlink), + :weight, + :rshares, + :vote_percent, + :last_update + )""" + # [DK] calculation of those is quite complicated, must think + weight = 0 + rshares = 0 + DB.query(sql, voter=voter, author=author, permlink=permlink, weight=weight, rshares=rshares, + vote_percent=vote_percent, last_update=date) + + @classmethod + def _update(cls, vote_id, op, date): + """ Update existing vote """ + vote_percent = op['weight'] + sql = """ + UPDATE + hive_votes + SET + weight = :weight, + rshares = :rshares, + vote_percent = :vote_percent, + last_update = :last_update, + num_changes = (SELECT num_changes FROM hive_votes WHERE id = :id) + 1 + WHERE id = :id + """ + # [DK] calculation of those is quite complicated, must think + weight = 0 + rshares = 0 + DB.query(sql, weight=weight, rshares=rshares, vote_percent=vote_percent, last_update=date, + id=vote_id) + diff --git a/scripts/update_hivemind_db.sql b/scripts/update_hivemind_db.sql index 305d5e0c6..c99b5b1ea 100644 --- a/scripts/update_hivemind_db.sql +++ b/scripts/update_hivemind_db.sql @@ -151,6 +151,22 @@ CREATE TABLE IF NOT EXISTS hive_post_data ( ); CREATE INDEX IF NOT EXISTS hive_post_data_id_idx ON hive_post_data (id); +CREATE TABLE IF NOT EXISTS hive_votes ( + id BIGSERIAL PRIMARY KEY NOT NULL, + voter_id INT NOT NULL REFERENCES hive_accounts (id) ON DELETE RESTRICT, + author_id INT NOT NULL REFERENCES hive_accounts (id) ON DELETE RESTRICT, + permlink_id INT NOT NULL REFERENCES hive_permlink_data (id) ON DELETE RESTRICT, + weight BIGINT DEFAULT '0', + rshares BIGINT DEFAULT '0', + vote_percent INT DEFAULT '0', + last_update DATE DEFAULT '1970-01-01T00:00:00', + num_changes INT DEFAULT '0' +); + +CREATE INDEX IF NOT EXISTS hive_votes_voter_id_idx ON hive_votes (voter_id); +CREATE INDEX IF NOT EXISTS hive_votes_author_id_idx ON hive_votes (author_id); +CREATE INDEX IF NOT EXISTS hive_votes_permlink_id_idx ON hive_votes (permlink_id); + -- Copy data from hive_posts table to new table -- RAISE NOTICE 'Copy data from hive_posts table to new table'; INSERT INTO hive_posts_new ( -- GitLab