From 5f7432f9eace166f5e3d8f318d6e7256268a0bc8 Mon Sep 17 00:00:00 2001 From: Mariusz <mtrela@syncad.com> Date: Tue, 8 Sep 2020 13:33:44 +0200 Subject: [PATCH] The call `list_votes` sorted by `voter_comment` works --- hive/db/db_state.py | 5 +- hive/db/schema.py | 78 +++++++++++++++++++++++++++-- hive/server/database_api/methods.py | 33 +++--------- tests/tests_api | 2 +- 4 files changed, 86 insertions(+), 32 deletions(-) diff --git a/hive/db/db_state.py b/hive/db/db_state.py index c00fa119d..1d3d56937 100644 --- a/hive/db/db_state.py +++ b/hive/db/db_state.py @@ -112,7 +112,10 @@ class DbState: 'hive_accounts_ix5', # (cached_at, name) - 'hive_post_tags_tag_id_idx' + 'hive_post_tags_tag_id_idx', + + 'hive_votes_voter_id_permlink_id_idx', + 'hive_votes_permlink_id_voter_id_idx' ] to_return = [] diff --git a/hive/db/schema.py b/hive/db/schema.py index 85fbea1ce..5be435ebb 100644 --- a/hive/db/schema.py +++ b/hive/db/schema.py @@ -211,6 +211,8 @@ def build_metadata(): sa.Index('hive_votes_post_id_idx', 'post_id'), sa.Index('hive_votes_voter_id_idx', 'voter_id'), + sa.Index('hive_votes_voter_id_permlink_id_idx', 'voter_id', 'permlink_id'), + sa.Index('hive_votes_permlink_id_voter_id_idx', 'permlink_id', 'voter_id'), sa.Index('hive_votes_block_num_idx', 'block_num') ) @@ -844,10 +846,10 @@ def setup(db): sql = """ DROP VIEW IF EXISTS hive_votes_accounts_permlinks_view ; - CREATE VIEW hive_votes_accounts_permlinks_view + CREATE OR REPLACE VIEW hive_votes_accounts_permlinks_view AS SELECT - ha_v.id as voter_id, + hv.voter_id as voter_id, ha_a.name as author, hpd.permlink as permlink, vote_percent as percent, @@ -857,7 +859,7 @@ def setup(db): ha_v.name as voter, weight, num_changes, - hpd.id as permlink_id, + hv.permlink_id as permlink_id, post_id, is_effective FROM @@ -869,6 +871,76 @@ def setup(db): """ db.query_no_return(sql) + sql = """ + DROP VIEW IF EXISTS list_votes_by_voter_comment; + + CREATE OR REPLACE FUNCTION public.list_votes_by_voter_comment + ( + in _VOTER hive_accounts.name%TYPE, + in _AUTHOR hive_accounts.name%TYPE, + in _PERMLINK hive_permlink_data.permlink%TYPE, + in _LIMIT INT + ) + RETURNS TABLE + ( + voter hive_accounts.name%TYPE, + author hive_accounts.name%TYPE, + permlink hive_permlink_data.permlink%TYPE, + weight hive_votes.weight%TYPE, + rshares hive_votes.rshares%TYPE, + percent hive_votes.vote_percent%TYPE, + last_update hive_votes.last_update%TYPE, + num_changes hive_votes.num_changes%TYPE, + reputation hive_accounts.reputation%TYPE + ) + LANGUAGE 'plpgsql' + VOLATILE + AS $BODY$ + DECLARE _VOTER_ID INT; + DECLARE _PERMLINK_ID INT; + BEGIN + + IF _VOTER = '' THEN + _VOTER_ID = 0; + ELSE + _VOTER_ID = + ( + SELECT id FROM hive_accounts + WHERE name=_VOTER + ); + END IF; + + _PERMLINK_ID = find_comment_id( _AUTHOR, _PERMLINK, True); + + RETURN QUERY + ( + SELECT + v.voter, + v.author, + v.permlink, + v.weight, + v.rshares, + v.percent, + v.time, + v.num_changes, + v.reputation + FROM + hive_votes_accounts_permlinks_view v + WHERE + ( v.voter_id = _VOTER_ID and v.permlink_id >= _PERMLINK_ID ) + OR + ( v.voter_id > _VOTER_ID ) + ORDER BY + voter_id, + permlink_id + LIMIT _LIMIT + ); + + END + $BODY$; + """ + db.query_no_return(sql) + sql = """ DROP FUNCTION IF EXISTS find_comment_id(character varying, character varying, boolean) ; diff --git a/hive/server/database_api/methods.py b/hive/server/database_api/methods.py index 9b117f0ce..2d3129933 100644 --- a/hive/server/database_api/methods.py +++ b/hive/server/database_api/methods.py @@ -4,6 +4,7 @@ from enum import Enum from hive.server.common.helpers import return_error_info, valid_limit, valid_account, valid_permlink, valid_date from hive.server.database_api.objects import database_post_object from hive.utils.normalize import rep_to_raw, number_to_json_value, time_string_with_t +from hive.server.common.helpers import json_date import datetime @@ -173,7 +174,7 @@ def result_presentation(rows, votes_presentation): if votes_presentation == VotesPresentation.DatabaseApi: ret.append(dict(voter=row.voter, author=row.author, permlink=row.permlink, weight=number_to_json_value(row.weight), rshares=number_to_json_value(row.rshares), vote_percent=row.percent, - last_update=str(row.time), num_changes=row.num_changes)) + last_update=json_date(row.last_update), num_changes=row.num_changes)) elif votes_presentation == VotesPresentation.CondenserApi: ret.append(dict(percent=str(row.percent), reputation=rep_to_raw(row.reputation), rshares=number_to_json_value(row.rshares), voter=row.voter)) @@ -223,20 +224,7 @@ async def list_votes(context, start: list, limit: int, order: str, votes_present assert len(start) == 3, "Expecting 3 elements in start array" db = context['db'] - sql = """ - SELECT - voter, - author, - permlink, - weight, - rshares, - percent, - time, - num_changes, - reputation - FROM - hive_votes_accounts_permlinks_view - """ + sql = "" if order == "by_comment_voter": sql += """ @@ -253,17 +241,8 @@ async def list_votes(context, start: list, limit: int, order: str, votes_present rows = await db.query_all(sql, author=start[0], permlink=start[1], voter=start[2], limit=limit) if order == "by_voter_comment": - sql += """ - WHERE - voter >= :voter AND - author >= :author AND - permlink >= :permlink - ORDER BY - voter_id ASC, - post_id ASC - LIMIT - :limit - """ - rows = await db.query_all(sql, author=start[1], permlink=start[2], voter=start[0], limit=limit) + sql = "select * from list_votes_by_voter_comment( '{}', '{}', '{}', {} )".format( start[0], start[1], start[2], limit ) + + rows = await db.query_all(sql) return result_presentation(rows, votes_presentation) diff --git a/tests/tests_api b/tests/tests_api index 43f46f320..4216ec21d 160000 --- a/tests/tests_api +++ b/tests/tests_api @@ -1 +1 @@ -Subproject commit 43f46f320af704f4ac173005696ab8526e8d08f2 +Subproject commit 4216ec21d977cb6ee08f4f655b3cf40165f7292d -- GitLab