From dc21d325e919cb84b17ae5417c8f9500ad6b8187 Mon Sep 17 00:00:00 2001 From: mtrela <mtrela@syncad.com> Date: Thu, 3 Sep 2020 13:46:10 +0200 Subject: [PATCH] Final version of `hive_accounts_info_view` view --- hive/db/schema.py | 68 +++++++++++++++++++++++++++++ hive/server/bridge_api/objects.py | 2 +- hive/server/condenser_api/cursor.py | 11 +++-- 3 files changed, 74 insertions(+), 7 deletions(-) diff --git a/hive/db/schema.py b/hive/db/schema.py index fa2b8fcd1..a06125cf9 100644 --- a/hive/db/schema.py +++ b/hive/db/schema.py @@ -560,6 +560,74 @@ def setup(db): """ db.query_no_return(sql) + # In original hivemind, a value of 'active_at' was calculated from + # max + # { + # created ( account_create_operation ), + # last_account_update ( account_update_operation/account_update2_operation ), + # last_post ( comment_operation - only creation ) + # last_root_post ( comment_operation - only creation + only ROOT ), + # last_vote_time ( vote_operation ) + # } + # In order to simplify calculations, `last_account_update` is not taken into consideration, because this updating accounts is very rare + # and posting/voting after an account updating, fixes `active_at` value immediately. + + sql = """ + DROP VIEW IF EXISTS public.hive_accounts_info_view; + + CREATE OR REPLACE VIEW public.hive_accounts_info_view + AS + SELECT + id, + name, + COALESCE( + ( + select count(*) post_count + FROM hive_posts hp + WHERE ha.id=hp.author_id + GROUP BY hp.author_id + ), + 0 + ) post_count, + COALESCE( + ( + select max(hp.created_at) + FROM hive_posts hp + WHERE ha.id=hp.author_id + GROUP BY hp.author_id + ), + '1970-01-01 00:00:00.0' + ) post_active_at, + COALESCE( + ( + select max(hv.last_update) + from hive_votes hv + WHERE ha.id=hv.voter_id + GROUP BY hv.voter_id + ), + '1970-01-01 00:00:00.0' + ) AS vote_active_at, + created_at, + display_name, + about, + reputation, + profile_image, + location, + website, + cover_image, + rank, + following, + followers, + proxy, + proxy_weight, + lastread_at, + cached_at, + raw_json + FROM + hive_accounts ha + """ + db.query_no_return(sql) + sql = """ DROP VIEW IF EXISTS public.hive_posts_view; diff --git a/hive/server/bridge_api/objects.py b/hive/server/bridge_api/objects.py index eec588ef2..1d185af61 100644 --- a/hive/server/bridge_api/objects.py +++ b/hive/server/bridge_api/objects.py @@ -201,7 +201,7 @@ def _condenser_profile_object(row): 'id': row['id'], 'name': row['name'], 'created': json_date(row['created_at']), - 'active': json_date(row['active_at']), + 'active': json_date(max( row['created_at'], row['post_active_at'], row['vote_active_at'] )), 'post_count': row['post_count'], 'reputation': row['reputation'], 'blacklists': blacklists, diff --git a/hive/server/condenser_api/cursor.py b/hive/server/condenser_api/cursor.py index 3d4d0ecf5..1094b0376 100644 --- a/hive/server/condenser_api/cursor.py +++ b/hive/server/condenser_api/cursor.py @@ -439,11 +439,8 @@ async def get_accounts(db, accounts: list): ret = [] names = ["'{}'".format(a) for a in accounts] - sql = """SELECT created_at, reputation, display_name, about, - location, website, profile_image, cover_image, followers, following, - proxy, post_count, proxy_weight, vote_weight, rank, - lastread_at, active_at, cached_at, raw_json - FROM hive_accounts WHERE name IN ({})""".format(",".join(names)) + sql = """SELECT * + FROM hive_accounts_info_view WHERE name IN ({})""".format(",".join(names)) result = await db.query_all(sql) for row in result: @@ -466,7 +463,9 @@ async def get_accounts(db, accounts: list): account_data['vote_weight'] = row.vote_weight account_data['rank'] = row.rank account_data['lastread_at'] = row.lastread_at.isoformat() - account_data['active_at'] = row.active_at.isoformat() + + account_data['active_at'] = max( row.created_at, row.post_active_at, row.vote_active_at ).isoformat() + account_data['cached_at'] = row.cached_at.isoformat() ret.append(account_data) -- GitLab