diff --git a/hive/db/schema.py b/hive/db/schema.py index 263b73ae32fe18ce929cfe64e8f20deb31d2ebea..55254cb8255fbf0a9b7d78f1b585622db6072dd3 100644 --- a/hive/db/schema.py +++ b/hive/db/schema.py @@ -73,7 +73,6 @@ def build_metadata(): 'hive_posts', metadata, sa.Column('id', sa.Integer, primary_key=True), sa.Column('parent_id', sa.Integer), - sa.Column('root_id', sa.Integer, nullable=False, server_defaut='-1'), # -1 will mean no root, root_author_id = author_id and root_permlink_id = permlink_id sa.Column('author_id', sa.Integer, nullable=False), sa.Column('permlink_id', sa.BigInteger, nullable=False), sa.Column('category_id', sa.Integer, nullable=False), @@ -388,9 +387,15 @@ def setup(db): "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, parent_id, root_id, author_id, permlink_id, category_id, community_id, parent_author_id, parent_permlink_id, root_author_id, root_permlink_id, created_at, depth) - VALUES (0, 0, -1, 0, 0, 0, 0, 0, 0, 0, 0, now(), 0);"""] + """ + INSERT INTO + public.hive_posts(id, parent_id, author_id, permlink_id, category_id, + community_id, parent_author_id, parent_permlink_id, root_author_id, + root_permlink_id, created_at, depth + ) + VALUES + (0, 0, 0, 0, 0, 0, 0, 0, 0, 0, now(), 0); + """] for sql in sqls: db.query(sql) @@ -398,100 +403,108 @@ def setup(db): db.query(sql) sql = """ -DROP FUNCTION if exists add_hive_post(character varying,character varying,character varying,character varying,timestamp without time zone,timestamp without time zone) -; -CREATE OR REPLACE FUNCTION add_hive_post( - 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 (id hive_posts.id%TYPE, author_id hive_posts.author_id%TYPE, permlink_id hive_posts.permlink_id%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 - (parent_id, root_id, parent_author_id, parent_permlink_id, depth, community_id, - category_id, - root_author_id, root_permlink_id, - is_muted, is_valid, - author_id, permlink_id, created_at) - SELECT - php.id AS parent_id, - (SELECT - CASE - WHEN root_id=-1 THEN php.id - ELSE root_id + DROP FUNCTION IF EXISTS add_hive_post(character varying,character varying,character varying,character varying,timestamp without time zone,timestamp without time zone); + CREATE OR REPLACE FUNCTION add_hive_post( + 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 (id hive_posts.id%TYPE, author_id hive_posts.author_id%TYPE, permlink_id hive_posts.permlink_id%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 (parent_id, parent_author_id, parent_permlink_id, depth, community_id, + category_id, + root_author_id, root_permlink_id, + is_muted, is_valid, + author_id, permlink_id, created_at + ) + SELECT + php.id AS parent_id, + php.author_id AS parent_author_id, + php.permlink_id AS parent_permlink_id, php.depth + 1 AS depth, + (CASE + WHEN _date > _community_support_start_date THEN + COALESCE(php.community_id, (select hc.id from hive_communities hc where hc.name = _parent_permlink)) + ELSE NULL + END) AS community_id, + COALESCE(php.category_id, (select hcg.id from hive_category_data hcg where hcg.category = _parent_permlink)) AS category_id, + php.root_author_id AS root_author_id, + php.root_permlink_id AS root_permlink_id, + php.is_muted as is_muted, php.is_valid AS is_valid, + ha.id AS author_id, hpd.id AS permlink_id, _date AS created_at + 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 + RETURNING hive_posts.id, hive_posts.author_id, hive_posts.permlink_id, hive_posts.parent_id, hive_posts.community_id, hive_posts.is_valid, hive_posts.is_muted, hive_posts.depth; + ELSE + INSERT INTO + hive_category_data (category) + VALUES + (_parent_permlink) + ON CONFLICT (category) DO NOTHING; + RETURN QUERY + INSERT INTO + hive_posts (parent_id, parent_author_id, parent_permlink_id, depth, community_id, + category_id, + root_author_id, root_permlink_id, + is_muted, is_valid, + author_id, permlink_id, created_at + ) + SELECT 0 AS parent_id, 0 AS parent_author_id, 0 AS parent_permlink_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, + ha.id AS root_author_id, -- use author_id AS root one if no parent + hpd.id AS root_permlink_id, -- use perlink_id AS root one if no parent + false AS is_muted, true AS is_valid, + ha.id AS author_id, hpd.id AS permlink_id, _date AS created_at + FROM hive_accounts ha, + hive_permlink_data hpd + WHERE ha.name = _author and hpd.permlink = _permlink + RETURNING hive_posts.id, hive_posts.author_id, hive_posts.permlink_id, hive_posts.parent_id, hive_posts.community_id, hive_posts.is_valid, hive_posts.is_muted, hive_posts.depth; + END IF; END - FROM hive_posts - WHERE hive_posts.id=php.id - ) as root_id, - php.author_id as parent_author_id, - php.permlink_id as parent_permlink_id, php.depth + 1 as depth, - (CASE - WHEN _date > _community_support_start_date THEN - COALESCE(php.community_id, (select hc.id from hive_communities hc where hc.name = _parent_permlink)) - ELSE NULL - END) as community_id, - COALESCE(php.category_id, (select hcg.id from hive_category_data hcg where hcg.category = _parent_permlink)) as category_id, - php.root_author_id as root_author_id, - php.root_permlink_id as root_permlink_id, - php.is_muted as is_muted, php.is_valid as is_valid, - ha.id as author_id, hpd.id as permlink_id, _date as created_at - 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 - RETURNING hive_posts.id, hive_posts.author_id, hive_posts.permlink_id, hive_posts.parent_id, hive_posts.community_id, hive_posts.is_valid, hive_posts.is_muted, hive_posts.depth -; -ELSE - INSERT INTO hive_category_data - (category) - VALUES (_parent_permlink) - ON CONFLICT (category) DO NOTHING - ; - - RETURN QUERY INSERT INTO hive_posts - (parent_id, root_id, parent_author_id, parent_permlink_id, depth, community_id, - category_id, - root_author_id, root_permlink_id, - is_muted, is_valid, - author_id, permlink_id, created_at) - SELECT 0 AS parent_id, -1 AS root_id, 0 as parent_author_id, 0 as parent_permlink_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, - ha.id as root_author_id, -- use author_id as root one if no parent - hpd.id as root_permlink_id, -- use perlink_id as root one if no parent - false as is_muted, true as is_valid, - ha.id as author_id, hpd.id as permlink_id, _date as created_at - FROM hive_accounts ha, - hive_permlink_data hpd - WHERE ha.name = _author and hpd.permlink = _permlink - RETURNING hive_posts.id, hive_posts.author_id, hive_posts.permlink_id, hive_posts.parent_id, hive_posts.community_id, hive_posts.is_valid, hive_posts.is_muted, hive_posts.depth; -END IF; -END -$function$ + $function$ + """ + db.query_no_return(sql) + + sql = """ + DROP MATERIALIZED VIEW IF EXISTS hive_posts_a_p + ; + CREATE MATERIALIZED VIEW hive_posts_a_p + AS + SELECT hp.id AS id, + ha_a.name AS author, + hpd_p.permlink AS permlink + 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 + WITH DATA + ; + DROP INDEX IF EXISTS hive_posts_a_p_idx + ; + CREATE unique index hive_posts_a_p_idx ON hive_posts_a_p (author collate "C", permlink collate "C") """ db.query_no_return(sql) diff --git a/hive/indexer/posts.py b/hive/indexer/posts.py index ce4062384a9f3f8570fd429ff959476a2e488f22..99d2bcbeb8f9bc223084c8b3744d8f447d16f5ea 100644 --- a/hive/indexer/posts.py +++ b/hive/indexer/posts.py @@ -32,20 +32,6 @@ class Posts: sql = "SELECT MAX(id) FROM hive_posts WHERE is_deleted = '0'" return DB.query_one(sql) or 0 - @classmethod - def find_root(cls, author, permlink): - """ Find root for post """ - sql = """ - SELECT - root_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) - return _id - @classmethod def get_id(cls, author, permlink): """Look up id by author/permlink, making use of LRU cache.""" @@ -96,11 +82,18 @@ class Posts: @classmethod def get_id_and_depth(cls, author, permlink): """Get the id and depth of @author/permlink post.""" - _id = cls.get_id(author, permlink) - if not _id: - return (None, -1) - depth = DB.query_one("SELECT depth FROM hive_posts WHERE id = :id", id=_id) - return (_id, depth) + sql = """ + SELECT + hp.id, + COALESCE(hp.depth, -1) + 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 = :author AND hpd_p.permlink = :permlink + """ + pid, depth = DB.query_row(sql, author=author, permlink=permlink) + return (pid, depth) @classmethod def is_pid_deleted(cls, pid): @@ -135,7 +128,6 @@ class Posts: """ Process comment payment operations """ for k, v in ops.items(): author, permlink = k.split("/") - pid = cls.get_id(author, permlink) # total payout to curators curator_rewards_sum = 0 # author payouts @@ -172,7 +164,13 @@ class Posts: last_payout = :last_payout, cashout_time = :cashout_time, is_paidout = true - WHERE id = :id + WHERE id = ( + 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 = :author AND hpd_p.permlink = :permlink + ) """ DB.query(sql, total_payout_value=legacy_amount(comment_author_reward), curator_payout_value=legacy_amount(curator_rewards), @@ -182,7 +180,7 @@ class Posts: author_rewards_vests=author_rewards_vests, last_payout=date, cashout_time=date, - id=pid) + author=author, permlink=permlink) @classmethod def insert(cls, op, date): @@ -228,12 +226,10 @@ class Posts: if op['parent_author']: #update parent child count - prnt = cls._get_parent_by_child_id(result['id']) - if prnt is not None: - cls.update_child_count(prnt['id']) + cls.update_child_count(result['id']) @classmethod - def update_child_count(cls, parent_id, op='+'): + def update_child_count(cls, child_id, op='+'): """ Increase/decrease child count by 1 """ sql = """ UPDATE @@ -248,16 +244,16 @@ class Posts: END FROM hive_posts - WHERE id = :id + WHERE id = (SELECT parent_id FROM hive_posts WHERE id = :child_id) )::int """ if op == '+': sql += """ + 1)""" else: sql += """ - 1)""" - sql += """ WHERE id = :id""" + sql += """ WHERE id = (SELECT parent_id FROM hive_posts WHERE id = :child_id)""" - DB.query(sql, id=parent_id) + DB.query(sql, child_id=child_id) @classmethod def undelete(cls, op, date, pid): @@ -277,7 +273,6 @@ class Posts: is_muted = :is_muted, is_deleted = '0', is_pinned = '0', - parent_id = :parent_id, category_id = (SELECT id FROM hive_category_data WHERE category = :category), community_id = :community_id, depth = :depth @@ -308,9 +303,7 @@ class Posts: FeedCache.delete(pid) # force parent child recount when child is deleted - prnt = cls._get_parent_by_child_id(pid) - if prnt is not None: - cls.update_child_count(prnt['id'], '-') + cls.update_child_count(pid, '-') @classmethod def update(cls, op, date, pid): @@ -318,15 +311,6 @@ class Posts: # pylint: disable=unused-argument post = cls._build_post(op, date) - # add permlinks to permlink table - for permlink in ['permlink', 'parent_permlink', 'root_permlink']: - if permlink in op: - sql = """ - INSERT INTO hive_permlink_data (permlink) - VALUES (:permlink) - ON CONFLICT (permlink) DO NOTHING""" - DB.query(sql, permlink=op[permlink]) - # add category to category table sql = """ INSERT INTO hive_category_data (category) @@ -372,7 +356,6 @@ class Posts: for comment_pending_payout in comment_pending_payouts: if 'cashout_info' in comment_pending_payout: cpp = comment_pending_payout['cashout_info'] - pid = cls.get_id(cpp['author'], cpp['permlink']) sql = """UPDATE hive_posts SET @@ -394,7 +377,13 @@ class Posts: allow_replies = :allow_replies, allow_votes = :allow_votes, allow_curation_rewards = :allow_curation_rewards - WHERE id = :id + WHERE id = ( + 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 = :author AND hpd_p.permlink = :permlink + ) """ DB.query(sql, total_payout_value=legacy_amount(cpp['total_payout_value']), @@ -415,24 +404,7 @@ class Posts: allow_replies=cpp['allow_replies'], allow_votes=cpp['allow_votes'], allow_curation_rewards=cpp['allow_curation_rewards'], - id=pid) - - @classmethod - def _get_parent_by_child_id(cls, child_id): - """Get parent's `id`, `author`, `permlink` by child id.""" - sql = """ - SELECT - hp.id, - ha_a.name as author, - hpd_p.permlink as permlink - 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 - hp.id = (SELECT parent_id FROM hive_posts WHERE id = :child_id)""" - result = DB.query_row(sql, child_id=child_id) - return None if result is None else result + author=cpp['author'], permlink=cpp['permlink']) @classmethod def _insert_feed_cache(cls, result): @@ -447,7 +419,6 @@ class Posts: 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 @@ -473,8 +444,6 @@ class Posts: # if this is a top-level post: if not op['parent_author']: - parent_id = None - root_id = -1 depth = 0 category = op['parent_permlink'] community_id = None @@ -482,40 +451,28 @@ class Posts: community_id = Community.validated_id(category) is_valid = True is_muted = False - root_author = op['author'] - root_permlink = op['permlink'] # this is a comment; inherit parent props. else: - parent_id = cls.get_id(op['parent_author'], op['parent_permlink']) sql = """ SELECT depth, hcd.category as category, community_id, is_valid, is_muted FROM hive_posts hp INNER JOIN hive_category_data hcd ON hcd.id = hp.category_id - WHERE hp.id = :id""" - (parent_depth, category, community_id, is_valid, is_muted) = DB.query_row(sql, id=parent_id) + WHERE hp.id = ( + SELECT hp1.id + FROM hive_posts hp1 + INNER JOIN hive_accounts ha_a ON ha_a.id = hp1.author_id + INNER JOIN hive_permlink_data hpd_p ON hpd_p.id = hp1.permlink_id + WHERE ha_a.name = :author AND hpd_p.permlink = :permlink + ) + """ + (parent_depth, category, community_id, is_valid, is_muted) = DB.query_row(sql, author=op['parent_author'], permlink=op['parent_permlink']) depth = parent_depth + 1 if not is_valid: error = 'replying to invalid post' elif is_muted: error = 'replying to muted post' #find root comment - root_id = cls.find_root(op['parent_author'], op['parent_permlink']) - if root_id > -1: - sql = """ - SELECT - ha_a.name as author, hpd_p.permlink as permlink - 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 - hp.id = :id""" - root_author, root_permlink = DB.query_row(sql, id=root_id) - else: - root_id = parent_id - root_author = op['parent_author'] - root_permlink = op['parent_permlink'] # check post validity in specified context error = None @@ -524,13 +481,8 @@ class Posts: #is_valid = False # TODO: reserved for future blacklist status? is_muted = True - ret = dict(parent_id=parent_id, root_id=root_id, id=pid, community_id=community_id, + ret = dict(id=pid, community_id=community_id, category=category, is_muted=is_muted, is_valid=is_valid, - depth=depth, date=date, error=error, - author=op['author'], permlink=op['permlink'], - parent_author=op['parent_author'], - parent_permlink=op['parent_permlink'], - root_permlink=root_permlink, - root_author=root_author) + depth=depth, date=date, error=error) return ret