diff --git a/hive/db/schema.py b/hive/db/schema.py index 8a698c14ee8971a05506ac5ad4e5cef977d698ec..7b04e94b266ec57ca7da3fa3b576c78efefacb8f 100644 --- a/hive/db/schema.py +++ b/hive/db/schema.py @@ -1,1249 +1,1249 @@ -"""Db schema definitions and setup routines.""" - -import sqlalchemy as sa -from sqlalchemy.sql import text as sql_text -from sqlalchemy.types import SMALLINT -from sqlalchemy.types import CHAR -from sqlalchemy.types import VARCHAR -from sqlalchemy.types import TEXT -from sqlalchemy.types import BOOLEAN - -#pylint: disable=line-too-long, too-many-lines, bad-whitespace - -# [DK] we changed and removed some tables so i upgraded DB_VERSION to 18 -DB_VERSION = 18 - -def build_metadata(): - """Build schema def with SqlAlchemy""" - metadata = sa.MetaData() - - sa.Table( - 'hive_blocks', metadata, - sa.Column('num', sa.Integer, primary_key=True, autoincrement=False), - sa.Column('hash', CHAR(40), nullable=False), - sa.Column('prev', CHAR(40)), - sa.Column('txs', SMALLINT, server_default='0', nullable=False), - sa.Column('ops', SMALLINT, server_default='0', nullable=False), - sa.Column('created_at', sa.DateTime, nullable=False), - - sa.UniqueConstraint('hash', name='hive_blocks_ux1'), - sa.ForeignKeyConstraint(['prev'], ['hive_blocks.hash'], name='hive_blocks_fk1'), - ) - - sa.Table( - 'hive_accounts', metadata, - sa.Column('id', sa.Integer, primary_key=True), - 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'), - - sa.Column('display_name', sa.String(20)), - sa.Column('about', sa.String(160)), - sa.Column('location', sa.String(30)), - sa.Column('website', sa.String(1024)), - sa.Column('profile_image', sa.String(1024), nullable=False, server_default=''), - sa.Column('cover_image', sa.String(1024), nullable=False, server_default=''), - - sa.Column('followers', sa.Integer, nullable=False, server_default='0'), - sa.Column('following', sa.Integer, nullable=False, server_default='0'), - - sa.Column('proxy', VARCHAR(16), nullable=False, server_default=''), - sa.Column('post_count', sa.Integer, nullable=False, server_default='0'), - sa.Column('proxy_weight', sa.Float(precision=6), nullable=False, server_default='0'), - sa.Column('vote_weight', sa.Float(precision=6), nullable=False, server_default='0'), - sa.Column('kb_used', sa.Integer, nullable=False, server_default='0'), # deprecated - sa.Column('rank', sa.Integer, nullable=False, server_default='0'), - - sa.Column('lastread_at', sa.DateTime, nullable=False, server_default='1970-01-01 00:00:00'), - sa.Column('active_at', sa.DateTime, nullable=False, server_default='1970-01-01 00:00:00'), - sa.Column('cached_at', sa.DateTime, nullable=False, server_default='1970-01-01 00:00:00'), - sa.Column('raw_json', sa.Text), - - sa.UniqueConstraint('name', name='hive_accounts_ux1'), - sa.Index('hive_accounts_ix1', 'vote_weight'), # core: quick ranks - sa.Index('hive_accounts_ix5', 'cached_at'), # core/listen sweep - ) - - sa.Table( - 'hive_posts', metadata, - sa.Column('id', sa.Integer, primary_key=True), - 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), - sa.Column('community_id', sa.Integer, nullable=True), - sa.Column('created_at', sa.DateTime, nullable=False), - sa.Column('depth', SMALLINT, nullable=False), - sa.Column('counter_deleted', sa.Integer, nullable=False, server_default='0'), - sa.Column('is_pinned', BOOLEAN, nullable=False, server_default='0'), - sa.Column('is_muted', BOOLEAN, nullable=False, server_default='0'), - sa.Column('is_valid', BOOLEAN, nullable=False, server_default='1'), - sa.Column('promoted', sa.types.DECIMAL(10, 3), nullable=False, server_default='0'), - - sa.Column('children', sa.Integer, nullable=False, server_default='0'), - - # 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'), - - # 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'), - - # ui flags/filters - sa.Column('is_nsfw', BOOLEAN, nullable=False, server_default='0'), - sa.Column('is_declined', BOOLEAN, nullable=False, server_default='0'), - sa.Column('is_full_power', BOOLEAN, nullable=False, server_default='0'), - sa.Column('is_hidden', BOOLEAN, nullable=False, server_default='0'), - sa.Column('is_grayed', 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=''), - 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('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('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('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('curator_payout_value', sa.String(30), nullable=False, server_default=''), - sa.Column('max_accepted_payout', sa.String(30), nullable=False, server_default='1000000.000 HBD'), - 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='[]'), - sa.Column('url', sa.Text, nullable=False, server_default=''), - 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'), - - sa.Index('hive_posts_category_id_idx', 'category_id'), - sa.Index('hive_posts_payout_at_idx', 'payout_at'), - sa.Index('hive_posts_payout_idx', 'payout'), - 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.Table( - 'hive_post_data', metadata, - sa.Column('id', sa.Integer, primary_key=True, autoincrement=False), - sa.Column('title', VARCHAR(512), nullable=False, server_default=''), - sa.Column('preview', VARCHAR(1024), nullable=False, server_default=''), - sa.Column('img_url', VARCHAR(1024), nullable=False, server_default=''), - sa.Column('body', TEXT, nullable=False, server_default=''), - sa.Column('json', TEXT, nullable=False, server_default='') - ) - - sa.Table( - 'hive_permlink_data', metadata, - sa.Column('id', sa.BigInteger, primary_key=True), - 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, collation='C'), nullable=False), - sa.UniqueConstraint('category', name='hive_category_data_category') - ) - - sa.Table( - 'hive_votes', metadata, - sa.Column('id', sa.BigInteger, primary_key=True), - sa.Column('post_id', sa.Integer, nullable=False), - 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.Numeric, 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.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'), - - sa.ForeignKeyConstraint(['post_id'], ['hive_posts.id']), - sa.ForeignKeyConstraint(['voter_id'], ['hive_accounts.id']), - sa.ForeignKeyConstraint(['author_id'], ['hive_accounts.id']), - sa.ForeignKeyConstraint(['permlink_id'], ['hive_permlink_data.id']), - sa.ForeignKeyConstraint(['block_num'], ['hive_blocks.num']), - - sa.Index('hive_votes_post_id_idx', 'post_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.Index('hive_votes_upvote_idx', 'vote_percent', postgresql_where=sql_text("vote_percent > 0")), - sa.Index('hive_votes_downvote_idx', 'vote_percent', postgresql_where=sql_text("vote_percent < 0")), - sa.Index('hive_votes_block_num_idx', 'block_num') - ) - - sa.Table( - 'hive_tag_data', metadata, - sa.Column('id', sa.Integer, nullable=False, primary_key=True), - sa.Column('tag', VARCHAR(64, collation='C'), nullable=False, server_default=''), - sa.UniqueConstraint('tag', name='hive_tag_data_ux1') - ) - - sa.Table( - 'hive_post_tags', metadata, - sa.Column('post_id', sa.Integer, nullable=False), - sa.Column('tag_id', sa.Integer, nullable=False), - sa.PrimaryKeyConstraint('post_id', 'tag_id', name='hive_post_tags_pk1'), - sa.ForeignKeyConstraint(['post_id'], ['hive_posts.id']), - sa.ForeignKeyConstraint(['tag_id'], ['hive_tag_data.id']), - sa.Index('hive_post_tags_post_id_idx', 'post_id'), - sa.Index('hive_post_tags_tag_id_idx', 'tag_id') - ) - - sa.Table( - 'hive_follows', metadata, - sa.Column('follower', sa.Integer, nullable=False), - sa.Column('following', sa.Integer, nullable=False), - sa.Column('state', SMALLINT, nullable=False, server_default='1'), - sa.Column('created_at', sa.DateTime, nullable=False), - sa.Column('blacklisted', sa.Boolean, nullable=False, server_default='0'), - sa.Column('follow_blacklists', sa.Boolean, nullable=False, server_default='0'), - - sa.PrimaryKeyConstraint('following', 'follower', name='hive_follows_pk'), # core - sa.Index('hive_follows_ix5a', 'following', 'state', 'created_at', 'follower'), - sa.Index('hive_follows_ix5b', 'follower', 'state', 'created_at', 'following'), - ) - - sa.Table( - 'hive_reblogs', metadata, - sa.Column('account', VARCHAR(16), nullable=False), - sa.Column('post_id', sa.Integer, nullable=False), - sa.Column('created_at', sa.DateTime, nullable=False), - - sa.ForeignKeyConstraint(['account'], ['hive_accounts.name'], name='hive_reblogs_fk1'), - sa.ForeignKeyConstraint(['post_id'], ['hive_posts.id'], name='hive_reblogs_fk2'), - sa.PrimaryKeyConstraint('account', 'post_id', name='hive_reblogs_pk'), # core - sa.Index('hive_reblogs_account', 'account'), - sa.Index('hive_reblogs_post_id', 'post_id'), - ) - - sa.Table( - 'hive_payments', metadata, - sa.Column('id', sa.Integer, primary_key=True), - sa.Column('block_num', sa.Integer, nullable=False), - sa.Column('tx_idx', SMALLINT, nullable=False), - sa.Column('post_id', sa.Integer, nullable=False), - sa.Column('from_account', sa.Integer, nullable=False), - sa.Column('to_account', sa.Integer, nullable=False), - sa.Column('amount', sa.types.DECIMAL(10, 3), nullable=False), - sa.Column('token', VARCHAR(5), nullable=False), - - sa.ForeignKeyConstraint(['from_account'], ['hive_accounts.id'], name='hive_payments_fk1'), - sa.ForeignKeyConstraint(['to_account'], ['hive_accounts.id'], name='hive_payments_fk2'), - sa.ForeignKeyConstraint(['post_id'], ['hive_posts.id'], name='hive_payments_fk3'), - sa.Index('hive_payments_from', 'from_account'), - sa.Index('hive_payments_to', 'to_account'), - sa.Index('hive_payments_post_id', 'post_id'), - ) - - sa.Table( - 'hive_feed_cache', metadata, - sa.Column('post_id', sa.Integer, nullable=False, primary_key=True), - sa.Column('account_id', sa.Integer, nullable=False), - sa.Column('created_at', sa.DateTime, nullable=False), - sa.Index('hive_feed_cache_account_id', 'account_id'), # API (and rebuild?) - sa.UniqueConstraint('account_id', 'post_id', name='hive_feed_cache_ux1') - ) - - sa.Table( - 'hive_state', metadata, - sa.Column('block_num', sa.Integer, primary_key=True, autoincrement=False), - sa.Column('db_version', sa.Integer, nullable=False), - sa.Column('steem_per_mvest', sa.types.DECIMAL(14, 6), nullable=False), - sa.Column('usd_per_steem', sa.types.DECIMAL(14, 6), nullable=False), - sa.Column('sbd_per_steem', sa.types.DECIMAL(14, 6), nullable=False), - sa.Column('dgpo', sa.Text, nullable=False), - ) - - metadata = build_metadata_community(metadata) - - return metadata - -def build_metadata_community(metadata=None): - """Build community schema defs""" - if not metadata: - metadata = sa.MetaData() - - sa.Table( - 'hive_communities', metadata, - 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, 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'), - sa.Column('num_pending', sa.Integer, nullable=False, server_default='0'), - sa.Column('num_authors', sa.Integer, nullable=False, server_default='0'), - sa.Column('rank', sa.Integer, nullable=False, server_default='0'), - sa.Column('subscribers', sa.Integer, nullable=False, server_default='0'), - sa.Column('is_nsfw', BOOLEAN, nullable=False, server_default='0'), - sa.Column('about', sa.String(120), nullable=False, server_default=''), - sa.Column('primary_tag', sa.String(32), nullable=False, server_default=''), - sa.Column('category', sa.String(32), nullable=False, server_default=''), - sa.Column('avatar_url', sa.String(1024), nullable=False, server_default=''), - sa.Column('description', sa.String(5000), nullable=False, server_default=''), - sa.Column('flag_text', sa.String(5000), nullable=False, server_default=''), - sa.Column('settings', TEXT, nullable=False, server_default='{}'), - - sa.UniqueConstraint('name', name='hive_communities_ux1'), - sa.Index('hive_communities_ix1', 'rank', 'id') - ) - - sa.Table( - 'hive_roles', metadata, - sa.Column('account_id', sa.Integer, nullable=False), - sa.Column('community_id', sa.Integer, nullable=False), - sa.Column('created_at', sa.DateTime, nullable=False), - sa.Column('role_id', SMALLINT, nullable=False, server_default='0'), - sa.Column('title', sa.String(140), nullable=False, server_default=''), - - sa.PrimaryKeyConstraint('account_id', 'community_id', name='hive_roles_pk'), - sa.Index('hive_roles_ix1', 'community_id', 'account_id', 'role_id'), - ) - - sa.Table( - 'hive_subscriptions', metadata, - sa.Column('account_id', sa.Integer, nullable=False), - sa.Column('community_id', sa.Integer, nullable=False), - sa.Column('created_at', sa.DateTime, nullable=False), - - sa.UniqueConstraint('account_id', 'community_id', name='hive_subscriptions_ux1'), - sa.Index('hive_subscriptions_ix1', 'community_id', 'account_id', 'created_at'), - ) - - sa.Table( - 'hive_notifs', metadata, - sa.Column('id', sa.Integer, primary_key=True), - sa.Column('type_id', SMALLINT, nullable=False), - sa.Column('score', SMALLINT, nullable=False), - sa.Column('created_at', sa.DateTime, nullable=False), - sa.Column('src_id', sa.Integer, nullable=True), - sa.Column('dst_id', sa.Integer, nullable=True), - sa.Column('post_id', sa.Integer, nullable=True), - sa.Column('community_id', sa.Integer, nullable=True), - sa.Column('block_num', sa.Integer, nullable=True), - sa.Column('payload', sa.Text, nullable=True), - - sa.Index('hive_notifs_ix1', 'dst_id', 'id', postgresql_where=sql_text("dst_id IS NOT NULL")), - sa.Index('hive_notifs_ix2', 'community_id', 'id', postgresql_where=sql_text("community_id IS NOT NULL")), - sa.Index('hive_notifs_ix3', 'community_id', 'type_id', 'id', postgresql_where=sql_text("community_id IS NOT NULL")), - sa.Index('hive_notifs_ix4', 'community_id', 'post_id', 'type_id', 'id', postgresql_where=sql_text("community_id IS NOT NULL AND post_id IS NOT NULL")), - sa.Index('hive_notifs_ix5', 'post_id', 'type_id', 'dst_id', 'src_id', postgresql_where=sql_text("post_id IS NOT NULL AND type_id IN (16,17)")), # filter: dedupe - sa.Index('hive_notifs_ix6', 'dst_id', 'created_at', 'score', 'id', postgresql_where=sql_text("dst_id IS NOT NULL")), # unread - ) - - return metadata - - -def teardown(db): - """Drop all tables""" - build_metadata().drop_all(db.engine()) - -def setup(db): - """Creates all tables and seed data""" - # initialize schema - build_metadata().create_all(db.engine()) - - # tune auto vacuum/analyze - reset_autovac(db) - - # default rows - sqls = [ - "INSERT INTO hive_state (block_num, db_version, steem_per_mvest, usd_per_steem, sbd_per_steem, dgpo) VALUES (0, %d, 0, 0, 0, '')" % DB_VERSION, - "INSERT INTO hive_blocks (num, hash, created_at) VALUES (0, '0000000000000000000000000000000000000000', '2016-03-24 16:04:57')", - - "INSERT INTO hive_permlink_data (id, permlink) VALUES (0, '')", - "INSERT INTO hive_category_data (id, category) VALUES (0, '')", - "INSERT INTO hive_accounts (id, name, created_at) VALUES (0, '', '1970-01-01T00:00:00')", - - "INSERT INTO hive_accounts (name, created_at) VALUES ('miners', '2016-03-24 16:05:00')", - "INSERT INTO hive_accounts (name, created_at) VALUES ('null', '2016-03-24 16:05:00')", - "INSERT INTO hive_accounts (name, created_at) VALUES ('temp', '2016-03-24 16:05:00')", - "INSERT INTO hive_accounts (name, created_at) VALUES ('initminer', '2016-03-24 16:05:00')", - - """ - INSERT INTO - 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, now(), 0); - """] - for sql in sqls: - db.query(sql) - - sql = "CREATE INDEX hive_communities_ft1 ON hive_communities USING GIN (to_tsvector('english', title || ' ' || about))" - db.query(sql) - - sql = """ - DROP FUNCTION if exists process_hive_post_operation(character varying,character varying,character varying,character varying,timestamp without time zone,timestamp without time zone) - ; - CREATE OR REPLACE FUNCTION process_hive_post_operation( - in _author hive_accounts.name%TYPE, - in _permlink hive_permlink_data.permlink%TYPE, - in _parent_author hive_accounts.name%TYPE, - in _parent_permlink hive_permlink_data.permlink%TYPE, - in _date hive_posts.created_at%TYPE, - 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) - LANGUAGE plpgsql - AS - $function$ - BEGIN - - INSERT INTO hive_permlink_data - (permlink) - values - ( - _permlink - ) - ON CONFLICT DO NOTHING - ; - if _parent_author != '' THEN - RETURN QUERY INSERT INTO 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) - 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, - 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 - - ON CONFLICT ON CONSTRAINT hive_posts_ux1 DO UPDATE SET - --- During post update it is disallowed to change: parent-post, category, community-id - --- then also depth, is_valid and is_muted is impossible to change - --- 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 - ; - ELSE - INSERT INTO hive_category_data - (category) - VALUES (_parent_permlink) - ON CONFLICT (category) DO NOTHING - ; - - RETURN QUERY INSERT INTO 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) - 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) - ELSE NULL - 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 - - ON CONFLICT ON CONSTRAINT hive_posts_ux1 DO UPDATE SET - --- During post update it is disallowed to change: parent-post, category, community-id - --- then also depth, is_valid and is_muted is impossible to change - --- post edit part - 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 - ; - END IF; - END - $function$ - """ - db.query_no_return(sql) - - sql = """ - DROP FUNCTION if exists delete_hive_post(character varying,character varying,character varying) - ; - CREATE OR REPLACE FUNCTION delete_hive_post( - in _author hive_accounts.name%TYPE, - in _permlink hive_permlink_data.permlink%TYPE) - RETURNS TABLE (id hive_posts.id%TYPE, depth hive_posts.depth%TYPE) - LANGUAGE plpgsql - AS - $function$ - BEGIN - RETURN QUERY UPDATE hive_posts AS hp - SET counter_deleted = - ( - SELECT max( hps.counter_deleted ) + 1 - FROM hive_posts hps - INNER JOIN hive_accounts ha ON hps.author_id = ha.id - INNER JOIN hive_permlink_data hpd ON hps.permlink_id = hpd.id - WHERE ha.name = _author AND hpd.permlink = _permlink - ) - FROM hive_posts hp1 - INNER JOIN hive_accounts ha ON hp1.author_id = ha.id - INNER JOIN hive_permlink_data hpd ON hp1.permlink_id = hpd.id - WHERE hp.id = hp1.id AND ha.name = _author AND hpd.permlink = _permlink AND hp1.counter_deleted = 0 - RETURNING hp.id, hp.depth; - END - $function$ - """ - db.query_no_return(sql) - - sql = """ - DROP VIEW IF EXISTS public.hive_posts_view; - - CREATE OR REPLACE VIEW public.hive_posts_view - 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, - hp.author_rewards, - hp.author_id, - hpd_p.permlink, - hpd.title, - hpd.body, - hpd.img_url, - hpd.preview, - hcd.category, - hp.depth, - hp.promoted, - hp.payout, - hp.pending_payout, - hp.payout_at, - hp.last_payout_at, - hp.cashout_time, - hp.is_paidout, - hp.children, - 0 AS votes, - 0 AS active_votes, - hp.created_at, - hp.updated_at, - COALESCE( - ( - SELECT SUM( v.rshares ) - FROM hive_votes v - WHERE v.post_id = hp.id - GROUP BY v.post_id - ), 0 - ) AS rshares, - hpd.json, - ha_a.reputation AS author_rep, - hp.is_hidden, - hp.is_grayed, - 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_pp.name AS parent_author, - hpd_pp.permlink AS parent_permlink, - hp.curator_payout_value, - ha_rp.name AS root_author, - hpd_rp.permlink AS root_permlink, - rcd.category as root_category, - hp.max_accepted_payout, - hp.percent_hbd, - True AS allow_replies, - hp.allow_votes, - hp.allow_curation_rewards, - hp.beneficiaries, - 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, - hp.counter_deleted, - hp.is_pinned, - hp.is_muted, - hp.is_nsfw, - hp.is_valid, - hr.title AS role_title, - hr.role_id AS role_id, - hc.title AS community_title, - hc.name AS community_name, - 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 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 - 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) - ; - """ - db.query_no_return(sql) - - sql = """ - DROP FUNCTION IF EXISTS public.update_hive_posts_children_count(); - - CREATE OR REPLACE FUNCTION public.update_hive_posts_children_count() - RETURNS void - LANGUAGE 'plpgsql' - VOLATILE - AS $BODY$ - BEGIN - - UPDATE hive_posts uhp - SET children = data_source.children_count - FROM - ( - WITH recursive tblChild AS - ( - SELECT s.queried_parent, s.id - FROM - (SELECT h1.Parent_Id AS queried_parent, h1.id - FROM hive_posts h1 - WHERE h1.depth > 0 AND h1.counter_deleted = 0 - ORDER BY h1.depth DESC - ) s - UNION ALL - SELECT tblChild.queried_parent, p.id FROM hive_posts p - JOIN tblChild ON p.Parent_Id = tblChild.Id - WHERE p.counter_deleted = 0 - ) - SELECT queried_parent, cast(count(1) AS int) AS children_count - FROM tblChild - GROUP BY queried_parent - ) data_source - WHERE uhp.id = data_source.queried_parent - ; - END - $BODY$; - """ - db.query_no_return(sql) - - sql = """ - DROP VIEW IF EXISTS hive_votes_accounts_permlinks_view - ; - CREATE VIEW hive_votes_accounts_permlinks_view - AS - SELECT - ha_v.id as voter_id, - ha_a.name as author, - hpd.permlink as permlink, - vote_percent as percent, - ha_a.reputation as reputation, - rshares, - last_update as time, - ha_v.name as voter, - weight, - num_changes, - hpd.id as permlink_id, - post_id, - is_effective - 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 - ; - """ - 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 ( - id INT, - community_id INT, - author VARCHAR(16), - permlink VARCHAR(255), - title VARCHAR(512), - body TEXT, - category VARCHAR(255), - depth SMALLINT, - promoted DECIMAL(10,3), - payout DECIMAL(10,3), - last_payout_at TIMESTAMP, - cashout_time TIMESTAMP, - is_paidout BOOLEAN, - children INT, - votes INT, - created_at TIMESTAMP, - updated_at TIMESTAMP, - rshares NUMERIC, - json TEXT, - is_hidden BOOLEAN, - is_grayed BOOLEAN, - total_votes BIGINT, - net_votes BIGINT, - total_vote_weight NUMERIC, - flag_weight REAL, - parent_author VARCHAR(16), - parent_permlink VARCHAR(255), - curator_payout_value VARCHAR(30), - root_author VARCHAR(16), - root_permlink VARCHAR(255), - max_accepted_payout VARCHAR(30), - percent_hbd INT, - allow_replies BOOLEAN, - allow_votes BOOLEAN, - allow_curation_rewards BOOLEAN, - beneficiaries JSON, - url TEXT, - root_title VARCHAR(512), - abs_rshares NUMERIC, - active TIMESTAMP, - author_rewards BIGINT, - max_cashout_time TIMESTAMP, - reward_weight INT - ) - ; - - DROP FUNCTION IF EXISTS list_comments_by_cashout_time(timestamp, character varying, character varying, int) - ; - CREATE OR REPLACE FUNCTION list_comments_by_cashout_time( - in _cashout_time timestamp, - in _author hive_accounts.name%TYPE, - in _permlink hive_permlink_data.permlink%TYPE, - in _limit INT) - 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.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.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 - FROM - hive_posts_view hp - WHERE - NOT hp.is_muted AND - 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 - LIMIT - _limit - ; - END - $function$ - LANGUAGE plpgsql - ; - - DROP FUNCTION IF EXISTS list_comments_by_permlink(character varying, character varying, int) - ; - CREATE OR REPLACE FUNCTION list_comments_by_permlink( - in _author hive_accounts.name%TYPE, - in _permlink hive_permlink_data.permlink%TYPE, - in _limit INT) - RETURNS SETOF database_api_post - AS - $function$ - BEGIN - 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.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.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 - FROM - hive_posts_view hp - WHERE - NOT hp.is_muted AND - hp.counter_deleted = 0 AND - hp.author > _author OR - hp.author = _author AND hp.permlink >= _permlink - ORDER BY - hp.author ASC, - hp.permlink ASC - LIMIT - _limit - ; - END - $function$ - LANGUAGE plpgsql - ; - - DROP FUNCTION IF EXISTS list_comments_by_root(character varying, character varying, character varying, character varying, int) - ; - CREATE OR REPLACE FUNCTION list_comments_by_root( - in _root_author hive_accounts.name%TYPE, - in _root_permlink hive_permlink_data.permlink%TYPE, - in _start_post_author hive_accounts.name%TYPE, - in _start_post_permlink hive_permlink_data.permlink%TYPE, - in _limit INT) - RETURNS SETOF database_api_post - 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.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.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 - FROM - hive_posts_view hp - WHERE - NOT hp.is_muted AND - hp.counter_deleted = 0 AND - hp.root_id > __root_id OR - hp.root_id = __root_id AND - hp.id >= __post_id - ORDER BY - root_id ASC, - id ASC - LIMIT - _limit - ; - END - $function$ - LANGUAGE plpgsql - ; - - DROP FUNCTION IF EXISTS list_comments_by_parent(character varying, character varying, character varying, character varying, int) - ; - CREATE OR REPLACE FUNCTION list_comments_by_parent( - in _parent_author hive_accounts.name%TYPE, - in _parent_permlink hive_permlink_data.permlink%TYPE, - in _start_post_author hive_accounts.name%TYPE, - in _start_post_permlink hive_permlink_data.permlink%TYPE, - in _limit INT) - RETURNS SETOF database_api_post - 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.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.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 - FROM - hive_posts_view hp - WHERE - NOT hp.is_muted AND - hp.counter_deleted = 0 AND - 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, - id ASC - LIMIT - _limit - ; - END - $function$ - LANGUAGE plpgsql - ; - - DROP FUNCTION IF EXISTS list_comments_by_last_update(character varying, timestamp, character varying, character varying, int) - ; - CREATE OR REPLACE FUNCTION list_comments_by_last_update( - in _parent_author hive_accounts.name%TYPE, - in _updated_at hive_posts.updated_at%TYPE, - in _start_post_author hive_accounts.name%TYPE, - in _start_post_permlink hive_permlink_data.permlink%TYPE, - in _limit INT) - RETURNS SETOF database_api_post - 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.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.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 - FROM - hive_posts_view hp - WHERE - NOT hp.is_muted AND - hp.counter_deleted = 0 AND - 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, - hp.id ASC - LIMIT - _limit - ; - END - $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( - in _author hive_accounts.name%TYPE, - in _updated_at hive_posts.updated_at%TYPE, - in _start_post_author hive_accounts.name%TYPE, - in _start_post_permlink hive_permlink_data.permlink%TYPE, - in _limit INT) - RETURNS SETOF database_api_post - 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.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.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 - FROM - hive_posts_view hp - WHERE - 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 (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.author ASC, - hp.updated_at ASC, - hp.id ASC - LIMIT - _limit - ; - END - $function$ - LANGUAGE plpgsql - ; - """ - db.query_no_return(sql) - - # hot and tranding functions - - sql = """ - DROP FUNCTION IF EXISTS date_diff() CASCADE - ; - CREATE OR REPLACE FUNCTION date_diff (units VARCHAR(30), start_t TIMESTAMP, end_t TIMESTAMP) - RETURNS INT AS $$ - DECLARE - diff_interval INTERVAL; - diff INT = 0; - years_diff INT = 0; - BEGIN - IF units IN ('yy', 'yyyy', 'year', 'mm', 'm', 'month') THEN - years_diff = DATE_PART('year', end_t) - DATE_PART('year', start_t); - IF units IN ('yy', 'yyyy', 'year') THEN - -- SQL Server does not count full years passed (only difference between year parts) - RETURN years_diff; - ELSE - -- If end month is less than start month it will subtracted - RETURN years_diff * 12 + (DATE_PART('month', end_t) - DATE_PART('month', start_t)); - END IF; - END IF; - -- Minus operator returns interval 'DDD days HH:MI:SS' - diff_interval = end_t - start_t; - diff = diff + DATE_PART('day', diff_interval); - IF units IN ('wk', 'ww', 'week') THEN - diff = diff/7; - RETURN diff; - END IF; - IF units IN ('dd', 'd', 'day') THEN - RETURN diff; - END IF; - diff = diff * 24 + DATE_PART('hour', diff_interval); - IF units IN ('hh', 'hour') THEN - RETURN diff; - END IF; - diff = diff * 60 + DATE_PART('minute', diff_interval); - IF units IN ('mi', 'n', 'minute') THEN - RETURN diff; - END IF; - diff = diff * 60 + DATE_PART('second', diff_interval); - RETURN diff; - END; - $$ LANGUAGE plpgsql IMMUTABLE - """ - db.query_no_return(sql) - - sql = """ - DROP FUNCTION IF EXISTS public.calculate_time_part_of_trending(_post_created_at hive_posts.created_at%TYPE ) CASCADE - ; - CREATE OR REPLACE FUNCTION public.calculate_time_part_of_trending( - _post_created_at hive_posts.created_at%TYPE) - RETURNS double precision - LANGUAGE 'plpgsql' - IMMUTABLE - AS $BODY$ - DECLARE - result double precision; - sec_from_epoch INT = 0; - BEGIN - sec_from_epoch = date_diff( 'second', CAST('19700101' AS TIMESTAMP), _post_created_at ); - result = sec_from_epoch/240000.0; - return result; - END; - $BODY$; - """ - db.query_no_return(sql) - - sql = """ - DROP FUNCTION IF EXISTS public.calculate_time_part_of_hot(_post_created_at hive_posts.created_at%TYPE ) CASCADE - ; - CREATE OR REPLACE FUNCTION public.calculate_time_part_of_hot( - _post_created_at hive_posts.created_at%TYPE) - RETURNS double precision - LANGUAGE 'plpgsql' - IMMUTABLE - AS $BODY$ - DECLARE - result double precision; - sec_from_epoch INT = 0; - BEGIN - sec_from_epoch = date_diff( 'second', CAST('19700101' AS TIMESTAMP), _post_created_at ); - result = sec_from_epoch/10000.0; - return result; - END; - $BODY$; - """ - 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$; - """ - 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$; - """ - db.query_no_return(sql) - - sql = """ - DO $$ - BEGIN - EXECUTE 'ALTER DATABASE '||current_database()||' SET join_collapse_limit TO 16'; - EXECUTE 'ALTER DATABASE '||current_database()||' SET from_collapse_limit TO 16'; - END - $$; - """ - 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$; - """ - db.query_no_return(sql) - -def reset_autovac(db): - """Initializes/resets per-table autovacuum/autoanalyze params. - - We use a scale factor of 0 and specify exact threshold tuple counts, - per-table, in the format (autovacuum_threshold, autoanalyze_threshold).""" - - autovac_config = { # vacuum analyze - 'hive_accounts': (50000, 100000), - 'hive_posts': (2500, 10000), - 'hive_post_tags': (5000, 10000), - 'hive_follows': (5000, 5000), - 'hive_feed_cache': (5000, 5000), - 'hive_blocks': (5000, 25000), - 'hive_reblogs': (5000, 5000), - 'hive_payments': (5000, 5000), - } - - for table, (n_vacuum, n_analyze) in autovac_config.items(): - sql = """ALTER TABLE %s SET (autovacuum_vacuum_scale_factor = 0, - autovacuum_vacuum_threshold = %s, - autovacuum_analyze_scale_factor = 0, - autovacuum_analyze_threshold = %s)""" - db.query(sql % (table, n_vacuum, n_analyze)) +"""Db schema definitions and setup routines.""" + +import sqlalchemy as sa +from sqlalchemy.sql import text as sql_text +from sqlalchemy.types import SMALLINT +from sqlalchemy.types import CHAR +from sqlalchemy.types import VARCHAR +from sqlalchemy.types import TEXT +from sqlalchemy.types import BOOLEAN + +#pylint: disable=line-too-long, too-many-lines, bad-whitespace + +# [DK] we changed and removed some tables so i upgraded DB_VERSION to 18 +DB_VERSION = 18 + +def build_metadata(): + """Build schema def with SqlAlchemy""" + metadata = sa.MetaData() + + sa.Table( + 'hive_blocks', metadata, + sa.Column('num', sa.Integer, primary_key=True, autoincrement=False), + sa.Column('hash', CHAR(40), nullable=False), + sa.Column('prev', CHAR(40)), + sa.Column('txs', SMALLINT, server_default='0', nullable=False), + sa.Column('ops', SMALLINT, server_default='0', nullable=False), + sa.Column('created_at', sa.DateTime, nullable=False), + + sa.UniqueConstraint('hash', name='hive_blocks_ux1'), + sa.ForeignKeyConstraint(['prev'], ['hive_blocks.hash'], name='hive_blocks_fk1'), + ) + + sa.Table( + 'hive_accounts', metadata, + sa.Column('id', sa.Integer, primary_key=True), + 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'), + + sa.Column('display_name', sa.String(20)), + sa.Column('about', sa.String(160)), + sa.Column('location', sa.String(30)), + sa.Column('website', sa.String(1024)), + sa.Column('profile_image', sa.String(1024), nullable=False, server_default=''), + sa.Column('cover_image', sa.String(1024), nullable=False, server_default=''), + + sa.Column('followers', sa.Integer, nullable=False, server_default='0'), + sa.Column('following', sa.Integer, nullable=False, server_default='0'), + + sa.Column('proxy', VARCHAR(16), nullable=False, server_default=''), + sa.Column('post_count', sa.Integer, nullable=False, server_default='0'), + sa.Column('proxy_weight', sa.Float(precision=6), nullable=False, server_default='0'), + sa.Column('vote_weight', sa.Float(precision=6), nullable=False, server_default='0'), + sa.Column('kb_used', sa.Integer, nullable=False, server_default='0'), # deprecated + sa.Column('rank', sa.Integer, nullable=False, server_default='0'), + + sa.Column('lastread_at', sa.DateTime, nullable=False, server_default='1970-01-01 00:00:00'), + sa.Column('active_at', sa.DateTime, nullable=False, server_default='1970-01-01 00:00:00'), + sa.Column('cached_at', sa.DateTime, nullable=False, server_default='1970-01-01 00:00:00'), + sa.Column('raw_json', sa.Text), + + sa.UniqueConstraint('name', name='hive_accounts_ux1'), + sa.Index('hive_accounts_ix1', 'vote_weight'), # core: quick ranks + sa.Index('hive_accounts_ix5', 'cached_at'), # core/listen sweep + ) + + sa.Table( + 'hive_posts', metadata, + sa.Column('id', sa.Integer, primary_key=True), + 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), + sa.Column('community_id', sa.Integer, nullable=True), + sa.Column('created_at', sa.DateTime, nullable=False), + sa.Column('depth', SMALLINT, nullable=False), + sa.Column('counter_deleted', sa.Integer, nullable=False, server_default='0'), + sa.Column('is_pinned', BOOLEAN, nullable=False, server_default='0'), + sa.Column('is_muted', BOOLEAN, nullable=False, server_default='0'), + sa.Column('is_valid', BOOLEAN, nullable=False, server_default='1'), + sa.Column('promoted', sa.types.DECIMAL(10, 3), nullable=False, server_default='0'), + + sa.Column('children', sa.Integer, nullable=False, server_default='0'), + + # 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'), + + # 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'), + + # ui flags/filters + sa.Column('is_nsfw', BOOLEAN, nullable=False, server_default='0'), + sa.Column('is_declined', BOOLEAN, nullable=False, server_default='0'), + sa.Column('is_full_power', BOOLEAN, nullable=False, server_default='0'), + sa.Column('is_hidden', BOOLEAN, nullable=False, server_default='0'), + sa.Column('is_grayed', 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=''), + 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('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('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('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('curator_payout_value', sa.String(30), nullable=False, server_default=''), + sa.Column('max_accepted_payout', sa.String(30), nullable=False, server_default='1000000.000 HBD'), + 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='[]'), + sa.Column('url', sa.Text, nullable=False, server_default=''), + 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'), + + sa.Index('hive_posts_category_id_idx', 'category_id'), + sa.Index('hive_posts_payout_at_idx', 'payout_at'), + sa.Index('hive_posts_payout_idx', 'payout'), + 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.Table( + 'hive_post_data', metadata, + sa.Column('id', sa.Integer, primary_key=True, autoincrement=False), + sa.Column('title', VARCHAR(512), nullable=False, server_default=''), + sa.Column('preview', VARCHAR(1024), nullable=False, server_default=''), + sa.Column('img_url', VARCHAR(1024), nullable=False, server_default=''), + sa.Column('body', TEXT, nullable=False, server_default=''), + sa.Column('json', TEXT, nullable=False, server_default='') + ) + + sa.Table( + 'hive_permlink_data', metadata, + sa.Column('id', sa.BigInteger, primary_key=True), + 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, collation='C'), nullable=False), + sa.UniqueConstraint('category', name='hive_category_data_category') + ) + + sa.Table( + 'hive_votes', metadata, + sa.Column('id', sa.BigInteger, primary_key=True), + sa.Column('post_id', sa.Integer, nullable=False), + 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.Numeric, 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.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'), + + sa.ForeignKeyConstraint(['post_id'], ['hive_posts.id']), + sa.ForeignKeyConstraint(['voter_id'], ['hive_accounts.id']), + sa.ForeignKeyConstraint(['author_id'], ['hive_accounts.id']), + sa.ForeignKeyConstraint(['permlink_id'], ['hive_permlink_data.id']), + sa.ForeignKeyConstraint(['block_num'], ['hive_blocks.num']), + + sa.Index('hive_votes_post_id_idx', 'post_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.Index('hive_votes_upvote_idx', 'vote_percent', postgresql_where=sql_text("vote_percent > 0")), + sa.Index('hive_votes_downvote_idx', 'vote_percent', postgresql_where=sql_text("vote_percent < 0")), + sa.Index('hive_votes_block_num_idx', 'block_num') + ) + + sa.Table( + 'hive_tag_data', metadata, + sa.Column('id', sa.Integer, nullable=False, primary_key=True), + sa.Column('tag', VARCHAR(64, collation='C'), nullable=False, server_default=''), + sa.UniqueConstraint('tag', name='hive_tag_data_ux1') + ) + + sa.Table( + 'hive_post_tags', metadata, + sa.Column('post_id', sa.Integer, nullable=False), + sa.Column('tag_id', sa.Integer, nullable=False), + sa.PrimaryKeyConstraint('post_id', 'tag_id', name='hive_post_tags_pk1'), + sa.ForeignKeyConstraint(['post_id'], ['hive_posts.id']), + sa.ForeignKeyConstraint(['tag_id'], ['hive_tag_data.id']), + sa.Index('hive_post_tags_post_id_idx', 'post_id'), + sa.Index('hive_post_tags_tag_id_idx', 'tag_id') + ) + + sa.Table( + 'hive_follows', metadata, + sa.Column('follower', sa.Integer, nullable=False), + sa.Column('following', sa.Integer, nullable=False), + sa.Column('state', SMALLINT, nullable=False, server_default='1'), + sa.Column('created_at', sa.DateTime, nullable=False), + sa.Column('blacklisted', sa.Boolean, nullable=False, server_default='0'), + sa.Column('follow_blacklists', sa.Boolean, nullable=False, server_default='0'), + + sa.PrimaryKeyConstraint('following', 'follower', name='hive_follows_pk'), # core + sa.Index('hive_follows_ix5a', 'following', 'state', 'created_at', 'follower'), + sa.Index('hive_follows_ix5b', 'follower', 'state', 'created_at', 'following'), + ) + + sa.Table( + 'hive_reblogs', metadata, + sa.Column('account', VARCHAR(16), nullable=False), + sa.Column('post_id', sa.Integer, nullable=False), + sa.Column('created_at', sa.DateTime, nullable=False), + + sa.ForeignKeyConstraint(['account'], ['hive_accounts.name'], name='hive_reblogs_fk1'), + sa.ForeignKeyConstraint(['post_id'], ['hive_posts.id'], name='hive_reblogs_fk2'), + sa.PrimaryKeyConstraint('account', 'post_id', name='hive_reblogs_pk'), # core + sa.Index('hive_reblogs_account', 'account'), + sa.Index('hive_reblogs_post_id', 'post_id'), + ) + + sa.Table( + 'hive_payments', metadata, + sa.Column('id', sa.Integer, primary_key=True), + sa.Column('block_num', sa.Integer, nullable=False), + sa.Column('tx_idx', SMALLINT, nullable=False), + sa.Column('post_id', sa.Integer, nullable=False), + sa.Column('from_account', sa.Integer, nullable=False), + sa.Column('to_account', sa.Integer, nullable=False), + sa.Column('amount', sa.types.DECIMAL(10, 3), nullable=False), + sa.Column('token', VARCHAR(5), nullable=False), + + sa.ForeignKeyConstraint(['from_account'], ['hive_accounts.id'], name='hive_payments_fk1'), + sa.ForeignKeyConstraint(['to_account'], ['hive_accounts.id'], name='hive_payments_fk2'), + sa.ForeignKeyConstraint(['post_id'], ['hive_posts.id'], name='hive_payments_fk3'), + sa.Index('hive_payments_from', 'from_account'), + sa.Index('hive_payments_to', 'to_account'), + sa.Index('hive_payments_post_id', 'post_id'), + ) + + sa.Table( + 'hive_feed_cache', metadata, + sa.Column('post_id', sa.Integer, nullable=False, primary_key=True), + sa.Column('account_id', sa.Integer, nullable=False), + sa.Column('created_at', sa.DateTime, nullable=False), + sa.Index('hive_feed_cache_account_id', 'account_id'), # API (and rebuild?) + sa.UniqueConstraint('account_id', 'post_id', name='hive_feed_cache_ux1') + ) + + sa.Table( + 'hive_state', metadata, + sa.Column('block_num', sa.Integer, primary_key=True, autoincrement=False), + sa.Column('db_version', sa.Integer, nullable=False), + sa.Column('steem_per_mvest', sa.types.DECIMAL(14, 6), nullable=False), + sa.Column('usd_per_steem', sa.types.DECIMAL(14, 6), nullable=False), + sa.Column('sbd_per_steem', sa.types.DECIMAL(14, 6), nullable=False), + sa.Column('dgpo', sa.Text, nullable=False), + ) + + metadata = build_metadata_community(metadata) + + return metadata + +def build_metadata_community(metadata=None): + """Build community schema defs""" + if not metadata: + metadata = sa.MetaData() + + sa.Table( + 'hive_communities', metadata, + 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, 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'), + sa.Column('num_pending', sa.Integer, nullable=False, server_default='0'), + sa.Column('num_authors', sa.Integer, nullable=False, server_default='0'), + sa.Column('rank', sa.Integer, nullable=False, server_default='0'), + sa.Column('subscribers', sa.Integer, nullable=False, server_default='0'), + sa.Column('is_nsfw', BOOLEAN, nullable=False, server_default='0'), + sa.Column('about', sa.String(120), nullable=False, server_default=''), + sa.Column('primary_tag', sa.String(32), nullable=False, server_default=''), + sa.Column('category', sa.String(32), nullable=False, server_default=''), + sa.Column('avatar_url', sa.String(1024), nullable=False, server_default=''), + sa.Column('description', sa.String(5000), nullable=False, server_default=''), + sa.Column('flag_text', sa.String(5000), nullable=False, server_default=''), + sa.Column('settings', TEXT, nullable=False, server_default='{}'), + + sa.UniqueConstraint('name', name='hive_communities_ux1'), + sa.Index('hive_communities_ix1', 'rank', 'id') + ) + + sa.Table( + 'hive_roles', metadata, + sa.Column('account_id', sa.Integer, nullable=False), + sa.Column('community_id', sa.Integer, nullable=False), + sa.Column('created_at', sa.DateTime, nullable=False), + sa.Column('role_id', SMALLINT, nullable=False, server_default='0'), + sa.Column('title', sa.String(140), nullable=False, server_default=''), + + sa.PrimaryKeyConstraint('account_id', 'community_id', name='hive_roles_pk'), + sa.Index('hive_roles_ix1', 'community_id', 'account_id', 'role_id'), + ) + + sa.Table( + 'hive_subscriptions', metadata, + sa.Column('account_id', sa.Integer, nullable=False), + sa.Column('community_id', sa.Integer, nullable=False), + sa.Column('created_at', sa.DateTime, nullable=False), + + sa.UniqueConstraint('account_id', 'community_id', name='hive_subscriptions_ux1'), + sa.Index('hive_subscriptions_ix1', 'community_id', 'account_id', 'created_at'), + ) + + sa.Table( + 'hive_notifs', metadata, + sa.Column('id', sa.Integer, primary_key=True), + sa.Column('type_id', SMALLINT, nullable=False), + sa.Column('score', SMALLINT, nullable=False), + sa.Column('created_at', sa.DateTime, nullable=False), + sa.Column('src_id', sa.Integer, nullable=True), + sa.Column('dst_id', sa.Integer, nullable=True), + sa.Column('post_id', sa.Integer, nullable=True), + sa.Column('community_id', sa.Integer, nullable=True), + sa.Column('block_num', sa.Integer, nullable=True), + sa.Column('payload', sa.Text, nullable=True), + + sa.Index('hive_notifs_ix1', 'dst_id', 'id', postgresql_where=sql_text("dst_id IS NOT NULL")), + sa.Index('hive_notifs_ix2', 'community_id', 'id', postgresql_where=sql_text("community_id IS NOT NULL")), + sa.Index('hive_notifs_ix3', 'community_id', 'type_id', 'id', postgresql_where=sql_text("community_id IS NOT NULL")), + sa.Index('hive_notifs_ix4', 'community_id', 'post_id', 'type_id', 'id', postgresql_where=sql_text("community_id IS NOT NULL AND post_id IS NOT NULL")), + sa.Index('hive_notifs_ix5', 'post_id', 'type_id', 'dst_id', 'src_id', postgresql_where=sql_text("post_id IS NOT NULL AND type_id IN (16,17)")), # filter: dedupe + sa.Index('hive_notifs_ix6', 'dst_id', 'created_at', 'score', 'id', postgresql_where=sql_text("dst_id IS NOT NULL")), # unread + ) + + return metadata + + +def teardown(db): + """Drop all tables""" + build_metadata().drop_all(db.engine()) + +def setup(db): + """Creates all tables and seed data""" + # initialize schema + build_metadata().create_all(db.engine()) + + # tune auto vacuum/analyze + reset_autovac(db) + + # default rows + sqls = [ + "INSERT INTO hive_state (block_num, db_version, steem_per_mvest, usd_per_steem, sbd_per_steem, dgpo) VALUES (0, %d, 0, 0, 0, '')" % DB_VERSION, + "INSERT INTO hive_blocks (num, hash, created_at) VALUES (0, '0000000000000000000000000000000000000000', '2016-03-24 16:04:57')", + + "INSERT INTO hive_permlink_data (id, permlink) VALUES (0, '')", + "INSERT INTO hive_category_data (id, category) VALUES (0, '')", + "INSERT INTO hive_accounts (id, name, created_at) VALUES (0, '', '1970-01-01T00:00:00')", + + "INSERT INTO hive_accounts (name, created_at) VALUES ('miners', '2016-03-24 16:05:00')", + "INSERT INTO hive_accounts (name, created_at) VALUES ('null', '2016-03-24 16:05:00')", + "INSERT INTO hive_accounts (name, created_at) VALUES ('temp', '2016-03-24 16:05:00')", + "INSERT INTO hive_accounts (name, created_at) VALUES ('initminer', '2016-03-24 16:05:00')", + + """ + INSERT INTO + 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, now(), 0); + """] + for sql in sqls: + db.query(sql) + + sql = "CREATE INDEX hive_communities_ft1 ON hive_communities USING GIN (to_tsvector('english', title || ' ' || about))" + db.query(sql) + + sql = """ + DROP FUNCTION if exists process_hive_post_operation(character varying,character varying,character varying,character varying,timestamp without time zone,timestamp without time zone) + ; + CREATE OR REPLACE FUNCTION process_hive_post_operation( + in _author hive_accounts.name%TYPE, + in _permlink hive_permlink_data.permlink%TYPE, + in _parent_author hive_accounts.name%TYPE, + in _parent_permlink hive_permlink_data.permlink%TYPE, + in _date hive_posts.created_at%TYPE, + 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) + LANGUAGE plpgsql + AS + $function$ + BEGIN + + INSERT INTO hive_permlink_data + (permlink) + values + ( + _permlink + ) + ON CONFLICT DO NOTHING + ; + if _parent_author != '' THEN + RETURN QUERY INSERT INTO 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) + 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, + 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 + + ON CONFLICT ON CONSTRAINT hive_posts_ux1 DO UPDATE SET + --- During post update it is disallowed to change: parent-post, category, community-id + --- then also depth, is_valid and is_muted is impossible to change + --- 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 + ; + ELSE + INSERT INTO hive_category_data + (category) + VALUES (_parent_permlink) + ON CONFLICT (category) DO NOTHING + ; + + RETURN QUERY INSERT INTO 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) + 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) + ELSE NULL + 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 + + ON CONFLICT ON CONSTRAINT hive_posts_ux1 DO UPDATE SET + --- During post update it is disallowed to change: parent-post, category, community-id + --- then also depth, is_valid and is_muted is impossible to change + --- post edit part + 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 + ; + END IF; + END + $function$ + """ + db.query_no_return(sql) + + sql = """ + DROP FUNCTION if exists delete_hive_post(character varying,character varying,character varying) + ; + CREATE OR REPLACE FUNCTION delete_hive_post( + in _author hive_accounts.name%TYPE, + in _permlink hive_permlink_data.permlink%TYPE) + RETURNS TABLE (id hive_posts.id%TYPE, depth hive_posts.depth%TYPE) + LANGUAGE plpgsql + AS + $function$ + BEGIN + RETURN QUERY UPDATE hive_posts AS hp + SET counter_deleted = + ( + SELECT max( hps.counter_deleted ) + 1 + FROM hive_posts hps + INNER JOIN hive_accounts ha ON hps.author_id = ha.id + INNER JOIN hive_permlink_data hpd ON hps.permlink_id = hpd.id + WHERE ha.name = _author AND hpd.permlink = _permlink + ) + FROM hive_posts hp1 + INNER JOIN hive_accounts ha ON hp1.author_id = ha.id + INNER JOIN hive_permlink_data hpd ON hp1.permlink_id = hpd.id + WHERE hp.id = hp1.id AND ha.name = _author AND hpd.permlink = _permlink AND hp1.counter_deleted = 0 + RETURNING hp.id, hp.depth; + END + $function$ + """ + db.query_no_return(sql) + + sql = """ + DROP VIEW IF EXISTS public.hive_posts_view; + + CREATE OR REPLACE VIEW public.hive_posts_view + 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, + hp.author_rewards, + hp.author_id, + hpd_p.permlink, + hpd.title, + hpd.body, + hpd.img_url, + hpd.preview, + hcd.category, + hp.depth, + hp.promoted, + hp.payout, + hp.pending_payout, + hp.payout_at, + hp.last_payout_at, + hp.cashout_time, + hp.is_paidout, + hp.children, + 0 AS votes, + 0 AS active_votes, + hp.created_at, + hp.updated_at, + COALESCE( + ( + SELECT SUM( v.rshares ) + FROM hive_votes v + WHERE v.post_id = hp.id + GROUP BY v.post_id + ), 0 + ) AS rshares, + hpd.json, + ha_a.reputation AS author_rep, + hp.is_hidden, + hp.is_grayed, + 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_pp.name AS parent_author, + hpd_pp.permlink AS parent_permlink, + hp.curator_payout_value, + ha_rp.name AS root_author, + hpd_rp.permlink AS root_permlink, + rcd.category as root_category, + hp.max_accepted_payout, + hp.percent_hbd, + True AS allow_replies, + hp.allow_votes, + hp.allow_curation_rewards, + hp.beneficiaries, + 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, + hp.counter_deleted, + hp.is_pinned, + hp.is_muted, + hp.is_nsfw, + hp.is_valid, + hr.title AS role_title, + hr.role_id AS role_id, + hc.title AS community_title, + hc.name AS community_name, + 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 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 + 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) + ; + """ + db.query_no_return(sql) + + sql = """ + DROP FUNCTION IF EXISTS public.update_hive_posts_children_count(); + + CREATE OR REPLACE FUNCTION public.update_hive_posts_children_count() + RETURNS void + LANGUAGE 'plpgsql' + VOLATILE + AS $BODY$ + BEGIN + + UPDATE hive_posts uhp + SET children = data_source.children_count + FROM + ( + WITH recursive tblChild AS + ( + SELECT s.queried_parent, s.id + FROM + (SELECT h1.Parent_Id AS queried_parent, h1.id + FROM hive_posts h1 + WHERE h1.depth > 0 AND h1.counter_deleted = 0 + ORDER BY h1.depth DESC + ) s + UNION ALL + SELECT tblChild.queried_parent, p.id FROM hive_posts p + JOIN tblChild ON p.Parent_Id = tblChild.Id + WHERE p.counter_deleted = 0 + ) + SELECT queried_parent, cast(count(1) AS int) AS children_count + FROM tblChild + GROUP BY queried_parent + ) data_source + WHERE uhp.id = data_source.queried_parent + ; + END + $BODY$; + """ + db.query_no_return(sql) + + sql = """ + DROP VIEW IF EXISTS hive_votes_accounts_permlinks_view + ; + CREATE VIEW hive_votes_accounts_permlinks_view + AS + SELECT + ha_v.id as voter_id, + ha_a.name as author, + hpd.permlink as permlink, + vote_percent as percent, + ha_a.reputation as reputation, + rshares, + last_update as time, + ha_v.name as voter, + weight, + num_changes, + hpd.id as permlink_id, + post_id, + is_effective + 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 + ; + """ + 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 ( + id INT, + community_id INT, + author VARCHAR(16), + permlink VARCHAR(255), + title VARCHAR(512), + body TEXT, + category VARCHAR(255), + depth SMALLINT, + promoted DECIMAL(10,3), + payout DECIMAL(10,3), + last_payout_at TIMESTAMP, + cashout_time TIMESTAMP, + is_paidout BOOLEAN, + children INT, + votes INT, + created_at TIMESTAMP, + updated_at TIMESTAMP, + rshares NUMERIC, + json TEXT, + is_hidden BOOLEAN, + is_grayed BOOLEAN, + total_votes BIGINT, + net_votes BIGINT, + total_vote_weight NUMERIC, + flag_weight REAL, + parent_author VARCHAR(16), + parent_permlink VARCHAR(255), + curator_payout_value VARCHAR(30), + root_author VARCHAR(16), + root_permlink VARCHAR(255), + max_accepted_payout VARCHAR(30), + percent_hbd INT, + allow_replies BOOLEAN, + allow_votes BOOLEAN, + allow_curation_rewards BOOLEAN, + beneficiaries JSON, + url TEXT, + root_title VARCHAR(512), + abs_rshares NUMERIC, + active TIMESTAMP, + author_rewards BIGINT, + max_cashout_time TIMESTAMP, + reward_weight INT + ) + ; + + DROP FUNCTION IF EXISTS list_comments_by_cashout_time(timestamp, character varying, character varying, int) + ; + CREATE OR REPLACE FUNCTION list_comments_by_cashout_time( + in _cashout_time timestamp, + in _author hive_accounts.name%TYPE, + in _permlink hive_permlink_data.permlink%TYPE, + in _limit INT) + 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.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.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 + FROM + hive_posts_view hp + WHERE + NOT hp.is_muted AND + 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 + LIMIT + _limit + ; + END + $function$ + LANGUAGE plpgsql + ; + + DROP FUNCTION IF EXISTS list_comments_by_permlink(character varying, character varying, int) + ; + CREATE OR REPLACE FUNCTION list_comments_by_permlink( + in _author hive_accounts.name%TYPE, + in _permlink hive_permlink_data.permlink%TYPE, + in _limit INT) + RETURNS SETOF database_api_post + AS + $function$ + BEGIN + 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.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.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 + FROM + hive_posts_view hp + WHERE + NOT hp.is_muted AND + hp.counter_deleted = 0 AND + hp.author > _author OR + hp.author = _author AND hp.permlink >= _permlink + ORDER BY + hp.author ASC, + hp.permlink ASC + LIMIT + _limit + ; + END + $function$ + LANGUAGE plpgsql + ; + + DROP FUNCTION IF EXISTS list_comments_by_root(character varying, character varying, character varying, character varying, int) + ; + CREATE OR REPLACE FUNCTION list_comments_by_root( + in _root_author hive_accounts.name%TYPE, + in _root_permlink hive_permlink_data.permlink%TYPE, + in _start_post_author hive_accounts.name%TYPE, + in _start_post_permlink hive_permlink_data.permlink%TYPE, + in _limit INT) + RETURNS SETOF database_api_post + 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.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.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 + FROM + hive_posts_view hp + WHERE + NOT hp.is_muted AND + hp.counter_deleted = 0 AND + hp.root_id > __root_id OR + hp.root_id = __root_id AND + hp.id >= __post_id + ORDER BY + root_id ASC, + id ASC + LIMIT + _limit + ; + END + $function$ + LANGUAGE plpgsql + ; + + DROP FUNCTION IF EXISTS list_comments_by_parent(character varying, character varying, character varying, character varying, int) + ; + CREATE OR REPLACE FUNCTION list_comments_by_parent( + in _parent_author hive_accounts.name%TYPE, + in _parent_permlink hive_permlink_data.permlink%TYPE, + in _start_post_author hive_accounts.name%TYPE, + in _start_post_permlink hive_permlink_data.permlink%TYPE, + in _limit INT) + RETURNS SETOF database_api_post + 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.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.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 + FROM + hive_posts_view hp + WHERE + NOT hp.is_muted AND + hp.counter_deleted = 0 AND + 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, + id ASC + LIMIT + _limit + ; + END + $function$ + LANGUAGE plpgsql + ; + + DROP FUNCTION IF EXISTS list_comments_by_last_update(character varying, timestamp, character varying, character varying, int) + ; + CREATE OR REPLACE FUNCTION list_comments_by_last_update( + in _parent_author hive_accounts.name%TYPE, + in _updated_at hive_posts.updated_at%TYPE, + in _start_post_author hive_accounts.name%TYPE, + in _start_post_permlink hive_permlink_data.permlink%TYPE, + in _limit INT) + RETURNS SETOF database_api_post + 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.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.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 + FROM + hive_posts_view hp + WHERE + NOT hp.is_muted AND + hp.counter_deleted = 0 AND + 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, + hp.id ASC + LIMIT + _limit + ; + END + $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( + in _author hive_accounts.name%TYPE, + in _updated_at hive_posts.updated_at%TYPE, + in _start_post_author hive_accounts.name%TYPE, + in _start_post_permlink hive_permlink_data.permlink%TYPE, + in _limit INT) + RETURNS SETOF database_api_post + 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.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.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 + FROM + hive_posts_view hp + WHERE + 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 (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.author ASC, + hp.updated_at ASC, + hp.id ASC + LIMIT + _limit + ; + END + $function$ + LANGUAGE plpgsql + ; + """ + db.query_no_return(sql) + + # hot and tranding functions + + sql = """ + DROP FUNCTION IF EXISTS date_diff() CASCADE + ; + CREATE OR REPLACE FUNCTION date_diff (units VARCHAR(30), start_t TIMESTAMP, end_t TIMESTAMP) + RETURNS INT AS $$ + DECLARE + diff_interval INTERVAL; + diff INT = 0; + years_diff INT = 0; + BEGIN + IF units IN ('yy', 'yyyy', 'year', 'mm', 'm', 'month') THEN + years_diff = DATE_PART('year', end_t) - DATE_PART('year', start_t); + IF units IN ('yy', 'yyyy', 'year') THEN + -- SQL Server does not count full years passed (only difference between year parts) + RETURN years_diff; + ELSE + -- If end month is less than start month it will subtracted + RETURN years_diff * 12 + (DATE_PART('month', end_t) - DATE_PART('month', start_t)); + END IF; + END IF; + -- Minus operator returns interval 'DDD days HH:MI:SS' + diff_interval = end_t - start_t; + diff = diff + DATE_PART('day', diff_interval); + IF units IN ('wk', 'ww', 'week') THEN + diff = diff/7; + RETURN diff; + END IF; + IF units IN ('dd', 'd', 'day') THEN + RETURN diff; + END IF; + diff = diff * 24 + DATE_PART('hour', diff_interval); + IF units IN ('hh', 'hour') THEN + RETURN diff; + END IF; + diff = diff * 60 + DATE_PART('minute', diff_interval); + IF units IN ('mi', 'n', 'minute') THEN + RETURN diff; + END IF; + diff = diff * 60 + DATE_PART('second', diff_interval); + RETURN diff; + END; + $$ LANGUAGE plpgsql IMMUTABLE + """ + db.query_no_return(sql) + + sql = """ + DROP FUNCTION IF EXISTS public.calculate_time_part_of_trending(_post_created_at hive_posts.created_at%TYPE ) CASCADE + ; + CREATE OR REPLACE FUNCTION public.calculate_time_part_of_trending( + _post_created_at hive_posts.created_at%TYPE) + RETURNS double precision + LANGUAGE 'plpgsql' + IMMUTABLE + AS $BODY$ + DECLARE + result double precision; + sec_from_epoch INT = 0; + BEGIN + sec_from_epoch = date_diff( 'second', CAST('19700101' AS TIMESTAMP), _post_created_at ); + result = sec_from_epoch/240000.0; + return result; + END; + $BODY$; + """ + db.query_no_return(sql) + + sql = """ + DROP FUNCTION IF EXISTS public.calculate_time_part_of_hot(_post_created_at hive_posts.created_at%TYPE ) CASCADE + ; + CREATE OR REPLACE FUNCTION public.calculate_time_part_of_hot( + _post_created_at hive_posts.created_at%TYPE) + RETURNS double precision + LANGUAGE 'plpgsql' + IMMUTABLE + AS $BODY$ + DECLARE + result double precision; + sec_from_epoch INT = 0; + BEGIN + sec_from_epoch = date_diff( 'second', CAST('19700101' AS TIMESTAMP), _post_created_at ); + result = sec_from_epoch/10000.0; + return result; + END; + $BODY$; + """ + 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$; + """ + 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$; + """ + db.query_no_return(sql) + + sql = """ + DO $$ + BEGIN + EXECUTE 'ALTER DATABASE '||current_database()||' SET join_collapse_limit TO 16'; + EXECUTE 'ALTER DATABASE '||current_database()||' SET from_collapse_limit TO 16'; + END + $$; + """ + 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$; + """ + db.query_no_return(sql) + +def reset_autovac(db): + """Initializes/resets per-table autovacuum/autoanalyze params. + + We use a scale factor of 0 and specify exact threshold tuple counts, + per-table, in the format (autovacuum_threshold, autoanalyze_threshold).""" + + autovac_config = { # vacuum analyze + 'hive_accounts': (50000, 100000), + 'hive_posts': (2500, 10000), + 'hive_post_tags': (5000, 10000), + 'hive_follows': (5000, 5000), + 'hive_feed_cache': (5000, 5000), + 'hive_blocks': (5000, 25000), + 'hive_reblogs': (5000, 5000), + 'hive_payments': (5000, 5000), + } + + for table, (n_vacuum, n_analyze) in autovac_config.items(): + sql = """ALTER TABLE %s SET (autovacuum_vacuum_scale_factor = 0, + autovacuum_vacuum_threshold = %s, + autovacuum_analyze_scale_factor = 0, + autovacuum_analyze_threshold = %s)""" + db.query(sql % (table, n_vacuum, n_analyze)) diff --git a/hive/indexer/posts.py b/hive/indexer/posts.py index 86909c3c82cd56dc2ef583ff3469835c12cad11e..329ce40a28ae3d38a1b76f45bc5a6fd22c0f7b7c 100644 --- a/hive/indexer/posts.py +++ b/hive/indexer/posts.py @@ -1,473 +1,473 @@ -"""Core posts manager.""" - -import logging -import collections - -from json import dumps, loads - -from diff_match_patch import diff_match_patch - -from hive.db.adapter import Db -from hive.db.db_state import DbState - -from hive.indexer.accounts import Accounts -from hive.indexer.feed_cache import FeedCache -from hive.indexer.community import Community, START_DATE -from hive.indexer.notify import Notify -from hive.indexer.post_data_cache import PostDataCache -from hive.indexer.tags import Tags -from hive.utils.normalize import sbd_amount, legacy_amount, asset_to_hbd_hive - -log = logging.getLogger(__name__) -DB = Db.instance() - -class Posts: - """Handles critical/core post ops and data.""" - - # LRU cache for (author-permlink -> id) lookup (~400mb per 1M entries) - CACHE_SIZE = 2000000 - _ids = collections.OrderedDict() - _hits = 0 - _miss = 0 - - comment_payout_ops = {} - _comment_payout_ops = [] - - @classmethod - def last_id(cls): - """Get the last indexed post id.""" - sql = "SELECT MAX(id) FROM hive_posts WHERE counter_deleted = 0" - return DB.query_one(sql) or 0 - - @classmethod - def get_id(cls, author, permlink): - """Look up id by author/permlink, making use of LRU cache.""" - url = author+'/'+permlink - if url in cls._ids: - cls._hits += 1 - _id = cls._ids.pop(url) - cls._ids[url] = _id - else: - cls._miss += 1 - sql = """ - SELECT hp.id - FROM 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 ha_a.name = :a AND hpd_p.permlink = :p - """ - _id = DB.query_one(sql, a=author, p=permlink) - if _id: - cls._set_id(url, _id) - - # cache stats (under 10M every 10K else every 100K) - total = cls._hits + cls._miss - if total % 100000 == 0: - log.info("pid lookups: %d, hits: %d (%.1f%%), entries: %d", - total, cls._hits, 100.0*cls._hits/total, len(cls._ids)) - - return _id - - @classmethod - def _set_id(cls, url, pid): - """Add an entry to the LRU, maintaining max size.""" - assert pid, "no pid provided for %s" % url - if len(cls._ids) > cls.CACHE_SIZE: - cls._ids.popitem(last=False) - cls._ids[url] = pid - - @classmethod - def delete_op(cls, op): - """Given a delete_comment op, mark the post as deleted. - - Also remove it from post-cache and feed-cache. - """ - cls.delete(op) - - @classmethod - def comment_op(cls, op, block_date): - """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 - FROM process_hive_post_operation((:author)::varchar, (:permlink)::varchar, (:parent_author)::varchar, (:parent_permlink)::varchar, (:date)::timestamp, (:community_support_start_date)::timestamp); - """ - - row = DB.query_row(sql, author=op['author'], permlink=op['permlink'], parent_author=op['parent_author'], - parent_permlink=op['parent_permlink'], date=block_date, community_support_start_date=START_DATE) - - result = dict(row) - - # TODO we need to enhance checking related community post validation and honor is_muted. - error = cls._verify_post_against_community(op, result['community_id'], result['is_valid'], result['is_muted']) - - cls._set_id(op['author']+'/'+op['permlink'], result['id']) - - if result['is_new_post']: - # add content data to hive_post_data - post_data = dict(title=op['title'], preview=op['preview'] if 'preview' in op else "", - img_url=op['img_url'] if 'img_url' in op else "", body=op['body'], - json=op['json_metadata'] if op['json_metadata'] else '{}') - else: - # edit case. Now we need to (potentially) apply patch to the post body. - new_body = cls._merge_post_body(id=result['id'], new_body_def=op['body']) - post_data = dict(title=op['title'], preview=op['preview'] if 'preview' in op else "", - img_url=op['img_url'] if 'img_url' in op else "", body=new_body, - json=op['json_metadata'] if op['json_metadata'] else '{}') - -# log.info("Adding author: {} permlink: {}".format(op['author'], op['permlink'])) - - printQuery = False # op['author'] == 'xeroc' and op['permlink'] == 're-piston-20160818t080811' - PostDataCache.add_data(result['id'], post_data, printQuery) - - md = {} - # At least one case where jsonMetadata was double-encoded: condenser#895 - # jsonMetadata = JSON.parse(jsonMetadata); - try: - md = loads(op['json_metadata']) - if not isinstance(md, dict): - md = {} - except Exception: - pass - - if not result['depth']: - tags = [result['post_category']] - if md and 'tags' in md and isinstance(md['tags'], list): - tags = tags + md['tags'] - tags = map(lambda tag: (str(tag) or '').strip('# ').lower()[:32], tags) - tags = filter(None, tags) - from funcy.seqs import distinct - tags = list(distinct(tags))[:5] - - for tag in tags: - Tags.add_tag(result['id'], tag) - - if not DbState.is_initial_sync(): - if error: - author_id = result['author_id'] - Notify('error', dst_id=author_id, when=block_date, - post_id=result['id'], payload=error).write() - cls._insert_feed_cache(result, block_date) - - @classmethod - def flush_into_db(cls): - sql = """ - 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 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 ), - 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, - t.total_payout_value, - t.curator_payout_value, - t.author_rewards, - t.author_rewards_hive, - t.author_rewards_hbd, - t.author_rewards_vests, - t.payout, - t.pending_payout, - t.payout_at, - t.last_payout_at, - t.cashout_time, - t.is_paidout, - t.total_vote_weight - from - ( - VALUES - --- put all constant values here - {} - ) AS T(author, permlink, - total_payout_value, - curator_payout_value, - author_rewards, - author_rewards_hive, - author_rewards_hbd, - author_rewards_vests, - payout, - pending_payout, - payout_at, - last_payout_at, - cashout_time, - 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 - WHERE ihp.permlink_id = data_source.permlink_id and ihp.author_id = data_source.author_id - """ - - def chunks(lst, n): - """Yield successive n-sized chunks from lst.""" - for i in range(0, len(lst), n): - yield lst[i:i + n] - - for chunk in chunks(cls._comment_payout_ops, 1000): - values_str = ','.join(chunk) - actual_query = sql.format(values_str) - DB.query(actual_query) - - n = len(cls._comment_payout_ops) - cls._comment_payout_ops.clear() - return n - - @classmethod - def comment_payout_op(cls): - values_limit = 1000 - - """ Process comment payment operations """ - for k, v in cls.comment_payout_ops.items(): - author = None - permlink = None - - # author payouts - author_rewards = None - author_rewards_hive = None - author_rewards_hbd = None - author_rewards_vests = None - - # total payout for comment - #comment_author_reward = None - curators_vesting_payout = None - total_payout_value = None; - curator_payout_value = None; - #beneficiary_payout_value = None; - - payout = None - 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: - value = v[ 'author_reward_operation' ] - author_rewards_hive = value['hive_payout']['amount'] - author_rewards_hbd = value['hbd_payout']['amount'] - author_rewards_vests = value['vesting_payout']['amount'] - curators_vesting_payout = value['curators_vesting_payout']['amount'] - if author is None: - author = value['author'] - permlink = value['permlink'] - - if v[ 'comment_reward_operation' ] is not None: - value = v[ 'comment_reward_operation' ] - #comment_author_reward = value['payout'] - author_rewards = value['author_rewards'] - total_payout_value = value['total_payout_value'] - curator_payout_value = value['curator_payout_value'] - #beneficiary_payout_value = value['beneficiary_payout_value'] - - 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'] - permlink = value['permlink'] - - if v[ 'effective_comment_vote_operation' ] is not None: - value = v[ 'effective_comment_vote_operation' ] - pending_payout = sbd_amount( value['pending_payout'] ) - total_vote_weight = value['total_vote_weight'] - if author is None: - author = value['author'] - permlink = value['permlink'] - - if v[ 'comment_payout_update_operation' ] is not None: - value = v[ 'comment_payout_update_operation' ] - is_paidout = True - - #Payout didn't generate any payments - if v[ 'comment_reward_operation' ] is None: - author_rewards = 0 - total_payout_value = "0.000 HBD" - curator_payout_value = "0.000 HBD" - - payout = 0 - pending_payout = 0 - - if author is None: - author = value['author'] - permlink = value['permlink'] - - #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( - author, - permlink, - "NULL" if ( total_payout_value is None ) else ( "'{}'".format( legacy_amount(total_payout_value) ) ), - "NULL" if ( curator_payout_value is None ) else ( "'{}'".format( legacy_amount(curator_payout_value) ) ), - "NULL" if ( author_rewards is None ) else author_rewards, - "NULL" if ( author_rewards_hive is None ) else author_rewards_hive, - "NULL" if ( author_rewards_hbd is None ) else author_rewards_hbd, - "NULL" if ( author_rewards_vests is None ) else author_rewards_vests, - "NULL" if ( payout is None ) else payout, - "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 ( total_vote_weight is None ) else total_vote_weight )) - - - n = len(cls.comment_payout_ops) - cls.comment_payout_ops.clear() - return n - - @classmethod - def update_child_count(cls, child_id, op='+'): - """ Increase/decrease child count by 1 """ - sql = """ - UPDATE - hive_posts - SET - children = GREATEST(0, ( - SELECT - CASE - WHEN children is NULL THEN 0 - WHEN children=32762 THEN 0 - ELSE children - END - FROM - hive_posts - WHERE id = (SELECT parent_id FROM hive_posts WHERE id = :child_id) - )::int - """ - if op == '+': - sql += """ + 1)""" - else: - sql += """ - 1)""" - sql += """ WHERE id = (SELECT parent_id FROM hive_posts WHERE id = :child_id)""" - - DB.query(sql, child_id=child_id) - - @classmethod - def comment_options_op(cls, op): - """ Process comment_options_operation """ - max_accepted_payout = legacy_amount(op['max_accepted_payout']) if 'max_accepted_payout' in op else '1000000.000 HBD' - allow_votes = op['allow_votes'] if 'allow_votes' in op else True - allow_curation_rewards = op['allow_curation_rewards'] if 'allow_curation_rewards' in op else True - percent_hbd = op['percent_hbd'] if 'percent_hbd' in op else 10000 - extensions = op['extensions'] if 'extensions' in op else [] - beneficiaries = [] - for extension in extensions: - if 'beneficiaries' in extensions: - beneficiaries = extension['beneficiaries'] - sql = """ - UPDATE - hive_posts hp - SET - max_accepted_payout = :max_accepted_payout, - percent_hbd = :percent_hbd, - allow_votes = :allow_votes, - allow_curation_rewards = :allow_curation_rewards, - beneficiaries = :beneficiaries - WHERE - hp.author_id = (SELECT id FROM hive_accounts WHERE name = :author) AND - hp.permlink_id = (SELECT id FROM hive_permlink_data WHERE permlink = :permlink) - """ - DB.query(sql, author=op['author'], permlink=op['permlink'], max_accepted_payout=max_accepted_payout, - percent_hbd=percent_hbd, allow_votes=allow_votes, allow_curation_rewards=allow_curation_rewards, - beneficiaries=beneficiaries) - - @classmethod - def delete(cls, op): - """Marks a post record as being deleted.""" - - sql = """ - SELECT id, depth - FROM delete_hive_post((:author)::varchar, (:permlink)::varchar); - """ - row = DB.query_row(sql, author=op['author'], permlink = op['permlink']) - - result = dict(row) - pid = result['id'] - - if not DbState.is_initial_sync(): - depth = result['depth'] - - if depth == 0: - # TODO: delete from hive_reblogs -- otherwise feed cache gets - # populated with deleted posts somwrimas - FeedCache.delete(pid) - - # force parent child recount when child is deleted - cls.update_child_count(pid, '-') - - @classmethod - def _insert_feed_cache(cls, result, date): - """Insert the new post into feed cache if it's not a comment.""" - if not result['depth']: - cls._insert_feed_cache4(result['depth'], result['id'], result['author_id'], date) - - @classmethod - def _insert_feed_cache4(cls, post_depth, post_id, author_id, post_date): - """Insert the new post into feed cache if it's not a comment.""" - if not post_depth: - FeedCache.insert(post_id, author_id, post_date) - - @classmethod - def _verify_post_against_community(cls, op, community_id, is_valid, is_muted): - error = None - if community_id and is_valid and not Community.is_post_valid(community_id, op): - error = 'not authorized' - #is_valid = False # TODO: reserved for future blacklist status? - is_muted = True - return error - - @classmethod - def _merge_post_body(cls, id, new_body_def): - new_body = '' - old_body = '' - - try: - dmp = diff_match_patch() - patch = dmp.patch_fromText(new_body_def) - if patch is not None and len(patch): - old_body = PostDataCache.get_post_body(id) - new_body, _ = dmp.patch_apply(patch, old_body) - #new_utf8_body = new_body.decode('utf-8') - #new_body = new_utf8_body - else: - new_body = new_body_def - except ValueError as e: -# log.info("Merging a body post id: {} caused an ValueError exception {}".format(id, e)) -# log.info("New body definition: {}".format(new_body_def)) -# log.info("Old body definition: {}".format(old_body)) - new_body = new_body_def - except Exception as ex: - log.info("Merging a body post id: {} caused an unknown exception {}".format(id, ex)) - log.info("New body definition: {}".format(new_body_def)) - log.info("Old body definition: {}".format(old_body)) - new_body = new_body_def - - return new_body - - - @classmethod - def flush(cls): - return cls.comment_payout_op() + cls.flush_into_db() +"""Core posts manager.""" + +import logging +import collections + +from json import dumps, loads + +from diff_match_patch import diff_match_patch + +from hive.db.adapter import Db +from hive.db.db_state import DbState + +from hive.indexer.accounts import Accounts +from hive.indexer.feed_cache import FeedCache +from hive.indexer.community import Community, START_DATE +from hive.indexer.notify import Notify +from hive.indexer.post_data_cache import PostDataCache +from hive.indexer.tags import Tags +from hive.utils.normalize import sbd_amount, legacy_amount, asset_to_hbd_hive + +log = logging.getLogger(__name__) +DB = Db.instance() + +class Posts: + """Handles critical/core post ops and data.""" + + # LRU cache for (author-permlink -> id) lookup (~400mb per 1M entries) + CACHE_SIZE = 2000000 + _ids = collections.OrderedDict() + _hits = 0 + _miss = 0 + + comment_payout_ops = {} + _comment_payout_ops = [] + + @classmethod + def last_id(cls): + """Get the last indexed post id.""" + sql = "SELECT MAX(id) FROM hive_posts WHERE counter_deleted = 0" + return DB.query_one(sql) or 0 + + @classmethod + def get_id(cls, author, permlink): + """Look up id by author/permlink, making use of LRU cache.""" + url = author+'/'+permlink + if url in cls._ids: + cls._hits += 1 + _id = cls._ids.pop(url) + cls._ids[url] = _id + else: + cls._miss += 1 + sql = """ + SELECT hp.id + FROM 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 ha_a.name = :a AND hpd_p.permlink = :p + """ + _id = DB.query_one(sql, a=author, p=permlink) + if _id: + cls._set_id(url, _id) + + # cache stats (under 10M every 10K else every 100K) + total = cls._hits + cls._miss + if total % 100000 == 0: + log.info("pid lookups: %d, hits: %d (%.1f%%), entries: %d", + total, cls._hits, 100.0*cls._hits/total, len(cls._ids)) + + return _id + + @classmethod + def _set_id(cls, url, pid): + """Add an entry to the LRU, maintaining max size.""" + assert pid, "no pid provided for %s" % url + if len(cls._ids) > cls.CACHE_SIZE: + cls._ids.popitem(last=False) + cls._ids[url] = pid + + @classmethod + def delete_op(cls, op): + """Given a delete_comment op, mark the post as deleted. + + Also remove it from post-cache and feed-cache. + """ + cls.delete(op) + + @classmethod + def comment_op(cls, op, block_date): + """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 + FROM process_hive_post_operation((:author)::varchar, (:permlink)::varchar, (:parent_author)::varchar, (:parent_permlink)::varchar, (:date)::timestamp, (:community_support_start_date)::timestamp); + """ + + row = DB.query_row(sql, author=op['author'], permlink=op['permlink'], parent_author=op['parent_author'], + parent_permlink=op['parent_permlink'], date=block_date, community_support_start_date=START_DATE) + + result = dict(row) + + # TODO we need to enhance checking related community post validation and honor is_muted. + error = cls._verify_post_against_community(op, result['community_id'], result['is_valid'], result['is_muted']) + + cls._set_id(op['author']+'/'+op['permlink'], result['id']) + + if result['is_new_post']: + # add content data to hive_post_data + post_data = dict(title=op['title'], preview=op['preview'] if 'preview' in op else "", + img_url=op['img_url'] if 'img_url' in op else "", body=op['body'], + json=op['json_metadata'] if op['json_metadata'] else '{}') + else: + # edit case. Now we need to (potentially) apply patch to the post body. + new_body = cls._merge_post_body(id=result['id'], new_body_def=op['body']) + post_data = dict(title=op['title'], preview=op['preview'] if 'preview' in op else "", + img_url=op['img_url'] if 'img_url' in op else "", body=new_body, + json=op['json_metadata'] if op['json_metadata'] else '{}') + +# log.info("Adding author: {} permlink: {}".format(op['author'], op['permlink'])) + + printQuery = False # op['author'] == 'xeroc' and op['permlink'] == 're-piston-20160818t080811' + PostDataCache.add_data(result['id'], post_data, printQuery) + + md = {} + # At least one case where jsonMetadata was double-encoded: condenser#895 + # jsonMetadata = JSON.parse(jsonMetadata); + try: + md = loads(op['json_metadata']) + if not isinstance(md, dict): + md = {} + except Exception: + pass + + if not result['depth']: + tags = [result['post_category']] + if md and 'tags' in md and isinstance(md['tags'], list): + tags = tags + md['tags'] + tags = map(lambda tag: (str(tag) or '').strip('# ').lower()[:32], tags) + tags = filter(None, tags) + from funcy.seqs import distinct + tags = list(distinct(tags))[:5] + + for tag in tags: + Tags.add_tag(result['id'], tag) + + if not DbState.is_initial_sync(): + if error: + author_id = result['author_id'] + Notify('error', dst_id=author_id, when=block_date, + post_id=result['id'], payload=error).write() + cls._insert_feed_cache(result, block_date) + + @classmethod + def flush_into_db(cls): + sql = """ + 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 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 ), + 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, + t.total_payout_value, + t.curator_payout_value, + t.author_rewards, + t.author_rewards_hive, + t.author_rewards_hbd, + t.author_rewards_vests, + t.payout, + t.pending_payout, + t.payout_at, + t.last_payout_at, + t.cashout_time, + t.is_paidout, + t.total_vote_weight + from + ( + VALUES + --- put all constant values here + {} + ) AS T(author, permlink, + total_payout_value, + curator_payout_value, + author_rewards, + author_rewards_hive, + author_rewards_hbd, + author_rewards_vests, + payout, + pending_payout, + payout_at, + last_payout_at, + cashout_time, + 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 + WHERE ihp.permlink_id = data_source.permlink_id and ihp.author_id = data_source.author_id + """ + + def chunks(lst, n): + """Yield successive n-sized chunks from lst.""" + for i in range(0, len(lst), n): + yield lst[i:i + n] + + for chunk in chunks(cls._comment_payout_ops, 1000): + values_str = ','.join(chunk) + actual_query = sql.format(values_str) + DB.query(actual_query) + + n = len(cls._comment_payout_ops) + cls._comment_payout_ops.clear() + return n + + @classmethod + def comment_payout_op(cls): + values_limit = 1000 + + """ Process comment payment operations """ + for k, v in cls.comment_payout_ops.items(): + author = None + permlink = None + + # author payouts + author_rewards = None + author_rewards_hive = None + author_rewards_hbd = None + author_rewards_vests = None + + # total payout for comment + #comment_author_reward = None + curators_vesting_payout = None + total_payout_value = None; + curator_payout_value = None; + #beneficiary_payout_value = None; + + payout = None + 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: + value = v[ 'author_reward_operation' ] + author_rewards_hive = value['hive_payout']['amount'] + author_rewards_hbd = value['hbd_payout']['amount'] + author_rewards_vests = value['vesting_payout']['amount'] + curators_vesting_payout = value['curators_vesting_payout']['amount'] + if author is None: + author = value['author'] + permlink = value['permlink'] + + if v[ 'comment_reward_operation' ] is not None: + value = v[ 'comment_reward_operation' ] + #comment_author_reward = value['payout'] + author_rewards = value['author_rewards'] + total_payout_value = value['total_payout_value'] + curator_payout_value = value['curator_payout_value'] + #beneficiary_payout_value = value['beneficiary_payout_value'] + + 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'] + permlink = value['permlink'] + + if v[ 'effective_comment_vote_operation' ] is not None: + value = v[ 'effective_comment_vote_operation' ] + pending_payout = sbd_amount( value['pending_payout'] ) + total_vote_weight = value['total_vote_weight'] + if author is None: + author = value['author'] + permlink = value['permlink'] + + if v[ 'comment_payout_update_operation' ] is not None: + value = v[ 'comment_payout_update_operation' ] + is_paidout = True + + #Payout didn't generate any payments + if v[ 'comment_reward_operation' ] is None: + author_rewards = 0 + total_payout_value = "0.000 HBD" + curator_payout_value = "0.000 HBD" + + payout = 0 + pending_payout = 0 + + if author is None: + author = value['author'] + permlink = value['permlink'] + + #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( + author, + permlink, + "NULL" if ( total_payout_value is None ) else ( "'{}'".format( legacy_amount(total_payout_value) ) ), + "NULL" if ( curator_payout_value is None ) else ( "'{}'".format( legacy_amount(curator_payout_value) ) ), + "NULL" if ( author_rewards is None ) else author_rewards, + "NULL" if ( author_rewards_hive is None ) else author_rewards_hive, + "NULL" if ( author_rewards_hbd is None ) else author_rewards_hbd, + "NULL" if ( author_rewards_vests is None ) else author_rewards_vests, + "NULL" if ( payout is None ) else payout, + "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 ( total_vote_weight is None ) else total_vote_weight )) + + + n = len(cls.comment_payout_ops) + cls.comment_payout_ops.clear() + return n + + @classmethod + def update_child_count(cls, child_id, op='+'): + """ Increase/decrease child count by 1 """ + sql = """ + UPDATE + hive_posts + SET + children = GREATEST(0, ( + SELECT + CASE + WHEN children is NULL THEN 0 + WHEN children=32762 THEN 0 + ELSE children + END + FROM + hive_posts + WHERE id = (SELECT parent_id FROM hive_posts WHERE id = :child_id) + )::int + """ + if op == '+': + sql += """ + 1)""" + else: + sql += """ - 1)""" + sql += """ WHERE id = (SELECT parent_id FROM hive_posts WHERE id = :child_id)""" + + DB.query(sql, child_id=child_id) + + @classmethod + def comment_options_op(cls, op): + """ Process comment_options_operation """ + max_accepted_payout = legacy_amount(op['max_accepted_payout']) if 'max_accepted_payout' in op else '1000000.000 HBD' + allow_votes = op['allow_votes'] if 'allow_votes' in op else True + allow_curation_rewards = op['allow_curation_rewards'] if 'allow_curation_rewards' in op else True + percent_hbd = op['percent_hbd'] if 'percent_hbd' in op else 10000 + extensions = op['extensions'] if 'extensions' in op else [] + beneficiaries = [] + for extension in extensions: + if 'beneficiaries' in extensions: + beneficiaries = extension['beneficiaries'] + sql = """ + UPDATE + hive_posts hp + SET + max_accepted_payout = :max_accepted_payout, + percent_hbd = :percent_hbd, + allow_votes = :allow_votes, + allow_curation_rewards = :allow_curation_rewards, + beneficiaries = :beneficiaries + WHERE + hp.author_id = (SELECT id FROM hive_accounts WHERE name = :author) AND + hp.permlink_id = (SELECT id FROM hive_permlink_data WHERE permlink = :permlink) + """ + DB.query(sql, author=op['author'], permlink=op['permlink'], max_accepted_payout=max_accepted_payout, + percent_hbd=percent_hbd, allow_votes=allow_votes, allow_curation_rewards=allow_curation_rewards, + beneficiaries=beneficiaries) + + @classmethod + def delete(cls, op): + """Marks a post record as being deleted.""" + + sql = """ + SELECT id, depth + FROM delete_hive_post((:author)::varchar, (:permlink)::varchar); + """ + row = DB.query_row(sql, author=op['author'], permlink = op['permlink']) + + result = dict(row) + pid = result['id'] + + if not DbState.is_initial_sync(): + depth = result['depth'] + + if depth == 0: + # TODO: delete from hive_reblogs -- otherwise feed cache gets + # populated with deleted posts somwrimas + FeedCache.delete(pid) + + # force parent child recount when child is deleted + cls.update_child_count(pid, '-') + + @classmethod + def _insert_feed_cache(cls, result, date): + """Insert the new post into feed cache if it's not a comment.""" + if not result['depth']: + cls._insert_feed_cache4(result['depth'], result['id'], result['author_id'], date) + + @classmethod + def _insert_feed_cache4(cls, post_depth, post_id, author_id, post_date): + """Insert the new post into feed cache if it's not a comment.""" + if not post_depth: + FeedCache.insert(post_id, author_id, post_date) + + @classmethod + def _verify_post_against_community(cls, op, community_id, is_valid, is_muted): + error = None + if community_id and is_valid and not Community.is_post_valid(community_id, op): + error = 'not authorized' + #is_valid = False # TODO: reserved for future blacklist status? + is_muted = True + return error + + @classmethod + def _merge_post_body(cls, id, new_body_def): + new_body = '' + old_body = '' + + try: + dmp = diff_match_patch() + patch = dmp.patch_fromText(new_body_def) + if patch is not None and len(patch): + old_body = PostDataCache.get_post_body(id) + new_body, _ = dmp.patch_apply(patch, old_body) + #new_utf8_body = new_body.decode('utf-8') + #new_body = new_utf8_body + else: + new_body = new_body_def + except ValueError as e: +# log.info("Merging a body post id: {} caused an ValueError exception {}".format(id, e)) +# log.info("New body definition: {}".format(new_body_def)) +# log.info("Old body definition: {}".format(old_body)) + new_body = new_body_def + except Exception as ex: + log.info("Merging a body post id: {} caused an unknown exception {}".format(id, ex)) + log.info("New body definition: {}".format(new_body_def)) + log.info("Old body definition: {}".format(old_body)) + new_body = new_body_def + + return new_body + + + @classmethod + def flush(cls): + return cls.comment_payout_op() + cls.flush_into_db()