From ae6e142fa0eb4b5baf558890130474becc825dc9 Mon Sep 17 00:00:00 2001 From: Michal Zander Date: Fri, 8 Aug 2025 10:23:44 +0000 Subject: [PATCH 1/4] Change proxied_vests to text, values that represent vests must be text due to json numeric compression --- backend/types/accounts/proxy_power.sql | 51 +++++++++++++------------- 1 file changed, 25 insertions(+), 26 deletions(-) diff --git a/backend/types/accounts/proxy_power.sql b/backend/types/accounts/proxy_power.sql index 74b516fc..83dc12cf 100644 --- a/backend/types/accounts/proxy_power.sql +++ b/backend/types/accounts/proxy_power.sql @@ -1,26 +1,25 @@ -SET ROLE hafbe_owner; - -/** openapi:components:schemas -hafbe_types.proxy_power: - type: object - properties: - account: - type: string - proxy_date: - type: string - format: date-time - proxied_vests: - type: number - format: double - description: Own vesting shares plus sum of proxied vesting shares (levels 1–4) -*/ --- openapi-generated-code-begin -DROP TYPE IF EXISTS hafbe_types.proxy_power CASCADE; -CREATE TYPE hafbe_types.proxy_power AS ( - "account" TEXT, - "proxy_date" TIMESTAMP, - "proxied_vests" FLOAT -); --- openapi-generated-code-end - -RESET ROLE; +SET ROLE hafbe_owner; + +/** openapi:components:schemas +hafbe_types.proxy_power: + type: object + properties: + account: + type: string + proxy_date: + type: string + format: date-time + proxied_vests: + type: string + description: Own vesting shares plus sum of proxied vesting shares (levels 1–4) decreased by delayed vests +*/ +-- openapi-generated-code-begin +DROP TYPE IF EXISTS hafbe_types.proxy_power CASCADE; +CREATE TYPE hafbe_types.proxy_power AS ( + "account" TEXT, + "proxy_date" TIMESTAMP, + "proxied_vests" TEXT +); +-- openapi-generated-code-end + +RESET ROLE; -- GitLab From 6aecfc150aab4a89c0bba15f8f8ff56693ba4338 Mon Sep 17 00:00:00 2001 From: Michal Zander Date: Fri, 8 Aug 2025 10:25:17 +0000 Subject: [PATCH 2/4] Apply script-generated changes and remove incorrect manual edits --- .../accounts/get_account_proxies_power.sql | 210 +++++++++--------- endpoints/endpoint_schema.sql | 7 +- rewrite_rules.conf | 4 +- 3 files changed, 110 insertions(+), 111 deletions(-) diff --git a/endpoints/accounts/get_account_proxies_power.sql b/endpoints/accounts/get_account_proxies_power.sql index a3c524e3..b147e403 100644 --- a/endpoints/accounts/get_account_proxies_power.sql +++ b/endpoints/accounts/get_account_proxies_power.sql @@ -1,105 +1,105 @@ -SET ROLE hafbe_owner; - -/** openapi:components:schemas -hafbe_types.array_of_proxy_power: - type: array - items: - $ref: '#/components/schemas/hafbe_types.proxy_power' -*/ - -/** openapi:paths -'/accounts/{account-name}/proxy-power': - get: - tags: - - Accounts - summary: Get delegators and total vested power they contribute via witness-proxy - description: | - Lists every account that has set **{account-name}** as its witness proxy, - the date the proxy was set, and the total vested power contributed - (own vesting_shares plus sum of proxied vesting shares levels 1–4). - - SQL example: - * `SELECT * FROM hafbe_endpoints.get_account_proxies_power(''gtg'', 1);` - - REST call example: - * `GET ''https://%1$s/hafbe-api/accounts/gtg/proxy-power?page=1''` - operationId: hafbe_endpoints.get_account_proxies_power - parameters: - - in: path - name: account-name - required: true - schema: - type: string - description: Name of the proxy account - - in: query - name: page - required: false - schema: - type: integer - minimum: 1 - default: 1 - description: 1-based page number (100 rows per page) - responses: - '200': - description: Array of delegators and their total vested power - content: - application/json: - schema: - $ref: '#/components/schemas/hafbe_types.array_of_proxy_power' - exaxmple: [ - { - "account": "geoffrey", - "proxied_vests": 30847126195440, - "proxy_date": "2016-08-09T06:52:03" - } - ] - '404': - description: No such account in the database -*/ --- openapi-generated-code-begin -DROP FUNCTION IF EXISTS hafbe_endpoints.get_account_proxies_power; -CREATE OR REPLACE FUNCTION hafbe_endpoints.get_account_proxies_power( - "account-name" TEXT, - "page" INT = 1 -) -RETURNS SETOF hafbe_types.proxy_power --- openapi-generated-code-end -/*------------------------------------------ - hafbe_endpoints.get_account_proxies_power -------------------------------------------*/ -LANGUAGE plpgsql -STABLE -SET JIT = OFF -SET join_collapse_limit = 16 -SET from_collapse_limit = 16 -AS -$$ -DECLARE - _account_id INT := hafbe_backend.get_account_id("account-name"); -BEGIN - -- validate that page ≥ 1 - PERFORM hafbe_exceptions.validate_negative_page(page); - - -- set short public cache - PERFORM set_config( - 'response.headers', - '[{"Cache-Control":"public, max-age=5"}]', - true - ); - - -- ensure account exists - IF _account_id IS NULL THEN - PERFORM hafbe_exceptions.rest_raise_missing_account("account-name"); - END IF; - - -- delegate to ID-based backend logic - RETURN QUERY - SELECT * - FROM hafbe_backend.get_account_proxies_power( - _account_id, - page - ); -END; -$$; - -RESET ROLE; +SET ROLE hafbe_owner; + +/** openapi:components:schemas +hafbe_types.array_of_proxy_power: + type: array + items: + $ref: '#/components/schemas/hafbe_types.proxy_power' +*/ + +/** openapi:paths +'/accounts/{account-name}/proxy-power': + get: + tags: + - Accounts + summary: Get delegators and total vested power they contribute via witness-proxy + description: | + Lists every account that has set **{account-name}** as its witness proxy, + the date the proxy was set, and the total vested power contributed + (own vesting_shares plus sum of proxied vesting shares levels 1–4 and decreased by delayed vests). + + SQL example: + * `SELECT * FROM hafbe_endpoints.get_account_proxies_power(''gtg'', 1);` + + REST call example: + * `GET ''https://%1$s/hafbe-api/accounts/gtg/proxy-power?page=1''` + operationId: hafbe_endpoints.get_account_proxies_power + parameters: + - in: path + name: account-name + required: true + schema: + type: string + description: Name of the proxy account + - in: query + name: page + required: false + schema: + type: integer + minimum: 1 + default: 1 + description: 1-based page number (100 rows per page) + responses: + '200': + description: Array of delegators and their total vested power + content: + application/json: + schema: + $ref: '#/components/schemas/hafbe_types.array_of_proxy_power' + exaxmple: [ + { + "account": "geoffrey", + "proxied_vests": 30847126195440, + "proxy_date": "2016-08-09T06:52:03" + } + ] + '404': + description: No such account in the database +*/ +-- openapi-generated-code-begin +DROP FUNCTION IF EXISTS hafbe_endpoints.get_account_proxies_power; +CREATE OR REPLACE FUNCTION hafbe_endpoints.get_account_proxies_power( + "account-name" TEXT, + "page" INT = 1 +) +RETURNS SETOF hafbe_types.proxy_power +-- openapi-generated-code-end +/*------------------------------------------ + hafbe_endpoints.get_account_proxies_power +------------------------------------------*/ +LANGUAGE plpgsql +STABLE +SET JIT = OFF +SET join_collapse_limit = 16 +SET from_collapse_limit = 16 +AS +$$ +DECLARE + _account_id INT := hafbe_backend.get_account_id("account-name"); +BEGIN + -- validate that page ≥ 1 + PERFORM hafbe_exceptions.validate_negative_page(page); + + -- set short public cache + PERFORM set_config( + 'response.headers', + '[{"Cache-Control":"public, max-age=5"}]', + true + ); + + -- ensure account exists + IF _account_id IS NULL THEN + PERFORM hafbe_exceptions.rest_raise_missing_account("account-name"); + END IF; + + -- delegate to ID-based backend logic + RETURN QUERY + SELECT * + FROM hafbe_backend.get_account_proxies_power( + _account_id, + page + ); +END; +$$; + +RESET ROLE; diff --git a/endpoints/endpoint_schema.sql b/endpoints/endpoint_schema.sql index cf7b6365..a5075838 100644 --- a/endpoints/endpoint_schema.sql +++ b/endpoints/endpoint_schema.sql @@ -510,9 +510,8 @@ declare "format": "date-time" }, "proxied_vests": { - "type": "number", - "format": "double", - "description": "Own vesting shares plus sum of proxied vesting shares (levels 1\u20134)" + "type": "string", + "description": "Own vesting shares plus sum of proxied vesting shares (levels 1\u20134) decreased by delayed vests" } } }, @@ -1458,7 +1457,7 @@ declare "Accounts" ], "summary": "Get delegators and total vested power they contribute via witness-proxy", - "description": "Lists every account that has set **{account-name}** as its witness proxy,\nthe date the proxy was set, and the total vested power contributed\n(own vesting_shares plus sum of proxied vesting shares levels 1\u20134).\n\nSQL example:\n* `SELECT * FROM hafbe_endpoints.get_account_proxies_power(''gtg'', 1);`\n\nREST call example:\n* `GET ''https://%1$s/hafbe-api/accounts/gtg/proxy-power?page=1''`\n", + "description": "Lists every account that has set **{account-name}** as its witness proxy,\nthe date the proxy was set, and the total vested power contributed\n(own vesting_shares plus sum of proxied vesting shares levels 1\u20134 and decreased by delayed vests).\n\nSQL example:\n* `SELECT * FROM hafbe_endpoints.get_account_proxies_power(''gtg'', 1);`\n\nREST call example:\n* `GET ''https://%1$s/hafbe-api/accounts/gtg/proxy-power?page=1''`\n", "operationId": "hafbe_endpoints.get_account_proxies_power", "parameters": [ { diff --git a/rewrite_rules.conf b/rewrite_rules.conf index 608aa968..301da135 100644 --- a/rewrite_rules.conf +++ b/rewrite_rules.conf @@ -22,8 +22,8 @@ rewrite ^/accounts/([^/]+)/operations/comments/([^/]+) /rpc/get_comment_operatio rewrite ^/accounts/([^/]+)/comment-permlinks /rpc/get_comment_permlinks?account-name=$1 break; # endpoint for get /accounts/{account-name}/comment-permlinks - rewrite ^/accounts/([^/]+)/proxy-power /rpc/get_account_proxies_power?account-name=$1&page=$arg_page break; - # endpoint for get /accounts/{account-name}/proxy-power?page={page} +rewrite ^/accounts/([^/]+)/proxy-power /rpc/get_account_proxies_power?account-name=$1 break; +# endpoint for get /accounts/{account-name}/proxy-power rewrite ^/accounts/([^/]+)/authority /rpc/get_account_authority?account-name=$1 break; # endpoint for get /accounts/{account-name}/authority -- GitLab From b514d63cdf9963148c4fd8b46bce0461a2f7c96b Mon Sep 17 00:00:00 2001 From: Michal Zander Date: Fri, 8 Aug 2025 12:58:26 +0000 Subject: [PATCH 3/4] Fix backend of get_account_proxies_power --- .../get_account_proxies_power.sql | 187 ++++++++++++------ 1 file changed, 127 insertions(+), 60 deletions(-) diff --git a/backend/endpoint_helpers/get_account_proxies_power.sql b/backend/endpoint_helpers/get_account_proxies_power.sql index d9e65069..922acd0f 100644 --- a/backend/endpoint_helpers/get_account_proxies_power.sql +++ b/backend/endpoint_helpers/get_account_proxies_power.sql @@ -3,67 +3,134 @@ CREATE OR REPLACE FUNCTION hafbe_backend.get_account_proxies_power ( _page INT DEFAULT 1 ) RETURNS SETOF hafbe_types.proxy_power -LANGUAGE sql +LANGUAGE 'plpgsql' STABLE -AS $$ -/* -------------------------------------------------------------------------- - 1. Who is proxying to _account_id ? ---------------------------------------------------------------------------- */ -WITH delegates AS ( - SELECT - cap.account_id AS delegator_id, - da.name AS delegator, - bl.created_at AS proxy_date - FROM hafbe_app.current_account_proxies cap - JOIN hafd.accounts da ON da.id = cap.account_id - JOIN hive.blocks_view bl ON bl.num = cap.source_op_block - JOIN hive.operations_view ov - ON ov.id = cap.source_op - AND ov.block_num = cap.source_op_block - AND ov.body->>'type' = 'account_witness_proxy_operation' - WHERE cap.proxy_id = _account_id -), - -/* -------------------------------------------------------------------------- - 2. Their own vesting shares ---------------------------------------------------------------------------- */ -balance_agg AS ( - SELECT - cab.account AS delegator_id, - MAX(cab.balance) AS vesting_shares -- their native VESTS - FROM hafbe_bal.current_account_balances cab - WHERE cab.nai = 37 -- 37 = VESTS asset - AND cab.account IN (SELECT delegator_id FROM delegates) - GROUP BY cab.account -), - -/* -------------------------------------------------------------------------- - 3. Stake *already* proxied to each delegator (levels 1-4) - → sum the four rows to match blockchain’s proxied_vsf_votes[0..3] ---------------------------------------------------------------------------- */ -proxied_sum AS ( +AS +$$ +DECLARE + __max_page_size INT := 100; -- max page size for pagination +BEGIN + + /* + WITH delegates AS ( + + -- (comment) don't join on the beginning of the query + -- (comment) try to calculate pages first and join in the final query + + SELECT + cap.account_id AS delegator_id, + da.name AS delegator, + bl.created_at AS proxy_date + FROM hafbe_app.current_account_proxies cap + + -- (comment) use views instead of tables + + JOIN hafd.accounts da ON da.id = cap.account_id + JOIN hive.blocks_view bl ON bl.num = cap.source_op_block + + -- (comment) what is that join for? + -- (comment) only thing that comes to mind is that it is for ensuring that the operation that edited the proxy exists? + -- (comment) usless join generally + + JOIN hive.operations_view ov + ON ov.id = cap.source_op + AND ov.block_num = cap.source_op_block + AND ov.body->>'type' = 'account_witness_proxy_operation' + WHERE cap.proxy_id = _account_id + ), + balance_agg AS ( + SELECT + cab.account AS delegator_id, + + -- (comment) what is that MAX for? + -- (comment) there is primary key on (account, nai) - there is no aggregation needed + + MAX(cab.balance) AS vesting_shares -- their native VESTS + FROM hafbe_bal.current_account_balances cab + WHERE cab.nai = 37 -- 37 = VESTS asset + AND cab.account IN (SELECT delegator_id FROM delegates) + + -- (comment) what is that group for? + -- (comment) there is primary key on (account, nai) - there is no aggregation needed + + GROUP BY cab.account + ), + proxied_sum AS ( + + -- (comment) use voters_proxied_vests_sum_view instead of this + -- (comment) it is already aggregated there + + SELECT + vpvv.proxy_id AS delegator_id, + SUM(vpvv.proxied_vests) AS proxied_vests_total + FROM hafbe_backend.voters_proxied_vests_view vpvv + WHERE vpvv.proxy_level BETWEEN 1 AND 4 -- depths 1-4 only + AND vpvv.proxy_id IN (SELECT delegator_id FROM delegates) + GROUP BY vpvv.proxy_id + ) SELECT - vpvv.proxy_id AS delegator_id, - SUM(vpvv.proxied_vests) AS proxied_vests_total - FROM hafbe_backend.voters_proxied_vests_view vpvv - WHERE vpvv.proxy_level BETWEEN 1 AND 4 -- depths 1-4 only - AND vpvv.proxy_id IN (SELECT delegator_id FROM delegates) - GROUP BY vpvv.proxy_id -) + d.delegator, + d.proxy_date, + COALESCE(b.vesting_shares, 0) -- their own stake + + COALESCE(p.proxied_vests_total, 0) -- plus everything already proxied to them + AS proxy_power + FROM delegates d + LEFT JOIN balance_agg b ON b.delegator_id = d.delegator_id + LEFT JOIN proxied_sum p ON p.delegator_id = d.delegator_id + ORDER BY d.proxy_date DESC + + -- (comment) final query performance is slow due to: + -- excessive joins made on the beginning of the query + -- excessive aggregations that are not needed + -- and the final query is paginated AFTER those joins and aggregations which slows down the query even more + + LIMIT 100 + OFFSET (_page - 1) * 100; + */ + + RETURN QUERY + WITH delegates AS MATERIALIZED ( + SELECT + cap.account_id, + cap.source_op, + -- block number extracted from operation id - the block_num column will be removed + hafd.operation_id_to_block_num(cap.source_op) AS source_op_block + FROM hafbe_app.current_account_proxies cap + WHERE cap.proxy_id = _account_id + ORDER BY cap.source_op DESC + -- always calculate pages first before any joins if it is possible + LIMIT __max_page_size + OFFSET (_page - 1) * __max_page_size + ) + SELECT + av.name::TEXT, + bv.created_at, + -- vests must be converted to TEXT + -- because these values are big enough to be compressed by json and ultimately the returned value is incorrect + ( + -- vests of the account - by his delayed vests + proxied vests + -- (proxy vests are calculated with delayed vests taken into account) + COALESCE(cab.balance, 0) - COALESCE(aw.delayed_vests,0) + COALESCE(avs.proxied_vests, 0) + )::TEXT + FROM delegates d + -- always use views if avalable (hafd.operation_types is an exception) + JOIN hive.accounts_view av ON av.id = d.account_id + JOIN hive.blocks_view bv ON bv.num = d.source_op_block + -- no need for grouping + LEFT JOIN current_account_balances cab ON cab.account = d.account_id AND cab.nai = 37 + -- (without delayed vests the proxied power is not accurate) + LEFT JOIN account_withdraws aw ON aw.account = d.account_id + -- use voters_proxied_vests_sum_view where the grouping is already done - simpler code + LEFT JOIN hafbe_backend.voters_proxied_vests_sum_view avs ON avs.proxy_id = d.account_id + -- order again at the end of the query to ensure that the pagination is correct + ORDER BY d.source_op DESC; + + -- old version: Execution Time: 2269.497 ms -- blocktrades + -- old version: Execution Time: 7203.320 ms -- gtg + -- old version: Execution Time: 711.519 ms -- arcange (only 1 proxy account) -/* -------------------------------------------------------------------------- - 4. Final result ---------------------------------------------------------------------------- */ -SELECT - d.delegator, - d.proxy_date, - COALESCE(b.vesting_shares, 0) -- their own stake - + COALESCE(p.proxied_vests_total, 0) -- plus everything already proxied to them - AS proxy_power -FROM delegates d -LEFT JOIN balance_agg b ON b.delegator_id = d.delegator_id -LEFT JOIN proxied_sum p ON p.delegator_id = d.delegator_id -ORDER BY d.proxy_date DESC -LIMIT 100 -OFFSET (_page - 1) * 100; + -- new version: Execution Time: 75.345 ms -- blocktrades + -- new version: Execution Time: 40.623 ms -- gtg + -- new version: Execution Time: 30.473 ms -- arcange (only 1 proxy account) +END $$; -- GitLab From 386ca4bdd7d3f52c0d51ba0e2b108f85c762bf2a Mon Sep 17 00:00:00 2001 From: Michal Zander Date: Fri, 8 Aug 2025 13:12:47 +0000 Subject: [PATCH 4/4] Adjust patterns with proxied_vests TEXT --- .../positive/blocktrades.pat.json | 66 +++++++++---------- .../positive/gtg.pat.json | 6 +- 2 files changed, 36 insertions(+), 36 deletions(-) diff --git a/tests/tavern/get_account_proxies_power/positive/blocktrades.pat.json b/tests/tavern/get_account_proxies_power/positive/blocktrades.pat.json index d3973084..7ee7dce7 100644 --- a/tests/tavern/get_account_proxies_power/positive/blocktrades.pat.json +++ b/tests/tavern/get_account_proxies_power/positive/blocktrades.pat.json @@ -1,82 +1,82 @@ [ { "account": "danea", - "proxied_vests": 241425731894331, - "proxy_date": "2016-05-06T03:44:51" + "proxy_date": "2016-05-06T03:44:51", + "proxied_vests": "241425731894331" }, { "account": "openledger", - "proxied_vests": 11850514000000, - "proxy_date": "2016-05-06T03:43:18" + "proxy_date": "2016-05-06T03:43:18", + "proxied_vests": "11850514000000" }, { "account": "jamgotin", - "proxied_vests": 293541190672188, - "proxy_date": "2016-05-06T03:42:30" + "proxy_date": "2016-05-06T03:42:30", + "proxied_vests": "293541190672188" }, { "account": "gifthana", - "proxied_vests": 246276394422197, - "proxy_date": "2016-05-06T03:42:21" + "proxy_date": "2016-05-06T03:42:21", + "proxied_vests": "246276394422197" }, { "account": "emf", - "proxied_vests": 12150776000000, - "proxy_date": "2016-05-06T03:38:09" + "proxy_date": "2016-05-06T03:38:09", + "proxied_vests": "12150776000000" }, { "account": "chana", - "proxied_vests": 330051075842200, - "proxy_date": "2016-05-06T03:38:00" + "proxy_date": "2016-05-06T03:38:00", + "proxied_vests": "330051075842200" }, { "account": "graavor", - "proxied_vests": 509341464062592, - "proxy_date": "2016-05-06T03:37:54" + "proxy_date": "2016-05-06T03:37:54", + "proxied_vests": "509341464062592" }, { "account": "ashleigh", - "proxied_vests": 239048038338325, - "proxy_date": "2016-05-06T03:37:00" + "proxy_date": "2016-05-06T03:37:00", + "proxied_vests": "239048038338325" }, { "account": "augusta", - "proxied_vests": 249549060602068, - "proxy_date": "2016-05-06T03:36:51" + "proxy_date": "2016-05-06T03:36:51", + "proxied_vests": "249549060602068" }, { "account": "anastacia", - "proxied_vests": 641198377809732, - "proxy_date": "2016-05-06T03:36:42" + "proxy_date": "2016-05-06T03:36:42", + "proxied_vests": "641198377809732" }, { "account": "alpha", - "proxied_vests": 101004025003604, - "proxy_date": "2016-05-06T03:36:09" + "proxy_date": "2016-05-06T03:36:09", + "proxied_vests": "101004025003604" }, { "account": "aftergut", - "proxied_vests": 297425667812964, - "proxy_date": "2016-05-06T03:36:03" + "proxy_date": "2016-05-06T03:36:03", + "proxied_vests": "297425667812964" }, { "account": "abdul", - "proxied_vests": 581861822354929, - "proxy_date": "2016-05-06T03:35:54" + "proxy_date": "2016-05-06T03:35:54", + "proxied_vests": "581861822354929" }, { "account": "btsnow", - "proxied_vests": 12150776000000, - "proxy_date": "2016-05-06T03:35:21" + "proxy_date": "2016-05-06T03:35:21", + "proxied_vests": "12150776000000" }, { "account": "adrian", - "proxied_vests": 330641976262938, - "proxy_date": "2016-05-06T03:34:51" + "proxy_date": "2016-05-06T03:34:51", + "proxied_vests": "330641976262938" }, { "account": "analisa", - "proxied_vests": 885887038528666, - "proxy_date": "2016-05-06T03:34:42" + "proxy_date": "2016-05-06T03:34:42", + "proxied_vests": "885887038528666" } -] +] \ No newline at end of file diff --git a/tests/tavern/get_account_proxies_power/positive/gtg.pat.json b/tests/tavern/get_account_proxies_power/positive/gtg.pat.json index d1d24714..c91bd188 100644 --- a/tests/tavern/get_account_proxies_power/positive/gtg.pat.json +++ b/tests/tavern/get_account_proxies_power/positive/gtg.pat.json @@ -1,7 +1,7 @@ [ { "account": "geoffrey", - "proxied_vests": 30847126195440, - "proxy_date": "2016-08-09T06:52:03" + "proxy_date": "2016-08-09T06:52:03", + "proxied_vests": "30847126195440" } -] +] \ No newline at end of file -- GitLab