From 13c5195cfcd16f17fdbfb11eded838e6f325e801 Mon Sep 17 00:00:00 2001 From: kristupas Date: Thu, 7 Jul 2022 12:37:36 +0000 Subject: [PATCH 01/89] Updated 'witness_votes', 'get_witness_voters()', removed 'get_top_witnesses()', 'get_witness_by_account' #22 --- api/backend.sql | 56 +++++++++++++++++------------------------------ api/endpoints.sql | 18 ++------------- db/hafbe_app.sql | 24 +++++++++++--------- 3 files changed, 36 insertions(+), 62 deletions(-) diff --git a/api/backend.sql b/api/backend.sql index d966c63..af548dd 100644 --- a/api/backend.sql +++ b/api/backend.sql @@ -357,45 +357,29 @@ RETURNS JSON LANGUAGE 'plpgsql' AS $$ +DECLARE + __result JSON; BEGIN - RETURN json_agg(account_id)::JSON FROM ( - SELECT account_id FROM ( - SELECT DISTINCT ON (account_id) - account_id, - SUM(vote) AS voted - FROM - hafbe_app.witness_votes - WHERE - witness_id = _witness_id + SELECT INTO __result json_agg(acc.name)::JSON + FROM ( + SELECT DISTINCT ON (voter_id) + voter_id, approve + FROM ( + SELECT voter_id, approve + FROM hafbe_app.witness_votes + WHERE witness_id = _witness_id + ORDER BY timestamp DESC ) votes - WHERE - voted = 1 - LIMIT _limit - ) voters; -END -$$ -; - -CREATE FUNCTION hafbe_backend.get_top_witnesses(_witnesses_number INT) -RETURNS JSON -LANGUAGE 'plpython3u' -AS -$$ - import subprocess - import json + ) voters + JOIN LATERAL ( + SELECT name, id + FROM hive.accounts_view + ) acc ON acc.id = voters.voter_id + WHERE voters.approve IS TRUE + LIMIT _limit; - return json.dumps( - json.loads( - subprocess.check_output([ - - """ - curl -X POST https://api.hive.blog \ - -H 'Content-Type: application/json' \ - -d '{"jsonrpc": "2.0", "method": "condenser_api.get_witnesses_by_vote", "params": [null, %d], "id": null}' - """ % _witnesses_number - ], shell=True).decode('utf-8') - )['result'] - ) + RETURN CASE WHEN __result IS NULL THEN '[]' ELSE __result END; +END $$ ; diff --git a/api/endpoints.sql b/api/endpoints.sql index b547577..30e16ee 100644 --- a/api/endpoints.sql +++ b/api/endpoints.sql @@ -221,7 +221,7 @@ END $$ ; -CREATE FUNCTION hafbe_endpoints.get_top_witnesses(_witnesses_number INT = 50) +CREATE FUNCTION hafbe_endpoints.get_witnesses(_witnesses_number INT = 50) RETURNS JSON LANGUAGE 'plpgsql' AS @@ -231,21 +231,7 @@ BEGIN _witnesses_number = FALSE; END IF; - RETURN json_agg(witness->>'owner') - FROM ( - SELECT json_array_elements(hafbe_backend.get_top_witnesses(_witnesses_number)) AS witness - ) result; -END -$$ -; - -CREATE FUNCTION hafbe_endpoints.get_witness_by_account(_account TEXT) -RETURNS JSON -LANGUAGE 'plpgsql' -AS -$$ -BEGIN - RETURN hafbe_backend.get_witness_by_account(_account); + RETURN hafbe_backend.get_witnesses(_account); END $$ ; diff --git a/db/hafbe_app.sql b/db/hafbe_app.sql index 8cf2ecf..a5559b8 100644 --- a/db/hafbe_app.sql +++ b/db/hafbe_app.sql @@ -16,13 +16,14 @@ BEGIN VALUES (True, 0); CREATE TABLE IF NOT EXISTS hafbe_app.witness_votes ( - witness TEXT NOT NULL, - voter TEXT NOT NULL, - vote INT NOT NULL + witness_id INT NOT NULL, + voter_id INT NOT NULL, + approve BOOLEAN NOT NULL, + timestamp TIMESTAMP NOT NULL ) INHERITS (hive.hafbe_app); - CREATE INDEX IF NOT EXISTS witness_votes_witness ON hafbe_app.witness_votes USING btree (witness); - CREATE INDEX IF NOT EXISTS witness_votes_voter ON hafbe_app.witness_votes USING btree (voter); + CREATE INDEX IF NOT EXISTS witness_votes_witness_id ON hafbe_app.witness_votes USING btree (witness_id); + CREATE INDEX IF NOT EXISTS witness_votes_voter_id ON hafbe_app.witness_votes USING btree (voter_id); CREATE TABLE IF NOT EXISTS hafbe_app.hived_account_cache ( account TEXT NOT NULL, @@ -105,13 +106,16 @@ BEGIN FOR b IN _from .. _to LOOP - INSERT INTO hafbe_app.witness_votes (witness, voter, vote) + INSERT INTO hafbe_app.witness_votes (witness_id, voter_id, approve, timestamp) SELECT - body_value->>'witness', - body_value->>'account', - CASE WHEN (body_value->>'approve')::BOOLEAN IS TRUE THEN 1 ELSE -1 END + hafbe_backend.get_account_id(body_value->>'witness'), + hafbe_backend.get_account_id(body_value->>'account'), + (body_value->>'approve')::BOOLEAN, + timestamp FROM ( - SELECT (body::JSON)->'value' AS body_value + SELECT + (body::JSON)->'value' AS body_value, + timestamp FROM hive.operations_view WHERE op_type_id = 12 AND block_num = b ) hov -- GitLab From 27fc376437aec5d1336e4be70c9df0624d5fdfe6 Mon Sep 17 00:00:00 2001 From: kristupas Date: Thu, 7 Jul 2022 13:23:41 +0000 Subject: [PATCH 02/89] Updated 'get_witness_voters()', created 'account_proxies' table --- api/backend.sql | 59 +++++++++++++++--------------------------------- db/hafbe_app.sql | 29 ++++++++++++++++++++---- 2 files changed, 43 insertions(+), 45 deletions(-) diff --git a/api/backend.sql b/api/backend.sql index af548dd..dea9b3e 100644 --- a/api/backend.sql +++ b/api/backend.sql @@ -357,54 +357,31 @@ RETURNS JSON LANGUAGE 'plpgsql' AS $$ -DECLARE - __result JSON; BEGIN - SELECT INTO __result json_agg(acc.name)::JSON + RETURN CASE WHEN res IS NULL THEN '[]' ELSE res END FROM ( - SELECT DISTINCT ON (voter_id) - voter_id, approve + SELECT json_agg(acc.name)::JSON AS res FROM ( - SELECT voter_id, approve - FROM hafbe_app.witness_votes - WHERE witness_id = _witness_id - ORDER BY timestamp DESC - ) votes - ) voters - JOIN LATERAL ( - SELECT name, id - FROM hive.accounts_view - ) acc ON acc.id = voters.voter_id - WHERE voters.approve IS TRUE - LIMIT _limit; - - RETURN CASE WHEN __result IS NULL THEN '[]' ELSE __result END; + SELECT DISTINCT ON (voter_id) + voter_id, approve + FROM ( + SELECT voter_id, approve + FROM hafbe_app.witness_votes + WHERE witness_id = _witness_id + ORDER BY timestamp DESC + ) votes + ) voters + JOIN LATERAL ( + SELECT name, id + FROM hive.accounts_view + ) acc ON acc.id = voters.voter_id + WHERE voters.approve IS TRUE + LIMIT _limit + ) result; END $$ ; -CREATE FUNCTION hafbe_backend.get_witness_by_account(_account TEXT) -RETURNS JSON -LANGUAGE 'plpython3u' -AS -$$ - import subprocess - import json - - return json.dumps( - json.loads( - subprocess.check_output([ - """ - curl -X POST https://api.hive.blog \ - -H 'Content-Type: application/json' \ - -d '{"jsonrpc": "2.0", "method": "condenser_api.get_witness_by_account", "params": ["%s"], "id": null}' - """ % _account - ], shell=True).decode('utf-8') - )['result'] - ) -$$ -; - CREATE FUNCTION hafbe_backend.get_account(_account TEXT) RETURNS JSON LANGUAGE 'plpython3u' diff --git a/db/hafbe_app.sql b/db/hafbe_app.sql index a5559b8..e19d662 100644 --- a/db/hafbe_app.sql +++ b/db/hafbe_app.sql @@ -25,6 +25,14 @@ BEGIN CREATE INDEX IF NOT EXISTS witness_votes_witness_id ON hafbe_app.witness_votes USING btree (witness_id); CREATE INDEX IF NOT EXISTS witness_votes_voter_id ON hafbe_app.witness_votes USING btree (voter_id); + CREATE TABLE IF NOT EXISTS hafbe_app.account_proxies ( + proxy_id INT NOT NULL, + account_id INT NOT NULL + ) INHERITS (hive.hafbe_app); + + CREATE INDEX IF NOT EXISTS account_proxies_proxy_id ON hafbe_app.account_proxies USING btree (proxy_id); + CREATE INDEX IF NOT EXISTS account_proxies_account_id ON hafbe_app.account_proxies USING btree (account_id); + CREATE TABLE IF NOT EXISTS hafbe_app.hived_account_cache ( account TEXT NOT NULL, data JSON NOT NULL, @@ -102,25 +110,38 @@ $$ DECLARE __last_reported_block INT := 0; __block_api_data JSON; + __proxy_operation JSON; BEGIN FOR b IN _from .. _to LOOP INSERT INTO hafbe_app.witness_votes (witness_id, voter_id, approve, timestamp) SELECT - hafbe_backend.get_account_id(body_value->>'witness'), - hafbe_backend.get_account_id(body_value->>'account'), - (body_value->>'approve')::BOOLEAN, + hafbe_backend.get_account_id(approve_operation->>'witness'), + hafbe_backend.get_account_id(approve_operation->>'account'), + (approve_operation->>'approve')::BOOLEAN, timestamp FROM ( SELECT - (body::JSON)->'value' AS body_value, + (body::JSON)->'value' AS approve_operation, timestamp FROM hive.operations_view WHERE op_type_id = 12 AND block_num = b ) hov ON CONFLICT DO NOTHING; + SELECT (body::JSON)->'value' FROM hive.operations_view WHERE op_type_id = 13 AND block_num = b INTO __proxy_operation; + + IF length(__proxy_operation->>'proxy') != 0 THEN + INSERT INTO hafbe_app.account_proxies (proxy_id, account_id) + SELECT + hafbe_backend.get_account_id(__proxy_operation->>'proxy'), + hafbe_backend.get_account_id(__proxy_operation->>'account') + ON CONFLICT DO NOTHING; + ELSE + DELETE FROM hafbe_app.account_proxies WHERE proxy_id = hafbe_backend.get_account_id(__proxy_operation->>'proxy'); + END IF; + /* IF __balance_change.source_op_block % _report_step = 0 AND __last_reported_block != __balance_change.source_op_block THEN RAISE NOTICE 'Processed data for block: %', __balance_change.source_op_block; -- GitLab From 79e4303bb1e541bbab93892d613ac843c90f35ff Mon Sep 17 00:00:00 2001 From: kristupas Date: Fri, 8 Jul 2022 09:25:01 +0000 Subject: [PATCH 03/89] Added 'operation_id' to hafbe tables #22 --- api/backend.sql | 17 +++++++++++++---- db/hafbe_app.sql | 41 ++++++++++++++++++++++------------------- 2 files changed, 35 insertions(+), 23 deletions(-) diff --git a/api/backend.sql b/api/backend.sql index dea9b3e..e634db4 100644 --- a/api/backend.sql +++ b/api/backend.sql @@ -365,11 +365,20 @@ BEGIN SELECT DISTINCT ON (voter_id) voter_id, approve FROM ( - SELECT voter_id, approve - FROM hafbe_app.witness_votes - WHERE witness_id = _witness_id + SELECT + votes.voter_id AS voter_id, + votes.approve AS approve + FROM ( + SELECT voter_id, approve, operation_id + FROM hafbe_app.witness_votes + WHERE witness_id = _witness_id + ) votes + JOIN LATERAL ( + SELECT timestamp, id + FROM hive.operations_view + ) hov ON votes.operation_id = hov.id ORDER BY timestamp DESC - ) votes + ) votes_ordered ) voters JOIN LATERAL ( SELECT name, id diff --git a/db/hafbe_app.sql b/db/hafbe_app.sql index e19d662..0975a13 100644 --- a/db/hafbe_app.sql +++ b/db/hafbe_app.sql @@ -19,19 +19,22 @@ BEGIN witness_id INT NOT NULL, voter_id INT NOT NULL, approve BOOLEAN NOT NULL, - timestamp TIMESTAMP NOT NULL + operation_id INT NOT NULL ) INHERITS (hive.hafbe_app); CREATE INDEX IF NOT EXISTS witness_votes_witness_id ON hafbe_app.witness_votes USING btree (witness_id); CREATE INDEX IF NOT EXISTS witness_votes_voter_id ON hafbe_app.witness_votes USING btree (voter_id); + CREATE INDEX IF NOT EXISTS witness_votes_operation_id ON hafbe_app.witness_votes USING btree (operation_id); CREATE TABLE IF NOT EXISTS hafbe_app.account_proxies ( - proxy_id INT NOT NULL, - account_id INT NOT NULL + account_id INT NOT NULL, + proxy_id INT, + operation_id INT NOT NULL ) INHERITS (hive.hafbe_app); - CREATE INDEX IF NOT EXISTS account_proxies_proxy_id ON hafbe_app.account_proxies USING btree (proxy_id); CREATE INDEX IF NOT EXISTS account_proxies_account_id ON hafbe_app.account_proxies USING btree (account_id); + CREATE INDEX IF NOT EXISTS account_proxies_proxy_id ON hafbe_app.account_proxies USING btree (proxy_id); + CREATE INDEX IF NOT EXISTS account_proxies_operation_id ON hafbe_app.account_proxies USING btree (operation_id); CREATE TABLE IF NOT EXISTS hafbe_app.hived_account_cache ( account TEXT NOT NULL, @@ -109,38 +112,38 @@ AS $$ DECLARE __last_reported_block INT := 0; - __block_api_data JSON; - __proxy_operation JSON; BEGIN FOR b IN _from .. _to LOOP - INSERT INTO hafbe_app.witness_votes (witness_id, voter_id, approve, timestamp) + INSERT INTO hafbe_app.witness_votes (witness_id, voter_id, approve, operation_id) SELECT hafbe_backend.get_account_id(approve_operation->>'witness'), hafbe_backend.get_account_id(approve_operation->>'account'), (approve_operation->>'approve')::BOOLEAN, - timestamp + id FROM ( SELECT (body::JSON)->'value' AS approve_operation, - timestamp + id FROM hive.operations_view WHERE op_type_id = 12 AND block_num = b ) hov ON CONFLICT DO NOTHING; - SELECT (body::JSON)->'value' FROM hive.operations_view WHERE op_type_id = 13 AND block_num = b INTO __proxy_operation; - - IF length(__proxy_operation->>'proxy') != 0 THEN - INSERT INTO hafbe_app.account_proxies (proxy_id, account_id) + INSERT INTO hafbe_app.account_proxies (account_id, proxy_id, operation_id) + SELECT + hafbe_backend.get_account_id(proxy_operation->>'account'), + hafbe_backend.get_account_id(proxy_operation->>'proxy'), + id + FROM ( SELECT - hafbe_backend.get_account_id(__proxy_operation->>'proxy'), - hafbe_backend.get_account_id(__proxy_operation->>'account') - ON CONFLICT DO NOTHING; - ELSE - DELETE FROM hafbe_app.account_proxies WHERE proxy_id = hafbe_backend.get_account_id(__proxy_operation->>'proxy'); - END IF; + (body::JSON)->'value' AS proxy_operation, + id + FROM hive.operations_view + WHERE op_type_id = 13 AND block_num = b + ) hov + ON CONFLICT DO NOTHING; /* IF __balance_change.source_op_block % _report_step = 0 AND __last_reported_block != __balance_change.source_op_block THEN -- GitLab From 8eb8f1c2f8fbe0835c9c727983ec74f7bd0f288b Mon Sep 17 00:00:00 2001 From: kristupas Date: Mon, 11 Jul 2022 13:37:23 +0000 Subject: [PATCH 04/89] Added 'proxy' column to 'account_proxies' and post-processing port; added proxy functions #22 --- api/backend.sql | 136 +++++++++++++++++++++++++++++++++++++++-------- db/hafbe_app.sql | 45 ++++++++++++---- 2 files changed, 151 insertions(+), 30 deletions(-) diff --git a/api/backend.sql b/api/backend.sql index e634db4..6f53cb3 100644 --- a/api/backend.sql +++ b/api/backend.sql @@ -353,44 +353,138 @@ $$ ; CREATE FUNCTION hafbe_backend.get_witness_voters(_witness_id INT, _limit INT) -RETURNS JSON -LANGUAGE 'plpgsql' +RETURNS TABLE ( + _voter_id INT, + _vests NUMERIC, + _account_vests BIGINT, + _proxied_vests NUMERIC +) AS -$$ +$function$ BEGIN - RETURN CASE WHEN res IS NULL THEN '[]' ELSE res END + RETURN QUERY SELECT + voter_id, + account_vests + proxied_vests, + account_vests, + proxied_vests FROM ( - SELECT json_agg(acc.name)::JSON AS res + SELECT + voters.voter_id AS voter_id, + cab.balance AS account_vests, + hafbe_backend.get_proxied_vests(voters.voter_id) AS proxied_vests FROM ( SELECT DISTINCT ON (voter_id) voter_id, approve FROM ( - SELECT - votes.voter_id AS voter_id, - votes.approve AS approve - FROM ( - SELECT voter_id, approve, operation_id - FROM hafbe_app.witness_votes - WHERE witness_id = _witness_id - ) votes - JOIN LATERAL ( - SELECT timestamp, id - FROM hive.operations_view - ) hov ON votes.operation_id = hov.id - ORDER BY timestamp DESC + SELECT voter_id, approve + FROM hafbe_app.witness_votes + WHERE witness_id = _witness_id + ORDER BY operation_id ) votes_ordered ) voters JOIN LATERAL ( SELECT name, id FROM hive.accounts_view ) acc ON acc.id = voters.voter_id - WHERE voters.approve IS TRUE + JOIN LATERAL ( + SELECT balance, account, nai + FROM btracker_app.current_account_balances + ) cab ON cab.account = acc.name + WHERE voters.approve IS TRUE AND cab.nai = 37 LIMIT _limit - ) result; + ) vests; END -$$ +$function$ +LANGUAGE 'plpgsql' STABLE +SET JIT=OFF +SET join_collapse_limit=16 +SET from_collapse_limit=16 +; + +-- TODO: create helper functions for repeated code +CREATE FUNCTION hafbe_backend.get_proxied_vests(_voter_id INT) +RETURNS TABLE ( + _balance NUMERIC +) +AS +$function$ +BEGIN + RETURN QUERY SELECT CASE WHEN balance IS NULL THEN 0 ELSE balance END + FROM ( + SELECT SUM(cab.balance) AS balance + FROM ( + SELECT + CASE WHEN balance < 0 THEN 0 ELSE balance END, + account, + nai + FROM btracker_app.current_account_balances + ) cab + JOIN LATERAL ( + SELECT name, id + FROM hive.accounts_view + ) hav ON hav.name = cab.account + JOIN LATERAL ( + SELECT DISTINCT ON (proxy_id) + account_id, proxy_id, operation_id + FROM ( + SELECT account_id, proxy_id, operation_id + FROM hafbe_app.account_proxies + WHERE proxy_id = _voter_id AND proxy IS TRUE + ORDER BY operation_id DESC + ) proxy_ops + ) ap ON ap.account_id = hav.id + WHERE ( + SELECT 1 + FROM hafbe_app.account_proxies + WHERE account_id = ap.account_id AND proxy_id = ap.proxy_id AND proxy IS FALSE AND operation_id > ap.operation_id + ) IS NULL AND cab.nai = 37 + ) is_null; +END +$function$ +LANGUAGE 'plpgsql' STABLE +SET JIT=OFF +SET join_collapse_limit=16 +SET from_collapse_limit=16 ; +CREATE FUNCTION hafbe_backend.is_voter_proxied(_voter_id INT) +RETURNS TABLE ( + proxied BOOLEAN +) +AS +$function$ +BEGIN + RETURN QUERY SELECT CASE WHEN ( + SELECT proxy_id + FROM ( + SELECT DISTINCT ON (proxy_id) + account_id, proxy_id, operation_id + FROM ( + SELECT account_id, proxy_id, operation_id + FROM hafbe_app.account_proxies + WHERE account_id = _voter_id AND proxy IS TRUE + ORDER BY operation_id DESC + ) proxy_ops + ) ap + WHERE ( + SELECT 1 + FROM hafbe_app.account_proxies + WHERE account_id = ap.account_id AND proxy_id = ap.proxy_id AND proxy IS FALSE AND operation_id > ap.operation_id + ) IS NULL + ) + IS NOT NULL THEN TRUE ELSE FALSE END; +END +$function$ +LANGUAGE 'plpgsql' STABLE +SET JIT=OFF +SET join_collapse_limit=16 +SET from_collapse_limit=16 +; + +/* +RETURN CASE WHEN res IS NULL THEN '[]' ELSE res END +*/ + CREATE FUNCTION hafbe_backend.get_account(_account TEXT) RETURNS JSON LANGUAGE 'plpython3u' diff --git a/db/hafbe_app.sql b/db/hafbe_app.sql index 0975a13..728db92 100644 --- a/db/hafbe_app.sql +++ b/db/hafbe_app.sql @@ -19,7 +19,7 @@ BEGIN witness_id INT NOT NULL, voter_id INT NOT NULL, approve BOOLEAN NOT NULL, - operation_id INT NOT NULL + operation_id BIGINT NOT NULL ) INHERITS (hive.hafbe_app); CREATE INDEX IF NOT EXISTS witness_votes_witness_id ON hafbe_app.witness_votes USING btree (witness_id); @@ -29,7 +29,8 @@ BEGIN CREATE TABLE IF NOT EXISTS hafbe_app.account_proxies ( account_id INT NOT NULL, proxy_id INT, - operation_id INT NOT NULL + proxy BOOLEAN, + operation_id BIGINT NOT NULL ) INHERITS (hive.hafbe_app); CREATE INDEX IF NOT EXISTS account_proxies_account_id ON hafbe_app.account_proxies USING btree (account_id); @@ -112,6 +113,8 @@ AS $$ DECLARE __last_reported_block INT := 0; + __unproxy_op RECORD; + __last_op_id BIGINT; BEGIN FOR b IN _from .. _to LOOP @@ -131,20 +134,44 @@ BEGIN ) hov ON CONFLICT DO NOTHING; - INSERT INTO hafbe_app.account_proxies (account_id, proxy_id, operation_id) + SELECT operation_id FROM hafbe_app.account_proxies ORDER BY operation_id DESC LIMIT 1 INTO __last_op_id; + + INSERT INTO hafbe_app.account_proxies (account_id, proxy_id, proxy, operation_id) SELECT - hafbe_backend.get_account_id(proxy_operation->>'account'), - hafbe_backend.get_account_id(proxy_operation->>'proxy'), + account_id, + proxy_id, + CASE WHEN proxy_id IS NULL THEN FALSE ELSE TRUE END, id FROM ( SELECT - (body::JSON)->'value' AS proxy_operation, + hafbe_backend.get_account_id(proxy_operation->>'account') AS account_id, + hafbe_backend.get_account_id(proxy_operation->>'proxy') AS proxy_id, id - FROM hive.operations_view - WHERE op_type_id = 13 AND block_num = b - ) hov + FROM ( + SELECT + (body::JSON)->'value' AS proxy_operation, + id + FROM hive.operations_view + WHERE op_type_id = 13 AND block_num = b + ) hov + ) acc_ids ON CONFLICT DO NOTHING; + -- postprocessing to fill null values of proxy_id when account does unproxy + FOR __unproxy_op IN + SELECT account_id, operation_id + FROM hafbe_app.account_proxies + WHERE operation_id > __last_op_id AND proxy_id IS NULL + LOOP + UPDATE hafbe_app.account_proxies + SET proxy_id = (SELECT proxy_id + FROM hafbe_app.account_proxies + WHERE operation_id < __unproxy_op.operation_id AND account_id = __unproxy_op.account_id AND proxy_id IS NOT NULL + ORDER BY operation_id DESC + LIMIT 1) + WHERE account_id = __unproxy_op.account_id AND proxy_id IS NULL; + END LOOP; + /* IF __balance_change.source_op_block % _report_step = 0 AND __last_reported_block != __balance_change.source_op_block THEN RAISE NOTICE 'Processed data for block: %', __balance_change.source_op_block; -- GitLab From 75f283df27883ddf290b766f3cf79b3acf331807 Mon Sep 17 00:00:00 2001 From: kristupas Date: Mon, 11 Jul 2022 14:17:46 +0000 Subject: [PATCH 05/89] 'vests_sum' subquery and ordering of voters --- api/backend.sql | 63 +++++++++++++++++++++++++++++++------------------ 1 file changed, 40 insertions(+), 23 deletions(-) diff --git a/api/backend.sql b/api/backend.sql index 6f53cb3..6429446 100644 --- a/api/backend.sql +++ b/api/backend.sql @@ -364,35 +364,50 @@ $function$ BEGIN RETURN QUERY SELECT voter_id, - account_vests + proxied_vests, + vests, account_vests, proxied_vests FROM ( SELECT - voters.voter_id AS voter_id, - cab.balance AS account_vests, - hafbe_backend.get_proxied_vests(voters.voter_id) AS proxied_vests + voter_id, + account_vests + proxied_vests AS vests, + account_vests, + proxied_vests FROM ( - SELECT DISTINCT ON (voter_id) - voter_id, approve + SELECT + voter_id, + CASE WHEN is_proxied IS TRUE THEN 0 ELSE account_vests END AS account_vests, + proxied_vests FROM ( - SELECT voter_id, approve - FROM hafbe_app.witness_votes - WHERE witness_id = _witness_id - ORDER BY operation_id - ) votes_ordered - ) voters - JOIN LATERAL ( - SELECT name, id - FROM hive.accounts_view - ) acc ON acc.id = voters.voter_id - JOIN LATERAL ( - SELECT balance, account, nai - FROM btracker_app.current_account_balances - ) cab ON cab.account = acc.name - WHERE voters.approve IS TRUE AND cab.nai = 37 - LIMIT _limit - ) vests; + SELECT + voters.voter_id AS voter_id, + cab.balance AS account_vests, + hafbe_backend.get_proxied_vests(voters.voter_id) AS proxied_vests, + hafbe_backend.is_voter_proxied(voters.voter_id) AS is_proxied + FROM ( + SELECT DISTINCT ON (voter_id) + voter_id, approve + FROM ( + SELECT voter_id, approve + FROM hafbe_app.witness_votes + WHERE witness_id = _witness_id + ORDER BY operation_id + ) votes_ordered + ) voters + JOIN LATERAL ( + SELECT name, id + FROM hive.accounts_view + ) acc ON acc.id = voters.voter_id + JOIN LATERAL ( + SELECT balance, account, nai + FROM btracker_app.current_account_balances + ) cab ON cab.account = acc.name + WHERE voters.approve IS TRUE AND cab.nai = 37 + LIMIT _limit + ) vests + ) is_proxied + ) vests_sum + ORDER BY vests DESC; END $function$ LANGUAGE 'plpgsql' STABLE @@ -432,6 +447,7 @@ BEGIN WHERE proxy_id = _voter_id AND proxy IS TRUE ORDER BY operation_id DESC ) proxy_ops + LIMIT 1 ) ap ON ap.account_id = hav.id WHERE ( SELECT 1 @@ -465,6 +481,7 @@ BEGIN WHERE account_id = _voter_id AND proxy IS TRUE ORDER BY operation_id DESC ) proxy_ops + LIMIT 1 ) ap WHERE ( SELECT 1 -- GitLab From 4fc7c84752b20b1faaed738d479476d87d490e82 Mon Sep 17 00:00:00 2001 From: kristupas Date: Mon, 11 Jul 2022 17:25:45 +0000 Subject: [PATCH 06/89] Return witness table as JSON #22 --- api/backend.sql | 81 ++++++++++++++++++++++++++++--------------------- 1 file changed, 47 insertions(+), 34 deletions(-) diff --git a/api/backend.sql b/api/backend.sql index 6429446..8b99270 100644 --- a/api/backend.sql +++ b/api/backend.sql @@ -352,37 +352,39 @@ END $$ ; -CREATE FUNCTION hafbe_backend.get_witness_voters(_witness_id INT, _limit INT) -RETURNS TABLE ( - _voter_id INT, - _vests NUMERIC, - _account_vests BIGINT, - _proxied_vests NUMERIC -) +CREATE TYPE hafbe_backend.witness_voters AS ( + voter_id INT, + vests NUMERIC, + account_vests BIGINT, + proxied_vests NUMERIC +); + +CREATE FUNCTION hafbe_backend.get_set_of_witness_voters(_witness_id INT, _limit INT) +RETURNS SETOF hafbe_backend.witness_voters AS $function$ BEGIN RETURN QUERY SELECT - voter_id, - vests, - account_vests, - proxied_vests + v_voter_id, + vests_sum, + cab_account_vests, + f_proxied_vests FROM ( SELECT - voter_id, - account_vests + proxied_vests AS vests, - account_vests, - proxied_vests + v_voter_id, + cab_account_vests + f_proxied_vests AS vests_sum, + cab_account_vests, + f_proxied_vests FROM ( SELECT - voter_id, - CASE WHEN is_proxied IS TRUE THEN 0 ELSE account_vests END AS account_vests, - proxied_vests + v_voter_id, + CASE WHEN is_proxied IS TRUE THEN 0 ELSE cab_account_vests END AS cab_account_vests, + f_proxied_vests FROM ( SELECT - voters.voter_id AS voter_id, - cab.balance AS account_vests, - hafbe_backend.get_proxied_vests(voters.voter_id) AS proxied_vests, + voters.voter_id AS v_voter_id, + cab.balance AS cab_account_vests, + hafbe_backend.get_proxied_vests(voters.voter_id) AS f_proxied_vests, hafbe_backend.is_voter_proxied(voters.voter_id) AS is_proxied FROM ( SELECT DISTINCT ON (voter_id) @@ -403,11 +405,11 @@ BEGIN FROM btracker_app.current_account_balances ) cab ON cab.account = acc.name WHERE voters.approve IS TRUE AND cab.nai = 37 - LIMIT _limit ) vests ) is_proxied ) vests_sum - ORDER BY vests DESC; + ORDER BY vests_sum DESC + LIMIT _limit; END $function$ LANGUAGE 'plpgsql' STABLE @@ -416,6 +418,21 @@ SET join_collapse_limit=16 SET from_collapse_limit=16 ; +CREATE OR REPLACE FUNCTION hafbe_backend.get_witness_voters(_witness_id INT, _limit INT) +RETURNS JSON +LANGUAGE 'plpgsql' +AS +$$ +BEGIN + RETURN to_json(arr) FROM ( + SELECT ARRAY( + SELECT to_json(hafbe_backend.get_set_of_witness_voters(_witness_id, _limit)) + ) arr + ) result; +END +$$ +; + -- TODO: create helper functions for repeated code CREATE FUNCTION hafbe_backend.get_proxied_vests(_voter_id INT) RETURNS TABLE ( @@ -439,7 +456,7 @@ BEGIN FROM hive.accounts_view ) hav ON hav.name = cab.account JOIN LATERAL ( - SELECT DISTINCT ON (proxy_id) + SELECT DISTINCT ON (account_id) account_id, proxy_id, operation_id FROM ( SELECT account_id, proxy_id, operation_id @@ -447,12 +464,12 @@ BEGIN WHERE proxy_id = _voter_id AND proxy IS TRUE ORDER BY operation_id DESC ) proxy_ops - LIMIT 1 ) ap ON ap.account_id = hav.id WHERE ( - SELECT 1 + SELECT account_id FROM hafbe_app.account_proxies WHERE account_id = ap.account_id AND proxy_id = ap.proxy_id AND proxy IS FALSE AND operation_id > ap.operation_id + LIMIT 1 ) IS NULL AND cab.nai = 37 ) is_null; END @@ -473,14 +490,10 @@ BEGIN RETURN QUERY SELECT CASE WHEN ( SELECT proxy_id FROM ( - SELECT DISTINCT ON (proxy_id) - account_id, proxy_id, operation_id - FROM ( - SELECT account_id, proxy_id, operation_id - FROM hafbe_app.account_proxies - WHERE account_id = _voter_id AND proxy IS TRUE - ORDER BY operation_id DESC - ) proxy_ops + SELECT account_id, proxy_id, operation_id + FROM hafbe_app.account_proxies + WHERE account_id = _voter_id AND proxy IS TRUE + ORDER BY operation_id DESC LIMIT 1 ) ap WHERE ( -- GitLab From 5c409fff0050302f202f4363dca7c93c3ea8fc14 Mon Sep 17 00:00:00 2001 From: kristupas Date: Mon, 11 Jul 2022 17:40:55 +0000 Subject: [PATCH 07/89] Return '[]' when empty response, added helper func for repeated code #22 --- api/backend.sql | 39 ++++++++++++++++++++------------------- 1 file changed, 20 insertions(+), 19 deletions(-) diff --git a/api/backend.sql b/api/backend.sql index 8b99270..053e155 100644 --- a/api/backend.sql +++ b/api/backend.sql @@ -249,7 +249,7 @@ LANGUAGE 'plpgsql' AS $$ BEGIN - RETURN to_json(arr) FROM ( + RETURN CASE WHEN arr IS NOT NULL THEN to_json(arr) ELSE '[]'::JSON END FROM ( SELECT ARRAY( SELECT to_json(hafbe_backend.get_set_of_ops_by_account(_account_id, _top_op_id, _limit, _filter, _date_start, _date_end)) ) arr @@ -343,7 +343,7 @@ LANGUAGE 'plpgsql' AS $$ BEGIN - RETURN to_json(arr) FROM ( + RETURN CASE WHEN arr IS NOT NULL THEN to_json(arr) ELSE '[]'::JSON END FROM ( SELECT ARRAY( SELECT to_json(hafbe_backend.get_set_of_ops_by_block(_block_num, _top_op_id, _limit, _filter)) ) arr @@ -424,7 +424,7 @@ LANGUAGE 'plpgsql' AS $$ BEGIN - RETURN to_json(arr) FROM ( + RETURN CASE WHEN arr IS NOT NULL THEN to_json(arr) ELSE '[]'::JSON END FROM ( SELECT ARRAY( SELECT to_json(hafbe_backend.get_set_of_witness_voters(_witness_id, _limit)) ) arr @@ -433,7 +433,21 @@ END $$ ; --- TODO: create helper functions for repeated code +CREATE OR REPLACE FUNCTION hafbe_backend.was_acc_unproxied(_account_id INT, _proxy_id INT, _operation_id BIGINT) +RETURNS TABLE ( + one INT +) +LANGUAGE 'plpgsql' +AS +$$ +BEGIN + RETURN QUERY SELECT 1 + FROM hafbe_app.account_proxies + WHERE account_id = _account_id AND proxy_id = _proxy_id AND proxy IS FALSE AND operation_id > _operation_id; +END +$$ +; + CREATE FUNCTION hafbe_backend.get_proxied_vests(_voter_id INT) RETURNS TABLE ( _balance NUMERIC @@ -465,12 +479,7 @@ BEGIN ORDER BY operation_id DESC ) proxy_ops ) ap ON ap.account_id = hav.id - WHERE ( - SELECT account_id - FROM hafbe_app.account_proxies - WHERE account_id = ap.account_id AND proxy_id = ap.proxy_id AND proxy IS FALSE AND operation_id > ap.operation_id - LIMIT 1 - ) IS NULL AND cab.nai = 37 + WHERE (SELECT hafbe_backend.was_acc_unproxied(ap.account_id, ap.proxy_id, ap.operation_id)) IS NULL AND cab.nai = 37 ) is_null; END $function$ @@ -496,11 +505,7 @@ BEGIN ORDER BY operation_id DESC LIMIT 1 ) ap - WHERE ( - SELECT 1 - FROM hafbe_app.account_proxies - WHERE account_id = ap.account_id AND proxy_id = ap.proxy_id AND proxy IS FALSE AND operation_id > ap.operation_id - ) IS NULL + WHERE (SELECT hafbe_backend.was_acc_unproxied(ap.account_id, ap.proxy_id, ap.operation_id)) IS NULL ) IS NOT NULL THEN TRUE ELSE FALSE END; END @@ -511,10 +516,6 @@ SET join_collapse_limit=16 SET from_collapse_limit=16 ; -/* -RETURN CASE WHEN res IS NULL THEN '[]' ELSE res END -*/ - CREATE FUNCTION hafbe_backend.get_account(_account TEXT) RETURNS JSON LANGUAGE 'plpython3u' -- GitLab From f7836531837c0024628c8fca0ac92f0ae43abe51 Mon Sep 17 00:00:00 2001 From: kristupas Date: Wed, 13 Jul 2022 11:14:15 +0000 Subject: [PATCH 08/89] Added dynamic ordering to 'get_witness_voters()' ; param null-proofing and assertions #22 --- api/backend.sql | 75 ++++++++++++++++++++++++++++++---------------- api/endpoints.sql | 22 ++++++++++++-- api/exceptions.sql | 28 +++++++++++++++++ 3 files changed, 97 insertions(+), 28 deletions(-) diff --git a/api/backend.sql b/api/backend.sql index 053e155..f46e78c 100644 --- a/api/backend.sql +++ b/api/backend.sql @@ -353,44 +353,45 @@ $$ ; CREATE TYPE hafbe_backend.witness_voters AS ( - voter_id INT, + account TEXT, vests NUMERIC, account_vests BIGINT, - proxied_vests NUMERIC + proxied_vests NUMERIC, + timestamp TIMESTAMP ); -CREATE FUNCTION hafbe_backend.get_set_of_witness_voters(_witness_id INT, _limit INT) +-- TODO: order by timestamp too slow +CREATE FUNCTION hafbe_backend.get_set_of_witness_voters(_witness_id INT) RETURNS SETOF hafbe_backend.witness_voters AS $function$ BEGIN - RETURN QUERY SELECT - v_voter_id, - vests_sum, - cab_account_vests, - f_proxied_vests + RETURN QUERY SELECT account, vests, account_vests, proxied_vests, timestamp FROM ( SELECT - v_voter_id, - cab_account_vests + f_proxied_vests AS vests_sum, - cab_account_vests, - f_proxied_vests + account, + account_vests + proxied_vests AS vests, + account_vests, + proxied_vests, + timestamp FROM ( SELECT - v_voter_id, - CASE WHEN is_proxied IS TRUE THEN 0 ELSE cab_account_vests END AS cab_account_vests, - f_proxied_vests + account, + CASE WHEN is_proxied IS TRUE THEN 0 ELSE account_vests END AS account_vests, + proxied_vests, + hov.timestamp AS timestamp FROM ( SELECT - voters.voter_id AS v_voter_id, - cab.balance AS cab_account_vests, - hafbe_backend.get_proxied_vests(voters.voter_id) AS f_proxied_vests, - hafbe_backend.is_voter_proxied(voters.voter_id) AS is_proxied + acc.name::TEXT AS account, + cab.balance AS account_vests, + hafbe_backend.get_proxied_vests(voters.voter_id) AS proxied_vests, + hafbe_backend.is_voter_proxied(voters.voter_id) AS is_proxied, + voters.operation_id AS operation_id FROM ( SELECT DISTINCT ON (voter_id) - voter_id, approve + voter_id, approve, operation_id FROM ( - SELECT voter_id, approve + SELECT voter_id, approve, operation_id FROM hafbe_app.witness_votes WHERE witness_id = _witness_id ORDER BY operation_id @@ -406,10 +407,12 @@ BEGIN ) cab ON cab.account = acc.name WHERE voters.approve IS TRUE AND cab.nai = 37 ) vests + JOIN LATERAL ( + SELECT timestamp, id + FROM hive.operations_view + ) hov ON hov.id = vests.operation_id ) is_proxied - ) vests_sum - ORDER BY vests_sum DESC - LIMIT _limit; + ) vests_sum; END $function$ LANGUAGE 'plpgsql' STABLE @@ -418,7 +421,27 @@ SET join_collapse_limit=16 SET from_collapse_limit=16 ; -CREATE OR REPLACE FUNCTION hafbe_backend.get_witness_voters(_witness_id INT, _limit INT) +CREATE OR REPLACE FUNCTION hafbe_backend.get_witness_voters_ordered(_witness_id INT, _limit INT, _order_by TEXT, _order_is TEXT) +RETURNS SETOF hafbe_backend.witness_voters +LANGUAGE 'plpgsql' +AS +$$ +BEGIN + RETURN QUERY EXECUTE format( + $query$ + SELECT account, vests, account_vests, proxied_vests, timestamp + FROM hafbe_backend.get_set_of_witness_voters(%L) + ORDER BY + (CASE WHEN %L = 'desc' THEN %I ELSE NULL END) DESC, + (CASE WHEN %L = 'asc' THEN %I ELSE NULL END) ASC + LIMIT %L; + $query$, _witness_id, _order_is, _order_by, _order_is, _order_by, _limit + ) res; +END +$$ +; + +CREATE OR REPLACE FUNCTION hafbe_backend.get_witness_voters(_witness_id INT, _limit INT, _order_by TEXT, _order_is TEXT) RETURNS JSON LANGUAGE 'plpgsql' AS @@ -426,7 +449,7 @@ $$ BEGIN RETURN CASE WHEN arr IS NOT NULL THEN to_json(arr) ELSE '[]'::JSON END FROM ( SELECT ARRAY( - SELECT to_json(hafbe_backend.get_set_of_witness_voters(_witness_id, _limit)) + SELECT hafbe_backend.get_witness_voters_ordered(_witness_id, _limit, _order_by, _order_is) ) arr ) result; END diff --git a/api/endpoints.sql b/api/endpoints.sql index 30e16ee..eb9f23c 100644 --- a/api/endpoints.sql +++ b/api/endpoints.sql @@ -208,7 +208,7 @@ END $$ ; -CREATE FUNCTION hafbe_endpoints.get_witness_voters(_witness TEXT, _limit INT = 1000) +CREATE FUNCTION hafbe_endpoints.get_witness_voters(_witness TEXT, _limit INT = 1000, _order_by TEXT = 'vests', _order_is TEXT = 'desc') RETURNS JSON LANGUAGE 'plpgsql' AS @@ -216,7 +216,25 @@ $$ DECLARE __witness_id INT = hafbe_backend.get_account_id(_witness); BEGIN - RETURN hafbe_backend.get_witness_voters(__witness_id, _limit); + IF _limit IS NULL OR _limit <= 0 THEN + _limit = 1000; + END IF; + + IF _order_by NOT SIMILAR TO '(account|vests|account_vests|proxied_vests|timestamp)' THEN + RETURN hafbe_exceptions.raise_no_such_column_exception(_order_by); + END IF; + IF _order_by IS NULL THEN + _order_by = 'vests'; + END IF; + + IF _order_is NOT SIMILAR TO '(asc|desc)' THEN + RETURN hafbe_exceptions.raise_no_such_order_exception(_order_is); + END IF; + IF _order_is IS NULL THEN + _order_is = 'desc'; + END IF; + + RETURN hafbe_backend.get_witness_voters(__witness_id, _limit, _order_by, _order_is); END $$ ; diff --git a/api/exceptions.sql b/api/exceptions.sql index 28dff83..5eb789b 100644 --- a/api/exceptions.sql +++ b/api/exceptions.sql @@ -72,4 +72,32 @@ BEGIN ); END $$ +; + +CREATE FUNCTION hafbe_exceptions.raise_no_such_column_exception(_order_by TEXT) +RETURNS JSON +LANGUAGE 'plpgsql' +AS +$$ +BEGIN + RETURN hafbe_exceptions.raise_exception(406, 5, 'Not Acceptable', + 'Provided ''_order_by'' column does not exist', + format('''%s'' not in (account, vests, account_vests, proxied_vests, timestamp)', _order_by) + ); +END +$$ +; + +CREATE FUNCTION hafbe_exceptions.raise_no_such_order_exception(_order_is TEXT) +RETURNS JSON +LANGUAGE 'plpgsql' +AS +$$ +BEGIN + RETURN hafbe_exceptions.raise_exception(406, 6, 'Not Acceptable', + 'Provided ''_order_is'' does not exist', + format('''%s'' is not ''asc'' or ''desc''', _order_is) + ); +END +$$ ; \ No newline at end of file -- GitLab From a6e4df88b510586ef86ca7c4c19260e336e4aa31 Mon Sep 17 00:00:00 2001 From: kristupas Date: Thu, 14 Jul 2022 12:38:17 +0000 Subject: [PATCH 09/89] Added 'account_operation_cache' table, updated related methods, added 'hive_account_operations_block_num' index #22 --- api/backend.sql | 38 ++++++++++++++++++++++---------------- db/hafbe_app.sql | 21 +++++++++++++++++++++ run.sh | 3 +++ 3 files changed, 46 insertions(+), 16 deletions(-) diff --git a/api/backend.sql b/api/backend.sql index f46e78c..ff8f5e8 100644 --- a/api/backend.sql +++ b/api/backend.sql @@ -54,13 +54,13 @@ LANGUAGE 'plpgsql' AS $$ BEGIN - RETURN ('[' || _operation_id || ', "' || split_part(_operation_name, '::', 3) || '", ' || _is_virtual || ']')::JSON; + RETURN ('[' || _operation_id || ', "' || split_part(_operation_name, '::', 3) || '", ' || _is_virtual || ']'); END $$ ; CREATE TYPE hafbe_backend.op_types AS ( - operation_id BIGINT, + op_type_id INT, operation_name TEXT, is_virtual BOOLEAN ); @@ -72,7 +72,7 @@ AS $$ BEGIN RETURN QUERY SELECT - id::BIGINT, + id::INT, name::TEXT, is_virtual::BOOLEAN FROM hive.operation_types @@ -87,8 +87,10 @@ LANGUAGE 'plpgsql' AS $$ BEGIN - RETURN json_agg(hafbe_backend.format_op_types(operation_id, operation_name, is_virtual)) - FROM hafbe_backend.get_set_of_op_types(); + RETURN CASE WHEN res.arr IS NOT NULL THEN res.arr ELSE '[]'::JSON END FROM ( + SELECT json_agg(hafbe_backend.format_op_types(op_type_id, operation_name, is_virtual)) AS arr + FROM hafbe_backend.get_set_of_op_types() + ) res; END $$ ; @@ -100,20 +102,20 @@ AS $$ BEGIN RETURN QUERY SELECT - haov.op_type_id::BIGINT, + aoc.op_type_id, hot.name::TEXT, hot.is_virtual::BOOLEAN FROM ( - SELECT DISTINCT op_type_id - FROM hive.account_operations_view + SELECT op_type_id + FROM hafbe_app.account_operation_cache WHERE account_id = _account_id - ) haov + ) aoc JOIN LATERAL ( SELECT id, name, is_virtual FROM hive.operation_types - ) hot ON hot.id = haov.op_type_id - ORDER BY haov.op_type_id ASC; + ) hot ON hot.id = aoc.op_type_id + ORDER BY aoc.op_type_id ASC; END $$ ; @@ -124,8 +126,10 @@ LANGUAGE 'plpgsql' AS $$ BEGIN - RETURN json_agg(hafbe_backend.format_op_types(operation_id, operation_name, is_virtual)) - FROM hafbe_backend.get_set_of_acc_op_types(_account_id); + RETURN CASE WHEN res.arr IS NOT NULL THEN res.arr ELSE '[]'::JSON END FROM ( + SELECT json_agg(hafbe_backend.format_op_types(op_type_id, operation_name, is_virtual)) AS arr + FROM hafbe_backend.get_set_of_acc_op_types(_account_id) + ) res; END $$ ; @@ -137,7 +141,7 @@ AS $$ BEGIN RETURN QUERY SELECT - hov.op_type_id::BIGINT, + hot.id::INT, hot.name::TEXT, hot.is_virtual::BOOLEAN FROM ( @@ -161,8 +165,10 @@ LANGUAGE 'plpgsql' AS $$ BEGIN - RETURN json_agg(hafbe_backend.format_op_types(operation_id, operation_name, is_virtual)) - FROM hafbe_backend.get_set_of_block_op_types(_block_num); + RETURN CASE WHEN res.arr IS NOT NULL THEN res.arr ELSE '[]'::JSON END FROM ( + SELECT json_agg(hafbe_backend.format_op_types(op_type_id, operation_name, is_virtual)) AS arr + FROM hafbe_backend.get_set_of_block_op_types(_block_num) + ) res; END $$ ; diff --git a/db/hafbe_app.sql b/db/hafbe_app.sql index 728db92..7a5268b 100644 --- a/db/hafbe_app.sql +++ b/db/hafbe_app.sql @@ -44,6 +44,17 @@ BEGIN CONSTRAINT pk_hived_account_cache PRIMARY KEY (account) ); + CREATE TABLE IF NOT EXISTS hafbe_app.account_operation_cache ( + uq_key TEXT NOT NULL, + account_id INT NOT NULL, + op_type_id INT NOT NULL, + + CONSTRAINT uq_account_operation_cache UNIQUE (uq_key) + ) INHERITS (hive.hafbe_app); + + CREATE INDEX IF NOT EXISTS account_operation_cache_account_id ON hafbe_app.account_operation_cache USING btree (account_id); + CREATE INDEX IF NOT EXISTS account_operation_cache_op_type_id ON hafbe_app.account_operation_cache USING btree (op_type_id); + --ALTER SCHEMA hafbe_app OWNER TO hafbe_owner; END $$ @@ -171,6 +182,16 @@ BEGIN LIMIT 1) WHERE account_id = __unproxy_op.account_id AND proxy_id IS NULL; END LOOP; + + + INSERT INTO hafbe_app.account_operation_cache (uq_key, account_id, op_type_id) + SELECT + account_id::TEXT || '-' || op_type_id::TEXT, + account_id, + op_type_id + FROM hive.account_operations_view haov + WHERE block_num = b + ON CONFLICT DO NOTHING; /* IF __balance_change.source_op_block % _report_step = 0 AND __last_reported_block != __balance_change.source_op_block THEN diff --git a/run.sh b/run.sh index 0550d21..51befd1 100755 --- a/run.sh +++ b/run.sh @@ -33,6 +33,9 @@ create_indexes() { psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "CREATE UNIQUE INDEX IF NOT EXISTS hive_account_operations_reversible_uq2 ON hive.account_operations_reversible USING btree (account_id, op_type_id, operation_id, fork_id)" psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "CREATE UNIQUE INDEX IF NOT EXISTS hive_account_operations_uq2 ON hive.account_operations USING btree (account_id, op_type_id, operation_id)" + + psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "CREATE INDEX IF NOT EXISTS hive_account_operations_reversible_block_num ON hive.account_operations_reversible USING btree (block_num, fork_id)" + psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "CREATE INDEX IF NOT EXISTS hive_account_operations_block_num ON hive.account_operations USING btree (block_num)" } start_webserver() { -- GitLab From 5f8a5d652769f3de5f999ee7f889100d28ad71de Mon Sep 17 00:00:00 2001 From: kristupas Date: Thu, 14 Jul 2022 12:42:16 +0000 Subject: [PATCH 10/89] Fixed 'one than more row' bug #22 --- api/backend.sql | 3 ++- 1 file changed, 2 insertions(+), 1 deletion(-) diff --git a/api/backend.sql b/api/backend.sql index ff8f5e8..0aae581 100644 --- a/api/backend.sql +++ b/api/backend.sql @@ -472,7 +472,8 @@ $$ BEGIN RETURN QUERY SELECT 1 FROM hafbe_app.account_proxies - WHERE account_id = _account_id AND proxy_id = _proxy_id AND proxy IS FALSE AND operation_id > _operation_id; + WHERE account_id = _account_id AND proxy_id = _proxy_id AND proxy IS FALSE AND operation_id > _operation_id + LIMIT 1; END $$ ; -- GitLab From 612461eb2e6efb689206159722105f500e664863 Mon Sep 17 00:00:00 2001 From: kristupas Date: Fri, 15 Jul 2022 11:54:29 +0000 Subject: [PATCH 11/89] Added 'hive_operations_timestamp' index, fixed last vote op select bug #22 --- api/backend.sql | 21 +++++++++++++++++++-- run.sh | 9 ++++++--- 2 files changed, 25 insertions(+), 5 deletions(-) diff --git a/api/backend.sql b/api/backend.sql index 0aae581..9b81c5f 100644 --- a/api/backend.sql +++ b/api/backend.sql @@ -366,7 +366,6 @@ CREATE TYPE hafbe_backend.witness_voters AS ( timestamp TIMESTAMP ); --- TODO: order by timestamp too slow CREATE FUNCTION hafbe_backend.get_set_of_witness_voters(_witness_id INT) RETURNS SETOF hafbe_backend.witness_voters AS @@ -400,7 +399,7 @@ BEGIN SELECT voter_id, approve, operation_id FROM hafbe_app.witness_votes WHERE witness_id = _witness_id - ORDER BY operation_id + ORDER BY operation_id DESC ) votes_ordered ) voters JOIN LATERAL ( @@ -546,6 +545,24 @@ SET join_collapse_limit=16 SET from_collapse_limit=16 ; +CREATE FUNCTION hafbe_backend.top_witnesses(_limit INT) +RETURNS TABLE ( + _witness_id INT +) +AS +$function$ +BEGIN + RETURN QUERY SELECT witness_id + FROM hafbe_app.witness_votes + LIMIT _limit; +END +$function$ +LANGUAGE 'plpgsql' STABLE +SET JIT=OFF +SET join_collapse_limit=16 +SET from_collapse_limit=16 +; + CREATE FUNCTION hafbe_backend.get_account(_account TEXT) RETURNS JSON LANGUAGE 'plpython3u' diff --git a/run.sh b/run.sh index 51befd1..0e2c751 100755 --- a/run.sh +++ b/run.sh @@ -26,16 +26,19 @@ create_indexes() { echo "Creating indexes, this might take a while." psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "CREATE UNIQUE INDEX IF NOT EXISTS uq_hive_blocks_reversible_hash ON hive.blocks_reversible USING btree (hash, fork_id)" - psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "CREATE INDEX IF NOT EXISTS hive_operations_reversible_timestamp ON hive.operations_reversible USING btree (timestamp, id, fork_id)" - psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "CREATE UNIQUE INDEX IF NOT EXISTS uq_hive_blocks_hash ON hive.blocks USING btree (hash)" - psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "CREATE INDEX IF NOT EXISTS hive_operations_timestamp ON hive.operations USING btree (timestamp, id)" + + psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "CREATE INDEX IF NOT EXISTS hive_operations_reversible_timestamp_id ON hive.operations_reversible USING btree (timestamp, id, fork_id)" + psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "CREATE INDEX IF NOT EXISTS hive_operations_timestamp_id ON hive.operations USING btree (timestamp, id)" psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "CREATE UNIQUE INDEX IF NOT EXISTS hive_account_operations_reversible_uq2 ON hive.account_operations_reversible USING btree (account_id, op_type_id, operation_id, fork_id)" psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "CREATE UNIQUE INDEX IF NOT EXISTS hive_account_operations_uq2 ON hive.account_operations USING btree (account_id, op_type_id, operation_id)" psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "CREATE INDEX IF NOT EXISTS hive_account_operations_reversible_block_num ON hive.account_operations_reversible USING btree (block_num, fork_id)" psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "CREATE INDEX IF NOT EXISTS hive_account_operations_block_num ON hive.account_operations USING btree (block_num)" + + psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "CREATE INDEX IF NOT EXISTS hive_operations_reversible_timestamp ON hive.operations_reversible USING btree (timestamp, fork_id)" + psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "CREATE INDEX IF NOT EXISTS hive_operations_timestamp ON hive.operations USING btree (timestamp)" } start_webserver() { -- GitLab From ca6b3189e386ce0f7eb43c463dde78923984f2ac Mon Sep 17 00:00:00 2001 From: kristupas Date: Tue, 19 Jul 2022 14:53:16 +0000 Subject: [PATCH 12/89] Added 'get_witnesses()' #22 --- api/backend.sql | 112 +++++++++++++++++++++++++++++++++++++++++----- api/endpoints.sql | 8 ++-- 2 files changed, 106 insertions(+), 14 deletions(-) diff --git a/api/backend.sql b/api/backend.sql index 9b81c5f..e166689 100644 --- a/api/backend.sql +++ b/api/backend.sql @@ -477,7 +477,7 @@ END $$ ; -CREATE FUNCTION hafbe_backend.get_proxied_vests(_voter_id INT) +CREATE OR REPLACE FUNCTION hafbe_backend.get_proxied_vests(_voter_id INT) RETURNS TABLE ( _balance NUMERIC ) @@ -518,7 +518,7 @@ SET join_collapse_limit=16 SET from_collapse_limit=16 ; -CREATE FUNCTION hafbe_backend.is_voter_proxied(_voter_id INT) +CREATE OR REPLACE FUNCTION hafbe_backend.is_voter_proxied(_voter_id INT) RETURNS TABLE ( proxied BOOLEAN ) @@ -545,15 +545,44 @@ SET join_collapse_limit=16 SET from_collapse_limit=16 ; -CREATE FUNCTION hafbe_backend.top_witnesses(_limit INT) -RETURNS TABLE ( - _witness_id INT -) +CREATE TYPE hafbe_backend.witnesses AS ( + witness TEXT, + url TEXT, + voters_num INT, + voters_num_change INT +); + +CREATE OR REPLACE FUNCTION hafbe_backend.get_set_of_witnesses(_limit INT) +RETURNS SETOF hafbe_backend.witnesses AS $function$ +DECLARE + __first_op_today BIGINT = (SELECT id FROM hive.operations_view WHERE timestamp >= 'today'::TIMESTAMP ORDER BY id LIMIT 1); BEGIN - RETURN QUERY SELECT witness_id - FROM hafbe_app.witness_votes + RETURN QUERY SELECT + witness::TEXT, + url, + voters_num, + hafbe_backend.get_witness_voters_num(witness_id, __first_op_today, TRUE) - voters_num AS voters_num_change + FROM ( + SELECT + witness, + witness_id, + url, + hafbe_backend.get_witness_voters_num(witness_id, __first_op_today, FALSE) AS voters_num + FROM ( + SELECT DISTINCT ON (witness_id) + witness_id, + hav.name AS witness, + hafbe_backend.get_witness_url(witness_id) AS url + FROM hafbe_app.witness_votes + JOIN ( + SELECT name, id + FROM hive.accounts_view + ) hav ON hav.id = witness_id + ) uq_witness + ) num_of_voters + ORDER BY voters_num DESC LIMIT _limit; END $function$ @@ -563,7 +592,70 @@ SET join_collapse_limit=16 SET from_collapse_limit=16 ; -CREATE FUNCTION hafbe_backend.get_account(_account TEXT) +CREATE OR REPLACE FUNCTION hafbe_backend.get_witnesses(_limit INT) +RETURNS JSON +LANGUAGE 'plpgsql' +AS +$$ +BEGIN + RETURN CASE WHEN arr IS NOT NULL THEN to_json(arr) ELSE '[]'::JSON END FROM ( + SELECT ARRAY( + SELECT hafbe_backend.get_set_of_witnesses(_limit) + ) arr + ) result; +END +$$ +; + +CREATE OR REPLACE FUNCTION hafbe_backend.get_witness_voters_num(_witness_id INT, _first_op_today BIGINT, _include_today BOOLEAN) +RETURNS TABLE ( + n_voters INT +) +LANGUAGE 'plpgsql' +AS +$$ +BEGIN + RETURN QUERY SELECT + COUNT(*)::INT + FROM ( + SELECT DISTINCT voter_id + FROM ( + SELECT witness_id, voter_id, approve, operation_id + FROM hafbe_app.witness_votes + WHERE witness_id = _witness_id + ORDER BY operation_id DESC + ) votes_ordered + WHERE + approve IS TRUE AND + operation_id < (CASE WHEN _include_today IS FALSE THEN _first_op_today ELSE 9223372036854775808 END) + ) votes_by_op; +END +$$ +; + +CREATE OR REPLACE FUNCTION hafbe_backend.get_witness_url(_witness_id INT) +RETURNS TABLE ( + _BODY TEXT +) +LANGUAGE 'plpgsql' +AS +$$ +BEGIN + RETURN QUERY SELECT + (body::JSON)->'value'->>'url' + FROM hive.operations_view + JOIN ( + SELECT operation_id + FROM hive.account_operations_view + WHERE account_id = _witness_id AND op_type_id = 11 + ORDER BY operation_id DESC + LIMIT 1 + ) haov ON id = haov.operation_id; +END +$$ +; + +CREATE OR REPLACE FUNCTION hafbe_backend.get_account(_account TEXT) RETURNS JSON LANGUAGE 'plpython3u' AS @@ -585,7 +677,7 @@ $$ $$ ; -CREATE FUNCTION hafbe_backend.parse_profile_picture(_account_data JSON, _key TEXT) +CREATE OR REPLACE FUNCTION hafbe_backend.parse_profile_picture(_account_data JSON, _key TEXT) RETURNS TEXT LANGUAGE 'plpgsql' AS diff --git a/api/endpoints.sql b/api/endpoints.sql index eb9f23c..125a395 100644 --- a/api/endpoints.sql +++ b/api/endpoints.sql @@ -239,17 +239,17 @@ END $$ ; -CREATE FUNCTION hafbe_endpoints.get_witnesses(_witnesses_number INT = 50) +CREATE FUNCTION hafbe_endpoints.get_witnesses(_limit INT = 50) RETURNS JSON LANGUAGE 'plpgsql' AS $$ BEGIN - IF _witnesses_number IS NULL OR _witnesses_number <= 0 THEN - _witnesses_number = FALSE; + IF _limit IS NULL OR _limit <= 0 THEN + _limit = 50; END IF; - RETURN hafbe_backend.get_witnesses(_account); + RETURN hafbe_backend.get_witnesses(_limit); END $$ ; -- GitLab From 507203b3659a7fb313329d2ecdccb500e7fb3f0b Mon Sep 17 00:00:00 2001 From: kristupas Date: Mon, 25 Jul 2022 17:37:35 +0000 Subject: [PATCH 13/89] Added 'get_witness_exchange_rate()', removed GRANT user, updated plpython version #22 --- api/backend.sql | 82 ++++++++++++++++++++++++++++++++++++++++++++++++- api/roles.sql | 2 -- run.sh | 2 +- 3 files changed, 82 insertions(+), 4 deletions(-) diff --git a/api/backend.sql b/api/backend.sql index e166689..6b70971 100644 --- a/api/backend.sql +++ b/api/backend.sql @@ -635,7 +635,7 @@ $$ CREATE OR REPLACE FUNCTION hafbe_backend.get_witness_url(_witness_id INT) RETURNS TABLE ( - _BODY TEXT + _url TEXT ) LANGUAGE 'plpgsql' AS @@ -655,6 +655,86 @@ END $$ ; +CREATE OR REPLACE FUNCTION hafbe_backend.get_witness_exchange_rate(_witness_id INT, _last_op_id BIGINT = NULL) +RETURNS TEXT +LANGUAGE 'plpgsql' +AS +$$ +BEGIN + IF _last_op_id IS NULL THEN + SELECT id FROM hive.operations_view ORDER BY id DESC LIMIT 1 INTO _last_op_id; + END IF; + + RETURN + CASE WHEN op_type_id = 42 THEN + hafbe_backend.unpack_from_vector(exchange_rate) + ELSE + exchange_rate + END + FROM ( + SELECT + CASE WHEN exchange_rate IS NULL THEN + hafbe_backend.get_witness_exchange_rate(_witness_id, op_id - 1) + ELSE + exchange_rate + END AS exchange_rate, + op_type_id + FROM ( + SELECT + CASE WHEN op_type_id = 42 THEN + ((op->'props')->0)->>1 + ELSE + op->>'exchange_rate' + END AS exchange_rate, + op_type_id, + id AS op_id + FROM ( + SELECT + (body::JSON)->'value' AS op, + op_type_id, + id + FROM hive.operations_view + JOIN ( + SELECT operation_id + FROM hive.account_operations_view + WHERE account_id = _witness_id + ) haov ON id = haov.operation_id + WHERE + (op_type_id = 42 OR op_type_id = 7) AND id = 3937555428 + ORDER BY id DESC + LIMIT 1 + ) op + ) price + ) recur; +END +$$ +; + + +CREATE OR REPLACE FUNCTION hafbe_backend.unpack_from_vector(_exchange_rate TEXT) +RETURNS TEXT +LANGUAGE 'plpgsql' +AS +$$ +DECLARE + __half_vector_len INT; + __quarter_vector_len INT; + __base TEXT; + __quote TEXT; +BEGIN + SELECT LENGTH(_exchange_rate) / 2 INTO __half_vector_len; + SELECT __half_vector_len / 2 INTO __quarter_vector_len; + + SELECT substring(_exchange_rate for __half_vector_len) INTO __base; + SELECT substring(_exchange_rate from __half_vector_len) INTO __quote; + + -- TODO: add vector unpacking code + + RETURN _exchange_rate; +END +$$ +; + CREATE OR REPLACE FUNCTION hafbe_backend.get_account(_account TEXT) RETURNS JSON LANGUAGE 'plpython3u' diff --git a/api/roles.sql b/api/roles.sql index 38f52b4..419202f 100755 --- a/api/roles.sql +++ b/api/roles.sql @@ -1,7 +1,6 @@ -- recreate hafbe schemas owner DROP ROLE IF EXISTS hafbe_owner; CREATE ROLE hafbe_owner LOGIN INHERIT IN ROLE hive_applications_group; -GRANT hafbe_owner TO hive; ALTER SCHEMA hafbe_backend OWNER TO hafbe_owner; ALTER SCHEMA hafbe_endpoints OWNER TO hafbe_owner; @@ -20,7 +19,6 @@ $$ -- recreate hafbe schemas user DROP ROLE IF EXISTS hafbe_user; CREATE ROLE hafbe_user LOGIN INHERIT IN ROLE hive_applications_group; -GRANT hafbe_user TO hive; -- grant new priviliges GRANT USAGE ON SCHEMA hafbe_backend TO hafbe_user; diff --git a/run.sh b/run.sh index 0e2c751..335082e 100755 --- a/run.sh +++ b/run.sh @@ -66,7 +66,7 @@ install_postgrest() { install_plpython() { sudo apt-get update -y - sudo apt-get -y install python3 postgresql-plpython3-12 + sudo apt-get -y install python3 postgresql-plpython3-14 } install_jmeter() { -- GitLab From 6c9905f30353a2790e3fdfa41aeb8de31b283f46 Mon Sep 17 00:00:00 2001 From: kristupas Date: Wed, 27 Jul 2022 15:20:47 +0000 Subject: [PATCH 14/89] Changed 'get_witness_url()' to subquery #22 --- api/backend.sql | 160 +++++++++++++++++++++++++----------------------- 1 file changed, 82 insertions(+), 78 deletions(-) diff --git a/api/backend.sql b/api/backend.sql index 6b70971..66c0403 100644 --- a/api/backend.sql +++ b/api/backend.sql @@ -549,7 +549,9 @@ CREATE TYPE hafbe_backend.witnesses AS ( witness TEXT, url TEXT, voters_num INT, - voters_num_change INT + voters_num_change INT, + feed_price TEXT, --JSON + feed_age INTERVAL ); CREATE OR REPLACE FUNCTION hafbe_backend.get_set_of_witnesses(_limit INT) @@ -563,24 +565,55 @@ BEGIN witness::TEXT, url, voters_num, - hafbe_backend.get_witness_voters_num(witness_id, __first_op_today, TRUE) - voters_num AS voters_num_change + hafbe_backend.get_witness_voters_num(witness_id, __first_op_today, TRUE) - voters_num AS voters_num_change, + feed_data->>'exchange_rate' AS feed_price, + (NOW() - (feed_data->>'timestamp')::TIMESTAMP)::INTERVAL AS feed_age FROM ( SELECT witness, witness_id, - url, - hafbe_backend.get_witness_voters_num(witness_id, __first_op_today, FALSE) AS voters_num + hov.url AS url, + hafbe_backend.get_witness_voters_num(witness_id, __first_op_today, FALSE) AS voters_num, + hafbe_backend.get_witness_exchange_rate(witness_id) AS feed_data FROM ( SELECT DISTINCT ON (witness_id) + witness, witness_id, - hav.name AS witness, - hafbe_backend.get_witness_url(witness_id) AS url - FROM hafbe_app.witness_votes - JOIN ( - SELECT name, id - FROM hive.accounts_view - ) hav ON hav.id = witness_id - ) uq_witness + url_op_id + FROM ( + SELECT + witness, + witness_id, + haov.operation_id AS url_op_id + FROM ( + SELECT + wv.witness_id AS witness_id, + hav.name AS witness + FROM ( + SELECT DISTINCT witness_id + FROM hafbe_app.witness_votes + ) wv + JOIN ( + SELECT name, id + FROM hive.accounts_view + ) hav ON hav.id = wv.witness_id + ) uq_witness + JOIN ( + SELECT account_id, operation_id + FROM hive.account_operations_view + WHERE op_type_id = 11 + ) haov ON haov.account_id = witness_id + ORDER BY haov.operation_id DESC + ) url_ops + ) last_url_update + + JOIN ( + SELECT + id, + (body::JSON)->'value'->>'url' AS url + FROM hive.operations_view + ) hov ON hov.id = url_op_id + ) num_of_voters ORDER BY voters_num DESC LIMIT _limit; @@ -633,30 +666,8 @@ END $$ ; -CREATE OR REPLACE FUNCTION hafbe_backend.get_witness_url(_witness_id INT) -RETURNS TABLE ( - _url TEXT -) -LANGUAGE 'plpgsql' -AS -$$ -BEGIN - RETURN QUERY SELECT - (body::JSON)->'value'->>'url' - FROM hive.operations_view - JOIN ( - SELECT operation_id - FROM hive.account_operations_view - WHERE account_id = _witness_id AND op_type_id = 11 - ORDER BY operation_id DESC - LIMIT 1 - ) haov ON id = haov.operation_id; -END -$$ -; - CREATE OR REPLACE FUNCTION hafbe_backend.get_witness_exchange_rate(_witness_id INT, _last_op_id BIGINT = NULL) -RETURNS TEXT +RETURNS JSON LANGUAGE 'plpgsql' AS $$ @@ -665,71 +676,64 @@ BEGIN SELECT id FROM hive.operations_view ORDER BY id DESC LIMIT 1 INTO _last_op_id; END IF; - RETURN - CASE WHEN op_type_id = 42 THEN - hafbe_backend.unpack_from_vector(exchange_rate) - ELSE - exchange_rate - END - FROM ( + RETURN to_json(result) FROM ( SELECT - CASE WHEN exchange_rate IS NULL THEN - hafbe_backend.get_witness_exchange_rate(_witness_id, op_id - 1) + CASE WHEN op_type_id = 42 THEN + hafbe_backend.unpack_from_vector(exchange_rate) ELSE exchange_rate END AS exchange_rate, - op_type_id + timestamp FROM ( SELECT - CASE WHEN op_type_id = 42 THEN - ((op->'props')->0)->>1 + CASE WHEN exchange_rate IS NULL THEN + (SELECT f->>'exchange_rate' FROM hafbe_backend.get_witness_exchange_rate(_witness_id, op_id - 1) f) ELSE - op->>'exchange_rate' + exchange_rate END AS exchange_rate, op_type_id, - id AS op_id + timestamp FROM ( SELECT - (body::JSON)->'value' AS op, + CASE WHEN op_type_id = 42 THEN + ((op->'props')->0)->>1 + ELSE + op->>'exchange_rate' + END AS exchange_rate, op_type_id, - id - FROM hive.operations_view - JOIN ( - SELECT operation_id - FROM hive.account_operations_view - WHERE account_id = _witness_id - ) haov ON id = haov.operation_id - WHERE - (op_type_id = 42 OR op_type_id = 7) AND id = 3937555428 - ORDER BY id DESC - LIMIT 1 - ) op - ) price - ) recur; + id AS op_id, + timestamp + FROM ( + SELECT + (body::JSON)->'value' AS op, + op_type_id, + id, + timestamp + FROM hive.operations_view + JOIN ( + SELECT operation_id + FROM hive.account_operations_view + WHERE account_id = _witness_id + ) haov ON id = haov.operation_id + WHERE + (op_type_id = 42 OR op_type_id = 7) AND id <= _last_op_id + ORDER BY id DESC + LIMIT 1 + ) op + ) price + ) recur + ) result; END $$ ; - CREATE OR REPLACE FUNCTION hafbe_backend.unpack_from_vector(_exchange_rate TEXT) RETURNS TEXT LANGUAGE 'plpgsql' AS $$ -DECLARE - __half_vector_len INT; - __quarter_vector_len INT; - __base TEXT; - __quote TEXT; BEGIN - SELECT LENGTH(_exchange_rate) / 2 INTO __half_vector_len; - SELECT __half_vector_len / 2 INTO __quarter_vector_len; - - SELECT substring(_exchange_rate for __half_vector_len) INTO __base; - SELECT substring(_exchange_rate from __half_vector_len) INTO __quote; - - -- TODO: add vector unpacking code - + -- TODO: to be replaced by hive fork manager method RETURN _exchange_rate; END $$ -- GitLab From 09046bf963f3ce4084f45abcc3deb1d37641eb53 Mon Sep 17 00:00:00 2001 From: kristupas Date: Wed, 27 Jul 2022 15:38:50 +0000 Subject: [PATCH 15/89] Improved 'get_set_of_witnesses()' performance #22 --- api/backend.sql | 85 ++++++++++++++++++++++++------------------------- 1 file changed, 42 insertions(+), 43 deletions(-) diff --git a/api/backend.sql b/api/backend.sql index 66c0403..6a3e447 100644 --- a/api/backend.sql +++ b/api/backend.sql @@ -562,61 +562,60 @@ DECLARE __first_op_today BIGINT = (SELECT id FROM hive.operations_view WHERE timestamp >= 'today'::TIMESTAMP ORDER BY id LIMIT 1); BEGIN RETURN QUERY SELECT - witness::TEXT, - url, - voters_num, - hafbe_backend.get_witness_voters_num(witness_id, __first_op_today, TRUE) - voters_num AS voters_num_change, + witness::TEXT, url, voters_num, voters_num_change, feed_data->>'exchange_rate' AS feed_price, (NOW() - (feed_data->>'timestamp')::TIMESTAMP)::INTERVAL AS feed_age - FROM ( + FROM( SELECT - witness, - witness_id, - hov.url AS url, - hafbe_backend.get_witness_voters_num(witness_id, __first_op_today, FALSE) AS voters_num, + witness, url, voters_num, + hafbe_backend.get_witness_voters_num(witness_id, __first_op_today, TRUE) - voters_num AS voters_num_change, hafbe_backend.get_witness_exchange_rate(witness_id) AS feed_data FROM ( - SELECT DISTINCT ON (witness_id) - witness, - witness_id, - url_op_id + SELECT + witness, witness_id, + hov.url AS url, + hafbe_backend.get_witness_voters_num(witness_id, __first_op_today, FALSE) AS voters_num FROM ( - SELECT - witness, - witness_id, - haov.operation_id AS url_op_id + SELECT DISTINCT ON (witness_id) + witness, witness_id, url_op_id FROM ( SELECT - wv.witness_id AS witness_id, - hav.name AS witness + witness, witness_id, + haov.operation_id AS url_op_id FROM ( - SELECT DISTINCT witness_id - FROM hafbe_app.witness_votes - ) wv - JOIN ( - SELECT name, id - FROM hive.accounts_view - ) hav ON hav.id = wv.witness_id - ) uq_witness - JOIN ( - SELECT account_id, operation_id - FROM hive.account_operations_view - WHERE op_type_id = 11 - ) haov ON haov.account_id = witness_id - ORDER BY haov.operation_id DESC - ) url_ops - ) last_url_update + SELECT + wv.witness_id AS witness_id, + hav.name AS witness + FROM ( + SELECT DISTINCT witness_id + FROM hafbe_app.witness_votes + ) wv + + JOIN ( + SELECT name, id + FROM hive.accounts_view + ) hav ON hav.id = wv.witness_id + ) uq_witness - JOIN ( - SELECT - id, - (body::JSON)->'value'->>'url' AS url - FROM hive.operations_view - ) hov ON hov.id = url_op_id + JOIN ( + SELECT account_id, operation_id + FROM hive.account_operations_view + WHERE op_type_id = 11 + ) haov ON haov.account_id = witness_id + ORDER BY haov.operation_id DESC + ) url_ops + ) last_url_update - ) num_of_voters + JOIN ( + SELECT + id, + (body::JSON)->'value'->>'url' AS url + FROM hive.operations_view + ) hov ON hov.id = url_op_id + ) num_of_voters ORDER BY voters_num DESC - LIMIT _limit; + LIMIT _limit + ) num_change_feed_upd; END $function$ LANGUAGE 'plpgsql' STABLE -- GitLab From 62d53a6ff48d0ce7d67f5165a4a03cc103cbd940 Mon Sep 17 00:00:00 2001 From: kristupas Date: Thu, 28 Jul 2022 08:34:20 +0000 Subject: [PATCH 16/89] Added 'get_witness_signing_key()' #22 --- api/backend.sql | 136 ++++++++++++++++++++++++++++++++++++++---------- 1 file changed, 109 insertions(+), 27 deletions(-) diff --git a/api/backend.sql b/api/backend.sql index 6a3e447..20f5cd8 100644 --- a/api/backend.sql +++ b/api/backend.sql @@ -550,8 +550,10 @@ CREATE TYPE hafbe_backend.witnesses AS ( url TEXT, voters_num INT, voters_num_change INT, - feed_price TEXT, --JSON - feed_age INTERVAL + price_feed TEXT, --JSON, + bias INT, + feed_age INTERVAL, + signing_key TEXT ); CREATE OR REPLACE FUNCTION hafbe_backend.get_set_of_witnesses(_limit INT) @@ -563,13 +565,18 @@ DECLARE BEGIN RETURN QUERY SELECT witness::TEXT, url, voters_num, voters_num_change, - feed_data->>'exchange_rate' AS feed_price, - (NOW() - (feed_data->>'timestamp')::TIMESTAMP)::INTERVAL AS feed_age + feed_data->>'exchange_rate' AS price_feed, + --(feed_data->'exchange_rate'->'quote'->>'amount')::INT - 1000 AS bias + 0 AS bias, + (NOW() - (feed_data->>'timestamp')::TIMESTAMP)::INTERVAL AS feed_age, + signing_data->>'signing_key' AS signing_key FROM( SELECT + -- todo: maybe url is also in set witness props operation witness, url, voters_num, hafbe_backend.get_witness_voters_num(witness_id, __first_op_today, TRUE) - voters_num AS voters_num_change, - hafbe_backend.get_witness_exchange_rate(witness_id) AS feed_data + hafbe_backend.get_witness_exchange_rate(witness_id) AS feed_data, + hafbe_backend.get_witness_signing_key(witness_id) AS signing_data FROM ( SELECT witness, witness_id, @@ -665,37 +672,57 @@ END $$ ; -CREATE OR REPLACE FUNCTION hafbe_backend.get_witness_exchange_rate(_witness_id INT, _last_op_id BIGINT = NULL) +CREATE OR REPLACE FUNCTION hafbe_backend.latest_op_id() RETURNS JSON LANGUAGE 'plpgsql' AS $$ +BEGIN + RETURN id FROM hive.operations_view ORDER BY id DESC LIMIT 1; +END +$$ +; + +CREATE OR REPLACE FUNCTION hafbe_backend.parse_witness_set_props(_op_value JSON, _attr_name TEXT) +RETURNS TEXT +LANGUAGE 'plpgsql' +AS +$$ +BEGIN + RETURN props->>1 + FROM ( + SELECT json_array_elements(_op_value->'props') AS props + ) to_arr + WHERE props->>0 = _attr_name; +END +$$ +; + +CREATE OR REPLACE FUNCTION hafbe_backend.get_witness_exchange_rate(_witness_id INT, _last_op_id BIGINT = NULL) +RETURNS JSON +AS +$function$ BEGIN IF _last_op_id IS NULL THEN - SELECT id FROM hive.operations_view ORDER BY id DESC LIMIT 1 INTO _last_op_id; + SELECT hafbe_backend.latest_op_id() INTO _last_op_id; END IF; RETURN to_json(result) FROM ( SELECT - CASE WHEN op_type_id = 42 THEN + CASE WHEN op_type_id = 42 AND exchange_rate IS NOT NULL THEN hafbe_backend.unpack_from_vector(exchange_rate) - ELSE - exchange_rate - END AS exchange_rate, + ELSE exchange_rate END AS exchange_rate, timestamp FROM ( SELECT - CASE WHEN exchange_rate IS NULL THEN + CASE WHEN op_type_id = 42 AND exchange_rate IS NULL THEN (SELECT f->>'exchange_rate' FROM hafbe_backend.get_witness_exchange_rate(_witness_id, op_id - 1) f) - ELSE - exchange_rate - END AS exchange_rate, - op_type_id, - timestamp + ELSE exchange_rate END AS exchange_rate, + op_type_id, timestamp FROM ( SELECT CASE WHEN op_type_id = 42 THEN - ((op->'props')->0)->>1 + hafbe_backend.parse_witness_set_props(op, 'hbd_exchange_rate') ELSE op->>'exchange_rate' END AS exchange_rate, @@ -705,25 +732,26 @@ BEGIN FROM ( SELECT (body::JSON)->'value' AS op, - op_type_id, - id, - timestamp + op_type_id, id, timestamp FROM hive.operations_view + JOIN ( SELECT operation_id FROM hive.account_operations_view - WHERE account_id = _witness_id + WHERE account_id = _witness_id AND (op_type_id = 42 OR op_type_id = 7) AND operation_id <= _last_op_id + ORDER BY operation_id DESC + LIMIT 1 ) haov ON id = haov.operation_id - WHERE - (op_type_id = 42 OR op_type_id = 7) AND id <= _last_op_id - ORDER BY id DESC - LIMIT 1 ) op ) price ) recur ) result; END -$$ +$function$ +LANGUAGE 'plpgsql' STABLE +SET JIT=OFF +SET join_collapse_limit=16 +SET from_collapse_limit=16 ; CREATE OR REPLACE FUNCTION hafbe_backend.unpack_from_vector(_exchange_rate TEXT) @@ -738,6 +766,60 @@ END $$ ; +CREATE OR REPLACE FUNCTION hafbe_backend.get_witness_signing_key(_witness_id INT, _last_op_id BIGINT = NULL) +RETURNS JSON +AS +$function$ +BEGIN + IF _last_op_id IS NULL THEN + SELECT hafbe_backend.latest_op_id() INTO _last_op_id; + END IF; + + RETURN to_json(result) FROM ( + SELECT + CASE WHEN op_type_id = 42 AND signing_key IS NULL THEN + (SELECT f->>'signing_key' FROM hafbe_backend.get_witness_signing_key(_witness_id, op_id - 1) f) + ELSE signing_key END AS signing_key + FROM ( + SELECT + CASE WHEN op_type_id = 42 AND signing_key IS NULL THEN + hafbe_backend.parse_witness_set_props(signing_key::JSON, 'key') + ELSE signing_key END AS signing_key, + op_type_id, op_id + FROM ( + SELECT + CASE WHEN op_type_id = 42 THEN + hafbe_backend.parse_witness_set_props(op, 'new_signing_key') + ELSE + op->>'block_signing_key' + END AS signing_key, + op_type_id, + id AS op_id + FROM ( + SELECT + (body::JSON)->'value' AS op, + op_type_id, id + FROM hive.operations_view + + JOIN ( + SELECT operation_id + FROM hive.account_operations_view + WHERE account_id = _witness_id AND (op_type_id = 42 OR op_type_id = 11) AND operation_id <= _last_op_id + ORDER BY operation_id DESC + LIMIT 1 + ) haov ON id = haov.operation_id + ) key_op + ) new_key_val + ) key_val + ) result; +END +$function$ +LANGUAGE 'plpgsql' STABLE +SET JIT=OFF +SET join_collapse_limit=16 +SET from_collapse_limit=16 +; + CREATE OR REPLACE FUNCTION hafbe_backend.get_account(_account TEXT) RETURNS JSON LANGUAGE 'plpython3u' -- GitLab From 2d7c75f86060a0661b39672a33751164cf452e89 Mon Sep 17 00:00:00 2001 From: kristupas Date: Thu, 28 Jul 2022 10:42:34 +0000 Subject: [PATCH 17/89] Added 'get_witness_url()' with id 42 op support #22 --- api/backend.sql | 133 +++++++++++++++++++++++++++++------------------- 1 file changed, 81 insertions(+), 52 deletions(-) diff --git a/api/backend.sql b/api/backend.sql index 20f5cd8..88599f7 100644 --- a/api/backend.sql +++ b/api/backend.sql @@ -564,7 +564,10 @@ DECLARE __first_op_today BIGINT = (SELECT id FROM hive.operations_view WHERE timestamp >= 'today'::TIMESTAMP ORDER BY id LIMIT 1); BEGIN RETURN QUERY SELECT - witness::TEXT, url, voters_num, voters_num_change, + witness::TEXT, + url_data->>'url', + voters_num, + voters_num_change, feed_data->>'exchange_rate' AS price_feed, --(feed_data->'exchange_rate'->'quote'->>'amount')::INT - 1000 AS bias 0 AS bias, @@ -572,53 +575,25 @@ BEGIN signing_data->>'signing_key' AS signing_key FROM( SELECT - -- todo: maybe url is also in set witness props operation - witness, url, voters_num, + witness, voters_num, hafbe_backend.get_witness_voters_num(witness_id, __first_op_today, TRUE) - voters_num AS voters_num_change, + hafbe_backend.get_witness_url(witness_id) AS url_data, hafbe_backend.get_witness_exchange_rate(witness_id) AS feed_data, hafbe_backend.get_witness_signing_key(witness_id) AS signing_data FROM ( SELECT - witness, witness_id, - hov.url AS url, - hafbe_backend.get_witness_voters_num(witness_id, __first_op_today, FALSE) AS voters_num + wv.witness_id AS witness_id, + hav.name AS witness, + hafbe_backend.get_witness_voters_num(wv.witness_id, __first_op_today, FALSE) AS voters_num FROM ( - SELECT DISTINCT ON (witness_id) - witness, witness_id, url_op_id - FROM ( - SELECT - witness, witness_id, - haov.operation_id AS url_op_id - FROM ( - SELECT - wv.witness_id AS witness_id, - hav.name AS witness - FROM ( - SELECT DISTINCT witness_id - FROM hafbe_app.witness_votes - ) wv - - JOIN ( - SELECT name, id - FROM hive.accounts_view - ) hav ON hav.id = wv.witness_id - ) uq_witness - - JOIN ( - SELECT account_id, operation_id - FROM hive.account_operations_view - WHERE op_type_id = 11 - ) haov ON haov.account_id = witness_id - ORDER BY haov.operation_id DESC - ) url_ops - ) last_url_update + SELECT DISTINCT witness_id + FROM hafbe_app.witness_votes + ) wv JOIN ( - SELECT - id, - (body::JSON)->'value'->>'url' AS url - FROM hive.operations_view - ) hov ON hov.id = url_op_id + SELECT name, id + FROM hive.accounts_view + ) hav ON hav.id = wv.witness_id ) num_of_voters ORDER BY voters_num DESC LIMIT _limit @@ -698,6 +673,72 @@ END $$ ; +CREATE OR REPLACE FUNCTION hafbe_backend.unpack_from_vector(_vector TEXT) +RETURNS TEXT +LANGUAGE 'plpgsql' +AS +$$ +BEGIN + -- TODO: to be replaced by hive fork manager method + RETURN _vector; +END +$$ +; + +CREATE OR REPLACE FUNCTION hafbe_backend.get_witness_url(_witness_id INT, _last_op_id BIGINT = NULL) +RETURNS JSON +AS +$function$ +BEGIN + IF _last_op_id IS NULL THEN + SELECT hafbe_backend.latest_op_id() INTO _last_op_id; + END IF; + + RETURN to_json(result) FROM ( + SELECT + CASE WHEN op_type_id = 42 AND url IS NOT NULL THEN + hafbe_backend.unpack_from_vector(url) + ELSE url END AS url + FROM ( + SELECT + CASE WHEN op_type_id = 42 AND url IS NULL THEN + (SELECT f->>'url' FROM hafbe_backend.get_witness_url(_witness_id, op_id - 1) f) + ELSE url END AS url, + op_type_id + FROM ( + SELECT + CASE WHEN op_type_id = 42 THEN + hafbe_backend.parse_witness_set_props(op, 'url') + ELSE + op->>'url' + END AS url, + op_type_id, + id AS op_id + FROM ( + SELECT + (body::JSON)->'value' AS op, + op_type_id, id + FROM hive.operations_view + + JOIN ( + SELECT operation_id + FROM hive.account_operations_view + WHERE account_id = _witness_id AND (op_type_id = 42 OR op_type_id = 11) AND operation_id <= _last_op_id + ORDER BY operation_id DESC + LIMIT 1 + ) haov ON id = haov.operation_id + ) op + ) price + ) recur + ) result; +END +$function$ +LANGUAGE 'plpgsql' STABLE +SET JIT=OFF +SET join_collapse_limit=16 +SET from_collapse_limit=16 +; + CREATE OR REPLACE FUNCTION hafbe_backend.get_witness_exchange_rate(_witness_id INT, _last_op_id BIGINT = NULL) RETURNS JSON AS @@ -754,18 +795,6 @@ SET join_collapse_limit=16 SET from_collapse_limit=16 ; -CREATE OR REPLACE FUNCTION hafbe_backend.unpack_from_vector(_exchange_rate TEXT) -RETURNS TEXT -LANGUAGE 'plpgsql' -AS -$$ -BEGIN - -- TODO: to be replaced by hive fork manager method - RETURN _exchange_rate; -END -$$ -; - CREATE OR REPLACE FUNCTION hafbe_backend.get_witness_signing_key(_witness_id INT, _last_op_id BIGINT = NULL) RETURNS JSON AS -- GitLab From 196af2918ca0b5af83a37a8048ffbfc0ca394c8f Mon Sep 17 00:00:00 2001 From: kristupas Date: Fri, 29 Jul 2022 08:59:00 +0000 Subject: [PATCH 18/89] Added 'get_witness_block_size()' #22 --- api/backend.sql | 57 +++++++++++++++++++++++++++++++++++++++++++++++++ 1 file changed, 57 insertions(+) diff --git a/api/backend.sql b/api/backend.sql index 88599f7..8d0c571 100644 --- a/api/backend.sql +++ b/api/backend.sql @@ -553,6 +553,7 @@ CREATE TYPE hafbe_backend.witnesses AS ( price_feed TEXT, --JSON, bias INT, feed_age INTERVAL, + block_size INT, signing_key TEXT ); @@ -572,6 +573,7 @@ BEGIN --(feed_data->'exchange_rate'->'quote'->>'amount')::INT - 1000 AS bias 0 AS bias, (NOW() - (feed_data->>'timestamp')::TIMESTAMP)::INTERVAL AS feed_age, + (block_size_data->>'block_size')::INT AS block_size, signing_data->>'signing_key' AS signing_key FROM( SELECT @@ -579,6 +581,7 @@ BEGIN hafbe_backend.get_witness_voters_num(witness_id, __first_op_today, TRUE) - voters_num AS voters_num_change, hafbe_backend.get_witness_url(witness_id) AS url_data, hafbe_backend.get_witness_exchange_rate(witness_id) AS feed_data, + hafbe_backend.get_witness_block_size(witness_id) AS block_size_data, hafbe_backend.get_witness_signing_key(witness_id) AS signing_data FROM ( SELECT @@ -739,6 +742,60 @@ SET join_collapse_limit=16 SET from_collapse_limit=16 ; +CREATE OR REPLACE FUNCTION hafbe_backend.get_witness_block_size(_witness_id INT, _last_op_id BIGINT = NULL) +RETURNS JSON +AS +$function$ +BEGIN + IF _last_op_id IS NULL THEN + SELECT hafbe_backend.latest_op_id() INTO _last_op_id; + END IF; + + RETURN to_json(result) FROM ( + SELECT + CASE WHEN op_type_id = 42 AND block_size IS NOT NULL THEN + hafbe_backend.unpack_from_vector(block_size) + ELSE block_size END AS block_size + FROM ( + SELECT + CASE WHEN op_type_id = 42 AND block_size IS NULL THEN + (SELECT f->>'block_size' FROM hafbe_backend.get_witness_block_size(_witness_id, op_id - 1) f) + ELSE block_size END AS block_size, + op_type_id + FROM ( + SELECT + CASE WHEN op_type_id = 42 THEN + hafbe_backend.parse_witness_set_props(op, 'maximum_block_size') + ELSE + op->'props'->>'maximum_block_size' + END AS block_size, + op_type_id, + id AS op_id + FROM ( + SELECT + (body::JSON)->'value' AS op, + op_type_id, id, timestamp + FROM hive.operations_view + + JOIN ( + SELECT operation_id + FROM hive.account_operations_view + WHERE account_id = _witness_id AND op_type_id = ANY('{42,30,14,11}'::INT[]) AND operation_id <= _last_op_id + ORDER BY operation_id DESC + LIMIT 1 + ) haov ON id = haov.operation_id + ) op + ) price + ) recur + ) result; +END +$function$ +LANGUAGE 'plpgsql' STABLE +SET JIT=OFF +SET join_collapse_limit=16 +SET from_collapse_limit=16 +; + CREATE OR REPLACE FUNCTION hafbe_backend.get_witness_exchange_rate(_witness_id INT, _last_op_id BIGINT = NULL) RETURNS JSON AS -- GitLab From 60783923fe2de704e2f1f8f4bd503a227c8430aa Mon Sep 17 00:00:00 2001 From: kristupas Date: Fri, 29 Jul 2022 11:45:16 +0000 Subject: [PATCH 19/89] Prepared 'get_set_of_witnesses()' returned object for voters stats #22 --- api/backend.sql | 100 ++++++++++++++++++++++++++---------------------- 1 file changed, 55 insertions(+), 45 deletions(-) diff --git a/api/backend.sql b/api/backend.sql index 8d0c571..7ef0188 100644 --- a/api/backend.sql +++ b/api/backend.sql @@ -402,15 +402,17 @@ BEGIN ORDER BY operation_id DESC ) votes_ordered ) voters + JOIN LATERAL ( SELECT name, id FROM hive.accounts_view ) acc ON acc.id = voters.voter_id JOIN LATERAL ( - SELECT balance, account, nai + SELECT balance, account FROM btracker_app.current_account_balances + WHERE nai = 37 ) cab ON cab.account = acc.name - WHERE voters.approve IS TRUE AND cab.nai = 37 + WHERE voters.approve IS TRUE ) vests JOIN LATERAL ( SELECT timestamp, id @@ -548,13 +550,16 @@ SET from_collapse_limit=16 CREATE TYPE hafbe_backend.witnesses AS ( witness TEXT, url TEXT, + votes INT, + votes_daily_change INT, voters_num INT, voters_num_change INT, price_feed TEXT, --JSON, bias INT, feed_age INTERVAL, block_size INT, - signing_key TEXT + signing_key TEXT, + version TEXT ); CREATE OR REPLACE FUNCTION hafbe_backend.get_set_of_witnesses(_limit INT) @@ -566,41 +571,53 @@ DECLARE BEGIN RETURN QUERY SELECT witness::TEXT, - url_data->>'url', + url_data->>'url' AS url, + votes, + (votes_change_data->>'votes')::INT - votes AS votes_daily_change, voters_num, - voters_num_change, + (votes_change_data->>'voters_num')::INT - voters_num AS voters_num_change, feed_data->>'exchange_rate' AS price_feed, --(feed_data->'exchange_rate'->'quote'->>'amount')::INT - 1000 AS bias 0 AS bias, (NOW() - (feed_data->>'timestamp')::TIMESTAMP)::INTERVAL AS feed_age, (block_size_data->>'block_size')::INT AS block_size, - signing_data->>'signing_key' AS signing_key - FROM( + signing_data->>'signing_key' AS signing_key, + '1.25.0' AS version + FROM ( SELECT - witness, voters_num, - hafbe_backend.get_witness_voters_num(witness_id, __first_op_today, TRUE) - voters_num AS voters_num_change, + witness, + votes, + voters_num, + hafbe_backend.get_witness_votes(witness_id) AS votes_change_data, hafbe_backend.get_witness_url(witness_id) AS url_data, hafbe_backend.get_witness_exchange_rate(witness_id) AS feed_data, hafbe_backend.get_witness_block_size(witness_id) AS block_size_data, hafbe_backend.get_witness_signing_key(witness_id) AS signing_data FROM ( SELECT - wv.witness_id AS witness_id, - hav.name AS witness, - hafbe_backend.get_witness_voters_num(wv.witness_id, __first_op_today, FALSE) AS voters_num + witness_id, + witness, + (votes_data->>'votes')::INT AS votes, + (votes_data->>'voters_num')::INT AS voters_num FROM ( - SELECT DISTINCT witness_id - FROM hafbe_app.witness_votes - ) wv - - JOIN ( - SELECT name, id - FROM hive.accounts_view - ) hav ON hav.id = wv.witness_id - ) num_of_voters - ORDER BY voters_num DESC - LIMIT _limit - ) num_change_feed_upd; + SELECT + wv.witness_id AS witness_id, + hav.name AS witness, + hafbe_backend.get_witness_votes(wv.witness_id, __first_op_today, FALSE) AS votes_data + FROM ( + SELECT DISTINCT witness_id + FROM hafbe_app.witness_votes + ) wv + + JOIN ( + SELECT name, id + FROM hive.accounts_view + ) hav ON hav.id = wv.witness_id + ) witness_votes + ) votes_and_num + ORDER BY votes DESC + LIMIT _limit + ) daily_change; END $function$ LANGUAGE 'plpgsql' STABLE @@ -624,30 +641,23 @@ END $$ ; -CREATE OR REPLACE FUNCTION hafbe_backend.get_witness_voters_num(_witness_id INT, _first_op_today BIGINT, _include_today BOOLEAN) -RETURNS TABLE ( - n_voters INT -) -LANGUAGE 'plpgsql' +CREATE OR REPLACE FUNCTION hafbe_backend.get_witness_votes(_witness_id INT, _first_op_today BIGINT = NULL, _include_today BOOLEAN = TRUE) +RETURNS JSON AS -$$ +$function$ BEGIN - RETURN QUERY SELECT - COUNT(*)::INT - FROM ( - SELECT DISTINCT voter_id - FROM ( - SELECT witness_id, voter_id, approve, operation_id - FROM hafbe_app.witness_votes - WHERE witness_id = _witness_id - ORDER BY operation_id DESC - ) votes_ordered - WHERE - approve IS TRUE AND - operation_id < (CASE WHEN _include_today IS FALSE THEN _first_op_today ELSE 9223372036854775808 END) - ) votes_by_op; + RETURN to_json(result) FROM ( + -- TODO: split is_voter_proxied() and reuse code for witness votes and voters_num + SELECT + 0 AS votes, + 0 AS voters_num + ) result; END -$$ +$function$ +LANGUAGE 'plpgsql' STABLE +SET JIT=OFF +SET join_collapse_limit=16 +SET from_collapse_limit=16 ; CREATE OR REPLACE FUNCTION hafbe_backend.latest_op_id() -- GitLab From 1fc8ae886f20ddeec8148ff3b47a1933cf8ffd2c Mon Sep 17 00:00:00 2001 From: kristupas Date: Fri, 29 Jul 2022 16:39:06 +0000 Subject: [PATCH 20/89] Made part of 'get_set_of_witness_voters()' code reusable #22 --- api/backend.sql | 133 ++++++++++++++++++++++++++++-------------------- 1 file changed, 77 insertions(+), 56 deletions(-) diff --git a/api/backend.sql b/api/backend.sql index 7ef0188..e02e18e 100644 --- a/api/backend.sql +++ b/api/backend.sql @@ -358,68 +358,88 @@ END $$ ; -CREATE TYPE hafbe_backend.witness_voters AS ( +CREATE TYPE hafbe_backend.witness_voters_vests AS ( account TEXT, vests NUMERIC, - account_vests BIGINT, + account_vests NUMERIC, proxied_vests NUMERIC, - timestamp TIMESTAMP + operation_id BIGINT ); -CREATE FUNCTION hafbe_backend.get_set_of_witness_voters(_witness_id INT) -RETURNS SETOF hafbe_backend.witness_voters +CREATE FUNCTION hafbe_backend.get_set_of_witness_voters_vests(_witness_id INT) +RETURNS SETOF hafbe_backend.witness_voters_vests AS $function$ BEGIN - RETURN QUERY SELECT account, vests, account_vests, proxied_vests, timestamp + RETURN QUERY SELECT + account::TEXT, + (account_vests + proxied_vests)::NUMERIC AS vests, + account_vests::NUMERIC, + proxied_vests::NUMERIC, + operation_id FROM ( SELECT account, - account_vests + proxied_vests AS vests, - account_vests, + CASE WHEN is_proxied IS TRUE THEN 0 ELSE account_vests END AS account_vests, proxied_vests, - timestamp + operation_id FROM ( SELECT - account, - CASE WHEN is_proxied IS TRUE THEN 0 ELSE account_vests END AS account_vests, - proxied_vests, - hov.timestamp AS timestamp + acc.name AS account, + cab.balance AS account_vests, + hafbe_backend.get_proxied_vests(voters.voter_id) AS proxied_vests, + hafbe_backend.is_voter_proxied(voters.voter_id) AS is_proxied, + voters.operation_id AS operation_id FROM ( - SELECT - acc.name::TEXT AS account, - cab.balance AS account_vests, - hafbe_backend.get_proxied_vests(voters.voter_id) AS proxied_vests, - hafbe_backend.is_voter_proxied(voters.voter_id) AS is_proxied, - voters.operation_id AS operation_id + SELECT DISTINCT ON (voter_id) + voter_id, approve, operation_id FROM ( - SELECT DISTINCT ON (voter_id) - voter_id, approve, operation_id - FROM ( - SELECT voter_id, approve, operation_id - FROM hafbe_app.witness_votes - WHERE witness_id = _witness_id - ORDER BY operation_id DESC - ) votes_ordered - ) voters - - JOIN LATERAL ( - SELECT name, id - FROM hive.accounts_view - ) acc ON acc.id = voters.voter_id - JOIN LATERAL ( - SELECT balance, account - FROM btracker_app.current_account_balances - WHERE nai = 37 - ) cab ON cab.account = acc.name - WHERE voters.approve IS TRUE - ) vests + SELECT voter_id, approve, operation_id + FROM hafbe_app.witness_votes + WHERE witness_id = _witness_id + ORDER BY operation_id DESC + ) votes_ordered + ) voters + JOIN LATERAL ( - SELECT timestamp, id - FROM hive.operations_view - ) hov ON hov.id = vests.operation_id - ) is_proxied - ) vests_sum; + SELECT name, id + FROM hive.accounts_view + ) acc ON acc.id = voters.voter_id + JOIN LATERAL ( + SELECT balance, account + FROM btracker_app.current_account_balances + WHERE nai = 37 + ) cab ON cab.account = acc.name + WHERE voters.approve IS TRUE + ) vests + ) result; +END +$function$ +LANGUAGE 'plpgsql' STABLE +SET JIT=OFF +SET join_collapse_limit=16 +SET from_collapse_limit=16 +; + +CREATE TYPE hafbe_backend.witness_voters AS ( + account TEXT, + vests NUMERIC, + account_vests NUMERIC, + proxied_vests NUMERIC, + timestamp TIMESTAMP +); + +CREATE FUNCTION hafbe_backend.get_set_of_witness_voters(_witness_id INT) +RETURNS SETOF hafbe_backend.witness_voters +AS +$function$ +BEGIN + RETURN QUERY SELECT account, vests, account_vests, proxied_vests, hov.timestamp + FROM hafbe_backend.get_set_of_witness_voters_vests(_witness_id) + JOIN LATERAL ( + SELECT timestamp, id + FROM hive.operations_view + ) hov ON hov.id = operation_id; END $function$ LANGUAGE 'plpgsql' STABLE @@ -550,8 +570,8 @@ SET from_collapse_limit=16 CREATE TYPE hafbe_backend.witnesses AS ( witness TEXT, url TEXT, - votes INT, - votes_daily_change INT, + votes NUMERIC, + votes_daily_change BIGINT, voters_num INT, voters_num_change INT, price_feed TEXT, --JSON, @@ -573,9 +593,9 @@ BEGIN witness::TEXT, url_data->>'url' AS url, votes, - (votes_change_data->>'votes')::INT - votes AS votes_daily_change, + ((votes_change_data->>'votes')::NUMERIC - votes)::BIGINT AS votes_daily_change, voters_num, - (votes_change_data->>'voters_num')::INT - voters_num AS voters_num_change, + ((votes_change_data->>'voters_num')::INT - voters_num)::INT AS voters_num_change, feed_data->>'exchange_rate' AS price_feed, --(feed_data->'exchange_rate'->'quote'->>'amount')::INT - 1000 AS bias 0 AS bias, @@ -588,7 +608,7 @@ BEGIN witness, votes, voters_num, - hafbe_backend.get_witness_votes(witness_id) AS votes_change_data, + hafbe_backend.get_witness_votes_stats(witness_id, __first_op_today) AS votes_change_data, hafbe_backend.get_witness_url(witness_id) AS url_data, hafbe_backend.get_witness_exchange_rate(witness_id) AS feed_data, hafbe_backend.get_witness_block_size(witness_id) AS block_size_data, @@ -597,13 +617,13 @@ BEGIN SELECT witness_id, witness, - (votes_data->>'votes')::INT AS votes, + (votes_data->>'votes')::NUMERIC AS votes, (votes_data->>'voters_num')::INT AS voters_num FROM ( SELECT wv.witness_id AS witness_id, hav.name AS witness, - hafbe_backend.get_witness_votes(wv.witness_id, __first_op_today, FALSE) AS votes_data + hafbe_backend.get_witness_votes_stats(wv.witness_id) AS votes_data FROM ( SELECT DISTINCT witness_id FROM hafbe_app.witness_votes @@ -641,16 +661,17 @@ END $$ ; -CREATE OR REPLACE FUNCTION hafbe_backend.get_witness_votes(_witness_id INT, _first_op_today BIGINT = NULL, _include_today BOOLEAN = TRUE) +CREATE OR REPLACE FUNCTION hafbe_backend.get_witness_votes_stats(_witness_id INT, _first_op_today BIGINT = 9223372036854775807) RETURNS JSON AS $function$ BEGIN RETURN to_json(result) FROM ( - -- TODO: split is_voter_proxied() and reuse code for witness votes and voters_num SELECT - 0 AS votes, - 0 AS voters_num + SUM(vests) AS votes, + COUNT(*) AS voters_num + FROM hafbe_backend.get_set_of_witness_voters_vests(_witness_id) + WHERE operation_id < _first_op_today ) result; END $function$ -- GitLab From 84cec4290c63eff4c5c090949c9a2fa252d063e8 Mon Sep 17 00:00:00 2001 From: kristupas Date: Fri, 29 Jul 2022 17:14:16 +0000 Subject: [PATCH 21/89] Reordered 'get_set_of_witness_voters_vests()' #22 --- api/backend.sql | 36 ++++++++++++++++++++---------------- 1 file changed, 20 insertions(+), 16 deletions(-) diff --git a/api/backend.sql b/api/backend.sql index e02e18e..6753ed0 100644 --- a/api/backend.sql +++ b/api/backend.sql @@ -387,30 +387,34 @@ BEGIN SELECT acc.name AS account, cab.balance AS account_vests, - hafbe_backend.get_proxied_vests(voters.voter_id) AS proxied_vests, - hafbe_backend.is_voter_proxied(voters.voter_id) AS is_proxied, - voters.operation_id AS operation_id + hafbe_backend.get_proxied_vests(voter_id) AS proxied_vests, + hafbe_backend.is_voter_proxied(voter_id) AS is_proxied, + operation_id FROM ( - SELECT DISTINCT ON (voter_id) - voter_id, approve, operation_id + SELECT + voter_id, operation_id FROM ( - SELECT voter_id, approve, operation_id - FROM hafbe_app.witness_votes - WHERE witness_id = _witness_id - ORDER BY operation_id DESC - ) votes_ordered - ) voters - - JOIN LATERAL ( + SELECT DISTINCT ON (voter_id) + voter_id, approve, operation_id + FROM ( + SELECT voter_id, approve, operation_id + FROM hafbe_app.witness_votes + WHERE witness_id = _witness_id + ORDER BY operation_id DESC + ) votes_ordered + ) voters + WHERE approve IS TRUE + ) approved + + JOIN ( SELECT name, id FROM hive.accounts_view - ) acc ON acc.id = voters.voter_id - JOIN LATERAL ( + ) acc ON acc.id = approved.voter_id + JOIN ( SELECT balance, account FROM btracker_app.current_account_balances WHERE nai = 37 ) cab ON cab.account = acc.name - WHERE voters.approve IS TRUE ) vests ) result; END -- GitLab From b49de611a3dacb21c1a80543f92449787de3cc7e Mon Sep 17 00:00:00 2001 From: kristupas Date: Mon, 1 Aug 2022 11:50:50 +0000 Subject: [PATCH 22/89] Rewritten 'get_set_of_witness_voters()' using JOINS instead of SUB-Q #22 --- api/backend.sql | 162 ++++++++++++++++++++---------------------------- 1 file changed, 68 insertions(+), 94 deletions(-) diff --git a/api/backend.sql b/api/backend.sql index 6753ed0..fe24c32 100644 --- a/api/backend.sql +++ b/api/backend.sql @@ -173,7 +173,7 @@ END $$ ; -CREATE OR REPLACE FUNCTION hafbe_backend.get_trx_hash(_block_num INT, _trx_in_block INT) +CREATE FUNCTION hafbe_backend.get_trx_hash(_block_num INT, _trx_in_block INT) RETURNS TEXT LANGUAGE 'plpgsql' AS @@ -249,7 +249,7 @@ SET join_collapse_limit=16 SET from_collapse_limit=16 ; -CREATE OR REPLACE FUNCTION hafbe_backend.get_ops_by_account(_account_id INT, _top_op_id BIGINT, _limit BIGINT, _filter SMALLINT[], _date_start TIMESTAMP, _date_end TIMESTAMP) +CREATE FUNCTION hafbe_backend.get_ops_by_account(_account_id INT, _top_op_id BIGINT, _limit BIGINT, _filter SMALLINT[], _date_start TIMESTAMP, _date_end TIMESTAMP) RETURNS JSON LANGUAGE 'plpgsql' AS @@ -305,7 +305,7 @@ $$ $$ ; -CREATE OR REPLACE FUNCTION hafbe_backend.get_set_of_ops_by_block(_block_num INT, _top_op_id BIGINT, _limit BIGINT, _filter SMALLINT[]) +CREATE FUNCTION hafbe_backend.get_set_of_ops_by_block(_block_num INT, _top_op_id BIGINT, _limit BIGINT, _filter SMALLINT[]) RETURNS SETOF hafbe_backend.operations AS $function$ @@ -343,7 +343,7 @@ SET join_collapse_limit=16 SET from_collapse_limit=16 ; -CREATE OR REPLACE FUNCTION hafbe_backend.get_ops_by_block(_block_num INT, _top_op_id BIGINT, _limit BIGINT, _filter SMALLINT[]) +CREATE FUNCTION hafbe_backend.get_ops_by_block(_block_num INT, _top_op_id BIGINT, _limit BIGINT, _filter SMALLINT[]) RETURNS JSON LANGUAGE 'plpgsql' AS @@ -358,92 +358,66 @@ END $$ ; -CREATE TYPE hafbe_backend.witness_voters_vests AS ( +CREATE TYPE hafbe_backend.witness_voters AS ( account TEXT, vests NUMERIC, - account_vests NUMERIC, + account_vests BIGINT, proxied_vests NUMERIC, - operation_id BIGINT + operation_id BIGINT, + timestamp TIMESTAMP ); -CREATE FUNCTION hafbe_backend.get_set_of_witness_voters_vests(_witness_id INT) -RETURNS SETOF hafbe_backend.witness_voters_vests +CREATE FUNCTION hafbe_backend.get_set_of_witness_voters(_witness_id INT, _get_timestamp BOOLEAN = FALSE) +RETURNS SETOF hafbe_backend.witness_voters AS $function$ BEGIN RETURN QUERY SELECT - account::TEXT, - (account_vests + proxied_vests)::NUMERIC AS vests, - account_vests::NUMERIC, - proxied_vests::NUMERIC, - operation_id + acc.name::TEXT AS account, + CASE WHEN cab.balance IS NULL THEN 0 ELSE cab.balance END + proxied_vests AS vests, + CASE WHEN cab.balance IS NULL THEN 0 ELSE cab.balance END AS account_vests, + proxied_vests, + operation_id, + timestamp FROM ( SELECT - account, - CASE WHEN is_proxied IS TRUE THEN 0 ELSE account_vests END AS account_vests, - proxied_vests, - operation_id + voter_id, operation_id FROM ( SELECT - acc.name AS account, - cab.balance AS account_vests, - hafbe_backend.get_proxied_vests(voter_id) AS proxied_vests, - hafbe_backend.is_voter_proxied(voter_id) AS is_proxied, - operation_id - FROM ( - SELECT - voter_id, operation_id - FROM ( - SELECT DISTINCT ON (voter_id) - voter_id, approve, operation_id - FROM ( - SELECT voter_id, approve, operation_id - FROM hafbe_app.witness_votes - WHERE witness_id = _witness_id - ORDER BY operation_id DESC - ) votes_ordered - ) voters - WHERE approve IS TRUE - ) approved - - JOIN ( - SELECT name, id - FROM hive.accounts_view - ) acc ON acc.id = approved.voter_id - JOIN ( - SELECT balance, account - FROM btracker_app.current_account_balances - WHERE nai = 37 - ) cab ON cab.account = acc.name - ) vests - ) result; -END -$function$ -LANGUAGE 'plpgsql' STABLE -SET JIT=OFF -SET join_collapse_limit=16 -SET from_collapse_limit=16 -; + ROW_NUMBER() OVER (PARTITION BY voter_id ORDER BY operation_id DESC) AS row_n, + voter_id, approve, operation_id + FROM hafbe_app.witness_votes + WHERE witness_id = _witness_id + ) row_count + WHERE row_n = 1 AND approve = TRUE + ) prox -CREATE TYPE hafbe_backend.witness_voters AS ( - account TEXT, - vests NUMERIC, - account_vests NUMERIC, - proxied_vests NUMERIC, - timestamp TIMESTAMP -); + JOIN LATERAL ( + SELECT proxied_vests + FROM hafbe_backend.get_proxied_vests(voter_id) + ) prox_vests ON TRUE + + JOIN ( + SELECT name, id + FROM hive.accounts_view + ) acc ON acc.id = prox.voter_id -CREATE FUNCTION hafbe_backend.get_set_of_witness_voters(_witness_id INT) -RETURNS SETOF hafbe_backend.witness_voters -AS -$function$ -BEGIN - RETURN QUERY SELECT account, vests, account_vests, proxied_vests, hov.timestamp - FROM hafbe_backend.get_set_of_witness_voters_vests(_witness_id) JOIN LATERAL ( - SELECT timestamp, id + SELECT proxied + FROM hafbe_backend.is_voter_proxied(voter_id) + ) is_prox ON TRUE + + LEFT JOIN LATERAL ( + SELECT balance + FROM btracker_app.current_account_balances cab + WHERE nai = 37 AND acc.name = account + ) cab ON proxied = FALSE + + LEFT JOIN LATERAL ( + SELECT timestamp FROM hive.operations_view - ) hov ON hov.id = operation_id; + WHERE id = operation_id + ) hov ON _get_timestamp = TRUE; END $function$ LANGUAGE 'plpgsql' STABLE @@ -452,7 +426,7 @@ SET join_collapse_limit=16 SET from_collapse_limit=16 ; -CREATE OR REPLACE FUNCTION hafbe_backend.get_witness_voters_ordered(_witness_id INT, _limit INT, _order_by TEXT, _order_is TEXT) +CREATE FUNCTION hafbe_backend.get_witness_voters_ordered(_witness_id INT, _limit INT, _order_by TEXT, _order_is TEXT) RETURNS SETOF hafbe_backend.witness_voters LANGUAGE 'plpgsql' AS @@ -460,8 +434,8 @@ $$ BEGIN RETURN QUERY EXECUTE format( $query$ - SELECT account, vests, account_vests, proxied_vests, timestamp - FROM hafbe_backend.get_set_of_witness_voters(%L) + SELECT account, vests, account_vests, proxied_vests, 0::BIGINT, timestamp + FROM hafbe_backend.get_set_of_witness_voters(%L, TRUE) ORDER BY (CASE WHEN %L = 'desc' THEN %I ELSE NULL END) DESC, (CASE WHEN %L = 'asc' THEN %I ELSE NULL END) ASC @@ -472,7 +446,7 @@ END $$ ; -CREATE OR REPLACE FUNCTION hafbe_backend.get_witness_voters(_witness_id INT, _limit INT, _order_by TEXT, _order_is TEXT) +CREATE FUNCTION hafbe_backend.get_witness_voters(_witness_id INT, _limit INT, _order_by TEXT, _order_is TEXT) RETURNS JSON LANGUAGE 'plpgsql' AS @@ -487,7 +461,7 @@ END $$ ; -CREATE OR REPLACE FUNCTION hafbe_backend.was_acc_unproxied(_account_id INT, _proxy_id INT, _operation_id BIGINT) +CREATE FUNCTION hafbe_backend.was_acc_unproxied(_account_id INT, _proxy_id INT, _operation_id BIGINT) RETURNS TABLE ( one INT ) @@ -503,9 +477,9 @@ END $$ ; -CREATE OR REPLACE FUNCTION hafbe_backend.get_proxied_vests(_voter_id INT) +CREATE FUNCTION hafbe_backend.get_proxied_vests(_voter_id INT) RETURNS TABLE ( - _balance NUMERIC + proxied_vests NUMERIC ) AS $function$ @@ -544,7 +518,7 @@ SET join_collapse_limit=16 SET from_collapse_limit=16 ; -CREATE OR REPLACE FUNCTION hafbe_backend.is_voter_proxied(_voter_id INT) +CREATE FUNCTION hafbe_backend.is_voter_proxied(_voter_id INT) RETURNS TABLE ( proxied BOOLEAN ) @@ -586,7 +560,7 @@ CREATE TYPE hafbe_backend.witnesses AS ( version TEXT ); -CREATE OR REPLACE FUNCTION hafbe_backend.get_set_of_witnesses(_limit INT) +CREATE FUNCTION hafbe_backend.get_set_of_witnesses(_limit INT) RETURNS SETOF hafbe_backend.witnesses AS $function$ @@ -650,7 +624,7 @@ SET join_collapse_limit=16 SET from_collapse_limit=16 ; -CREATE OR REPLACE FUNCTION hafbe_backend.get_witnesses(_limit INT) +CREATE FUNCTION hafbe_backend.get_witnesses(_limit INT) RETURNS JSON LANGUAGE 'plpgsql' AS @@ -665,7 +639,7 @@ END $$ ; -CREATE OR REPLACE FUNCTION hafbe_backend.get_witness_votes_stats(_witness_id INT, _first_op_today BIGINT = 9223372036854775807) +CREATE FUNCTION hafbe_backend.get_witness_votes_stats(_witness_id INT, _first_op_today BIGINT = 9223372036854775807) RETURNS JSON AS $function$ @@ -674,7 +648,7 @@ BEGIN SELECT SUM(vests) AS votes, COUNT(*) AS voters_num - FROM hafbe_backend.get_set_of_witness_voters_vests(_witness_id) + FROM hafbe_backend.get_set_of_witness_voters(_witness_id) WHERE operation_id < _first_op_today ) result; END @@ -685,7 +659,7 @@ SET join_collapse_limit=16 SET from_collapse_limit=16 ; -CREATE OR REPLACE FUNCTION hafbe_backend.latest_op_id() +CREATE FUNCTION hafbe_backend.latest_op_id() RETURNS JSON LANGUAGE 'plpgsql' AS @@ -696,7 +670,7 @@ END $$ ; -CREATE OR REPLACE FUNCTION hafbe_backend.parse_witness_set_props(_op_value JSON, _attr_name TEXT) +CREATE FUNCTION hafbe_backend.parse_witness_set_props(_op_value JSON, _attr_name TEXT) RETURNS TEXT LANGUAGE 'plpgsql' AS @@ -711,7 +685,7 @@ END $$ ; -CREATE OR REPLACE FUNCTION hafbe_backend.unpack_from_vector(_vector TEXT) +CREATE FUNCTION hafbe_backend.unpack_from_vector(_vector TEXT) RETURNS TEXT LANGUAGE 'plpgsql' AS @@ -723,7 +697,7 @@ END $$ ; -CREATE OR REPLACE FUNCTION hafbe_backend.get_witness_url(_witness_id INT, _last_op_id BIGINT = NULL) +CREATE FUNCTION hafbe_backend.get_witness_url(_witness_id INT, _last_op_id BIGINT = NULL) RETURNS JSON AS $function$ @@ -777,7 +751,7 @@ SET join_collapse_limit=16 SET from_collapse_limit=16 ; -CREATE OR REPLACE FUNCTION hafbe_backend.get_witness_block_size(_witness_id INT, _last_op_id BIGINT = NULL) +CREATE FUNCTION hafbe_backend.get_witness_block_size(_witness_id INT, _last_op_id BIGINT = NULL) RETURNS JSON AS $function$ @@ -831,7 +805,7 @@ SET join_collapse_limit=16 SET from_collapse_limit=16 ; -CREATE OR REPLACE FUNCTION hafbe_backend.get_witness_exchange_rate(_witness_id INT, _last_op_id BIGINT = NULL) +CREATE FUNCTION hafbe_backend.get_witness_exchange_rate(_witness_id INT, _last_op_id BIGINT = NULL) RETURNS JSON AS $function$ @@ -887,7 +861,7 @@ SET join_collapse_limit=16 SET from_collapse_limit=16 ; -CREATE OR REPLACE FUNCTION hafbe_backend.get_witness_signing_key(_witness_id INT, _last_op_id BIGINT = NULL) +CREATE FUNCTION hafbe_backend.get_witness_signing_key(_witness_id INT, _last_op_id BIGINT = NULL) RETURNS JSON AS $function$ @@ -941,7 +915,7 @@ SET join_collapse_limit=16 SET from_collapse_limit=16 ; -CREATE OR REPLACE FUNCTION hafbe_backend.get_account(_account TEXT) +CREATE FUNCTION hafbe_backend.get_account(_account TEXT) RETURNS JSON LANGUAGE 'plpython3u' AS @@ -963,7 +937,7 @@ $$ $$ ; -CREATE OR REPLACE FUNCTION hafbe_backend.parse_profile_picture(_account_data JSON, _key TEXT) +CREATE FUNCTION hafbe_backend.parse_profile_picture(_account_data JSON, _key TEXT) RETURNS TEXT LANGUAGE 'plpgsql' AS -- GitLab From 02b12b58454f5a60fd8d853022c649c1f7d28eee Mon Sep 17 00:00:00 2001 From: kristupas Date: Mon, 8 Aug 2022 13:43:04 +0000 Subject: [PATCH 23/89] Chaned 'run.sh' to create indexes CONCURRENTLY #22 --- run.sh | 20 ++++++++++---------- 1 file changed, 10 insertions(+), 10 deletions(-) diff --git a/run.sh b/run.sh index 335082e..cff170c 100755 --- a/run.sh +++ b/run.sh @@ -25,20 +25,20 @@ create_api() { create_indexes() { echo "Creating indexes, this might take a while." - psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "CREATE UNIQUE INDEX IF NOT EXISTS uq_hive_blocks_reversible_hash ON hive.blocks_reversible USING btree (hash, fork_id)" - psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "CREATE UNIQUE INDEX IF NOT EXISTS uq_hive_blocks_hash ON hive.blocks USING btree (hash)" + psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "CREATE UNIQUE INDEX CONCURRENTLY IF NOT EXISTS uq_hive_blocks_reversible_hash ON hive.blocks_reversible USING btree (hash, fork_id)" + psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "CREATE UNIQUE INDEX CONCURRENTLY IF NOT EXISTS uq_hive_blocks_hash ON hive.blocks USING btree (hash)" - psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "CREATE INDEX IF NOT EXISTS hive_operations_reversible_timestamp_id ON hive.operations_reversible USING btree (timestamp, id, fork_id)" - psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "CREATE INDEX IF NOT EXISTS hive_operations_timestamp_id ON hive.operations USING btree (timestamp, id)" + psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "CREATE INDEX CONCURRENTLY IF NOT EXISTS hive_operations_reversible_timestamp_id ON hive.operations_reversible USING btree (timestamp, id, fork_id)" + psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "CREATE INDEX CONCURRENTLY IF NOT EXISTS hive_operations_timestamp_id ON hive.operations USING btree (timestamp, id)" - psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "CREATE UNIQUE INDEX IF NOT EXISTS hive_account_operations_reversible_uq2 ON hive.account_operations_reversible USING btree (account_id, op_type_id, operation_id, fork_id)" - psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "CREATE UNIQUE INDEX IF NOT EXISTS hive_account_operations_uq2 ON hive.account_operations USING btree (account_id, op_type_id, operation_id)" + psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "CREATE UNIQUE INDEX CONCURRENTLY IF NOT EXISTS hive_account_operations_reversible_uq2 ON hive.account_operations_reversible USING btree (account_id, op_type_id, operation_id, fork_id)" + psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "CREATE UNIQUE INDEX CONCURRENTLY IF NOT EXISTS hive_account_operations_uq2 ON hive.account_operations USING btree (account_id, op_type_id, operation_id)" - psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "CREATE INDEX IF NOT EXISTS hive_account_operations_reversible_block_num ON hive.account_operations_reversible USING btree (block_num, fork_id)" - psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "CREATE INDEX IF NOT EXISTS hive_account_operations_block_num ON hive.account_operations USING btree (block_num)" + psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "CREATE INDEX CONCURRENTLY IF NOT EXISTS hive_account_operations_reversible_block_num ON hive.account_operations_reversible USING btree (block_num, fork_id)" + psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "CREATE INDEX CONCURRENTLY IF NOT EXISTS hive_account_operations_block_num ON hive.account_operations USING btree (block_num)" - psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "CREATE INDEX IF NOT EXISTS hive_operations_reversible_timestamp ON hive.operations_reversible USING btree (timestamp, fork_id)" - psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "CREATE INDEX IF NOT EXISTS hive_operations_timestamp ON hive.operations USING btree (timestamp)" + psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "CREATE INDEX CONCURRENTLY IF NOT EXISTS hive_operations_reversible_timestamp ON hive.operations_reversible USING btree (timestamp, fork_id)" + psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "CREATE INDEX CONCURRENTLY IF NOT EXISTS hive_operations_timestamp ON hive.operations USING btree (timestamp)" } start_webserver() { -- GitLab From c46ffff7de24190539a287008bf4a960cdeccbfc Mon Sep 17 00:00:00 2001 From: kristupas Date: Mon, 8 Aug 2022 14:24:57 +0000 Subject: [PATCH 24/89] Added 'hafbe_app.get_account_id()' from 'hafbe_backend' to avoid sync interruptions #22 --- db/hafbe_app.sql | 19 +++++++++++++++---- 1 file changed, 15 insertions(+), 4 deletions(-) diff --git a/db/hafbe_app.sql b/db/hafbe_app.sql index 7a5268b..3a4677d 100644 --- a/db/hafbe_app.sql +++ b/db/hafbe_app.sql @@ -117,6 +117,17 @@ END $$ ; +CREATE FUNCTION hafbe_app.get_account_id(_account TEXT) +RETURNS INT +LANGUAGE 'plpgsql' +AS +$$ +BEGIN + RETURN id FROM hive.accounts_view WHERE name = _account; +END +$$ +; + CREATE OR REPLACE FUNCTION hafbe_app.process_block_range_data_c(_from INT, _to INT, _report_step INT = 1000) RETURNS VOID LANGUAGE 'plpgsql' @@ -132,8 +143,8 @@ BEGIN INSERT INTO hafbe_app.witness_votes (witness_id, voter_id, approve, operation_id) SELECT - hafbe_backend.get_account_id(approve_operation->>'witness'), - hafbe_backend.get_account_id(approve_operation->>'account'), + hafbe_app.get_account_id(approve_operation->>'witness'), + hafbe_app.get_account_id(approve_operation->>'account'), (approve_operation->>'approve')::BOOLEAN, id FROM ( @@ -155,8 +166,8 @@ BEGIN id FROM ( SELECT - hafbe_backend.get_account_id(proxy_operation->>'account') AS account_id, - hafbe_backend.get_account_id(proxy_operation->>'proxy') AS proxy_id, + hafbe_app.get_account_id(proxy_operation->>'account') AS account_id, + hafbe_app.get_account_id(proxy_operation->>'proxy') AS proxy_id, id FROM ( SELECT -- GitLab From 61348c2edf782006c4b09c9899653b3e43a5e804 Mon Sep 17 00:00:00 2001 From: kristupas Date: Mon, 8 Aug 2022 16:10:54 +0000 Subject: [PATCH 25/89] Added 'create-indexes' and 'continue-processing' jobs to 'run.sh' #22 --- api/backend.sql | 79 +++++++++++++++++++++++++++++------------------- db/hafbe_app.sql | 8 ++++- run.sh | 13 +++++++- 3 files changed, 67 insertions(+), 33 deletions(-) diff --git a/api/backend.sql b/api/backend.sql index fe24c32..be96938 100644 --- a/api/backend.sql +++ b/api/backend.sql @@ -363,11 +363,10 @@ CREATE TYPE hafbe_backend.witness_voters AS ( vests NUMERIC, account_vests BIGINT, proxied_vests NUMERIC, - operation_id BIGINT, - timestamp TIMESTAMP + operation_id BIGINT ); -CREATE FUNCTION hafbe_backend.get_set_of_witness_voters(_witness_id INT, _get_timestamp BOOLEAN = FALSE) +CREATE FUNCTION hafbe_backend.get_set_of_witness_voters(_witness_id INT) RETURNS SETOF hafbe_backend.witness_voters AS $function$ @@ -377,8 +376,7 @@ BEGIN CASE WHEN cab.balance IS NULL THEN 0 ELSE cab.balance END + proxied_vests AS vests, CASE WHEN cab.balance IS NULL THEN 0 ELSE cab.balance END AS account_vests, proxied_vests, - operation_id, - timestamp + operation_id FROM ( SELECT voter_id, operation_id @@ -397,27 +395,22 @@ BEGIN FROM hafbe_backend.get_proxied_vests(voter_id) ) prox_vests ON TRUE - JOIN ( - SELECT name, id + JOIN LATERAL ( + SELECT name FROM hive.accounts_view - ) acc ON acc.id = prox.voter_id + WHERE id = prox.voter_id + ) acc ON TRUE JOIN LATERAL ( SELECT proxied - FROM hafbe_backend.is_voter_proxied(voter_id) + FROM hafbe_backend.is_voter_proxied(voter_id, _witness_id) ) is_prox ON TRUE LEFT JOIN LATERAL ( SELECT balance FROM btracker_app.current_account_balances cab - WHERE nai = 37 AND acc.name = account - ) cab ON proxied = FALSE - - LEFT JOIN LATERAL ( - SELECT timestamp - FROM hive.operations_view - WHERE id = operation_id - ) hov ON _get_timestamp = TRUE; + WHERE account = acc.name AND nai = 37 + ) cab ON proxied = FALSE; END $function$ LANGUAGE 'plpgsql' STABLE @@ -426,16 +419,30 @@ SET join_collapse_limit=16 SET from_collapse_limit=16 ; +CREATE TYPE hafbe_backend.witness_voters_history AS ( + account TEXT, + vests NUMERIC, + account_vests BIGINT, + proxied_vests NUMERIC, + timestamp TIMESTAMP +); + CREATE FUNCTION hafbe_backend.get_witness_voters_ordered(_witness_id INT, _limit INT, _order_by TEXT, _order_is TEXT) -RETURNS SETOF hafbe_backend.witness_voters +RETURNS SETOF hafbe_backend.witness_voters_history LANGUAGE 'plpgsql' AS $$ BEGIN RETURN QUERY EXECUTE format( $query$ - SELECT account, vests, account_vests, proxied_vests, 0::BIGINT, timestamp - FROM hafbe_backend.get_set_of_witness_voters(%L, TRUE) + SELECT account, vests, account_vests, proxied_vests, hov.timestamp + FROM hafbe_backend.get_set_of_witness_voters(%L) + + JOIN LATERAL ( + SELECT timestamp + FROM hive.operations_view + WHERE id = operation_id + ) hov ON TRUE ORDER BY (CASE WHEN %L = 'desc' THEN %I ELSE NULL END) DESC, (CASE WHEN %L = 'asc' THEN %I ELSE NULL END) ASC @@ -461,15 +468,15 @@ END $$ ; -CREATE FUNCTION hafbe_backend.was_acc_unproxied(_account_id INT, _proxy_id INT, _operation_id BIGINT) +CREATE FUNCTION hafbe_backend.get_acc_unproxy_op(_account_id INT, _proxy_id INT, _operation_id BIGINT) RETURNS TABLE ( - one INT + _unprox_op_id BIGINT ) LANGUAGE 'plpgsql' AS $$ BEGIN - RETURN QUERY SELECT 1 + RETURN QUERY SELECT operation_id FROM hafbe_app.account_proxies WHERE account_id = _account_id AND proxy_id = _proxy_id AND proxy IS FALSE AND operation_id > _operation_id LIMIT 1; @@ -508,7 +515,7 @@ BEGIN ORDER BY operation_id DESC ) proxy_ops ) ap ON ap.account_id = hav.id - WHERE (SELECT hafbe_backend.was_acc_unproxied(ap.account_id, ap.proxy_id, ap.operation_id)) IS NULL AND cab.nai = 37 + WHERE (SELECT hafbe_backend.get_acc_unproxy_op(ap.account_id, ap.proxy_id, ap.operation_id)) IS NULL AND cab.nai = 37 ) is_null; END $function$ @@ -518,7 +525,7 @@ SET join_collapse_limit=16 SET from_collapse_limit=16 ; -CREATE FUNCTION hafbe_backend.is_voter_proxied(_voter_id INT) +CREATE FUNCTION hafbe_backend.is_voter_proxied(_voter_id INT, _witness_id INT) RETURNS TABLE ( proxied BOOLEAN ) @@ -530,11 +537,15 @@ BEGIN FROM ( SELECT account_id, proxy_id, operation_id FROM hafbe_app.account_proxies - WHERE account_id = _voter_id AND proxy IS TRUE + WHERE proxy_id = _witness_id AND account_id = _voter_id AND proxy IS TRUE ORDER BY operation_id DESC LIMIT 1 ) ap - WHERE (SELECT hafbe_backend.was_acc_unproxied(ap.account_id, ap.proxy_id, ap.operation_id)) IS NULL + JOIN LATERAL ( + SELECT _unprox_op_id + FROM hafbe_backend.get_acc_unproxy_op(account_id, proxy_id, operation_id) + WHERE _unprox_op_id IS NULL + ) unprox ON TRUE ) IS NOT NULL THEN TRUE ELSE FALSE END; END @@ -640,14 +651,20 @@ $$ ; CREATE FUNCTION hafbe_backend.get_witness_votes_stats(_witness_id INT, _first_op_today BIGINT = 9223372036854775807) -RETURNS JSON +RETURNS TABLE ( + votes NUMERIC, + voters_num INT +) AS $function$ BEGIN - RETURN to_json(result) FROM ( + RETURN QUERY SELECT + CASE WHEN votes IS NULL THEN 0 ELSE votes END, + voters_num + FROM ( SELECT - SUM(vests) AS votes, - COUNT(*) AS voters_num + SUM(vests)::NUMERIC AS votes, + COUNT(*)::INT AS voters_num FROM hafbe_backend.get_set_of_witness_voters(_witness_id) WHERE operation_id < _first_op_today ) result; diff --git a/db/hafbe_app.sql b/db/hafbe_app.sql index 3a4677d..f646219 100644 --- a/db/hafbe_app.sql +++ b/db/hafbe_app.sql @@ -36,6 +36,8 @@ BEGIN CREATE INDEX IF NOT EXISTS account_proxies_account_id ON hafbe_app.account_proxies USING btree (account_id); CREATE INDEX IF NOT EXISTS account_proxies_proxy_id ON hafbe_app.account_proxies USING btree (proxy_id); CREATE INDEX IF NOT EXISTS account_proxies_operation_id ON hafbe_app.account_proxies USING btree (operation_id); + CREATE INDEX IF NOT EXISTS account_proxies_operation_id_account_id_proxy ON hafbe_app.account_proxies USING btree (operation_id, account_id, proxy); + CREATE INDEX IF NOT EXISTS account_proxies_proxy_id_account_id_proxy ON hafbe_app.account_proxies USING btree (proxy_id, account_id, proxy); CREATE TABLE IF NOT EXISTS hafbe_app.hived_account_cache ( account TEXT NOT NULL, @@ -284,7 +286,7 @@ $$ - creates HAF application context, - starts application main-loop (which iterates infinitely). To stop it call `hafbe_app.stopProcessing();` from another session and commit its trasaction. */ -CREATE OR REPLACE PROCEDURE hafbe_app.main(_appContext VARCHAR, _maxBlockLimit INT = 0) +CREATE OR REPLACE PROCEDURE hafbe_app.main(_appContext VARCHAR, _maxBlockLimit INT = NULLy) LANGUAGE 'plpgsql' AS $$ @@ -312,6 +314,10 @@ BEGIN RAISE NOTICE 'Entering application main loop...'; + IF _maxBlockLimit IS NULL THEN + _maxBlockLimit = 2147483647; + END IF; + WHILE hafbe_app.continueProcessing() AND (_maxBlockLimit = 0 OR __last_block < _maxBlockLimit) LOOP __next_block_range := hive.app_next_block(_appContext); diff --git a/run.sh b/run.sh index cff170c..7552fe3 100755 --- a/run.sh +++ b/run.sh @@ -9,8 +9,12 @@ drop_db() { } create_db() { - n_blocks=$1 psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -f db/hafbe_app.sql + process_blocks $@ +} + +process_blocks() { + n_blocks="${1:-null}" psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "CALL hafbe_app.main('$hive_app_name', $n_blocks);" } @@ -23,6 +27,7 @@ create_api() { } create_indexes() { + # creating indexes CONCURRENTLY inside sql function is not allowed, they must be created from script echo "Creating indexes, this might take a while." psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "CREATE UNIQUE INDEX CONCURRENTLY IF NOT EXISTS uq_hive_blocks_reversible_hash ON hive.blocks_reversible USING btree (hash, fork_id)" @@ -39,6 +44,8 @@ create_indexes() { psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "CREATE INDEX CONCURRENTLY IF NOT EXISTS hive_operations_reversible_timestamp ON hive.operations_reversible USING btree (timestamp, fork_id)" psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "CREATE INDEX CONCURRENTLY IF NOT EXISTS hive_operations_timestamp ON hive.operations USING btree (timestamp)" + + psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "CREATE INDEX CONCURRENTLY IF NOT EXISTS btracker_app_account_current_account_balances_nai ON btracker_app.current_account_balances(nai)" } start_webserver() { @@ -117,6 +124,10 @@ elif [ "$1" = "re-start" ]; then create_indexes echo 'SUCCESS: Users and API recreated' start_webserver $2 +elif [ "$1" = "create-indexes" ]; then + create_indexes +elif [ "$1" = "continue-processing" ]; then + create_indexes elif [ "$1" = "install-postgrest" ]; then install_postgrest elif [ "$1" = "install-plpython" ]; then -- GitLab From 00c75acd0d6922cfbbe592e2707b9bc0935b4f3e Mon Sep 17 00:00:00 2001 From: kristupas Date: Tue, 9 Aug 2022 11:30:31 +0000 Subject: [PATCH 26/89] Changed helper function to joins #22 --- api/backend.sql | 123 ++++++++++++++++++----------------------------- db/hafbe_app.sql | 2 - 2 files changed, 48 insertions(+), 77 deletions(-) diff --git a/api/backend.sql b/api/backend.sql index be96938..cf2371c 100644 --- a/api/backend.sql +++ b/api/backend.sql @@ -372,7 +372,7 @@ AS $function$ BEGIN RETURN QUERY SELECT - acc.name::TEXT AS account, + hav.name::TEXT AS account, CASE WHEN cab.balance IS NULL THEN 0 ELSE cab.balance END + proxied_vests AS vests, CASE WHEN cab.balance IS NULL THEN 0 ELSE cab.balance END AS account_vests, proxied_vests, @@ -388,29 +388,28 @@ BEGIN WHERE witness_id = _witness_id ) row_count WHERE row_n = 1 AND approve = TRUE - ) prox + ) wv JOIN LATERAL ( SELECT proxied_vests FROM hafbe_backend.get_proxied_vests(voter_id) ) prox_vests ON TRUE - JOIN LATERAL ( - SELECT name - FROM hive.accounts_view - WHERE id = prox.voter_id - ) acc ON TRUE - JOIN LATERAL ( SELECT proxied - FROM hafbe_backend.is_voter_proxied(voter_id, _witness_id) + FROM hafbe_backend.is_voter_proxied(voter_id) ) is_prox ON TRUE - LEFT JOIN LATERAL ( - SELECT balance - FROM btracker_app.current_account_balances cab - WHERE account = acc.name AND nai = 37 - ) cab ON proxied = FALSE; + JOIN ( + SELECT name, id + FROM hive.accounts_view + ) hav ON hav.id = voter_id + + LEFT JOIN ( + SELECT balance, account + FROM btracker_app.current_account_balances + WHERE nai = 37 + ) cab ON is_prox.proxied IS FALSE AND cab.account = hav.name; END $function$ LANGUAGE 'plpgsql' STABLE @@ -468,55 +467,22 @@ END $$ ; -CREATE FUNCTION hafbe_backend.get_acc_unproxy_op(_account_id INT, _proxy_id INT, _operation_id BIGINT) -RETURNS TABLE ( - _unprox_op_id BIGINT -) -LANGUAGE 'plpgsql' -AS -$$ -BEGIN - RETURN QUERY SELECT operation_id - FROM hafbe_app.account_proxies - WHERE account_id = _account_id AND proxy_id = _proxy_id AND proxy IS FALSE AND operation_id > _operation_id - LIMIT 1; -END -$$ -; - -CREATE FUNCTION hafbe_backend.get_proxied_vests(_voter_id INT) +CREATE FUNCTION hafbe_backend.is_voter_proxied(_voter_id INT) RETURNS TABLE ( - proxied_vests NUMERIC + proxied BOOLEAN ) AS $function$ BEGIN - RETURN QUERY SELECT CASE WHEN balance IS NULL THEN 0 ELSE balance END + RETURN QUERY SELECT proxy FROM ( - SELECT SUM(cab.balance) AS balance - FROM ( - SELECT - CASE WHEN balance < 0 THEN 0 ELSE balance END, - account, - nai - FROM btracker_app.current_account_balances - ) cab - JOIN LATERAL ( - SELECT name, id - FROM hive.accounts_view - ) hav ON hav.name = cab.account - JOIN LATERAL ( - SELECT DISTINCT ON (account_id) - account_id, proxy_id, operation_id - FROM ( - SELECT account_id, proxy_id, operation_id - FROM hafbe_app.account_proxies - WHERE proxy_id = _voter_id AND proxy IS TRUE - ORDER BY operation_id DESC - ) proxy_ops - ) ap ON ap.account_id = hav.id - WHERE (SELECT hafbe_backend.get_acc_unproxy_op(ap.account_id, ap.proxy_id, ap.operation_id)) IS NULL AND cab.nai = 37 - ) is_null; + SELECT + ROW_NUMBER() OVER (PARTITION BY account_id ORDER BY operation_id DESC) AS row_n, + proxy + FROM hafbe_app.account_proxies + WHERE account_id = _voter_id + ) row_count + WHERE row_n = 1; END $function$ LANGUAGE 'plpgsql' STABLE @@ -525,29 +491,36 @@ SET join_collapse_limit=16 SET from_collapse_limit=16 ; -CREATE FUNCTION hafbe_backend.is_voter_proxied(_voter_id INT, _witness_id INT) +CREATE FUNCTION hafbe_backend.get_proxied_vests(_voter_id INT) RETURNS TABLE ( - proxied BOOLEAN + proxied_vests NUMERIC ) AS $function$ BEGIN - RETURN QUERY SELECT CASE WHEN ( - SELECT proxy_id - FROM ( - SELECT account_id, proxy_id, operation_id - FROM hafbe_app.account_proxies - WHERE proxy_id = _witness_id AND account_id = _voter_id AND proxy IS TRUE - ORDER BY operation_id DESC - LIMIT 1 - ) ap - JOIN LATERAL ( - SELECT _unprox_op_id - FROM hafbe_backend.get_acc_unproxy_op(account_id, proxy_id, operation_id) - WHERE _unprox_op_id IS NULL - ) unprox ON TRUE - ) - IS NOT NULL THEN TRUE ELSE FALSE END; + RETURN QUERY SELECT (SUM(cab.balance))::NUMERIC + FROM ( + SELECT + ROW_NUMBER() OVER (PARTITION BY account_id ORDER BY operation_id DESC) AS row_n, + account_id, proxy, operation_id + FROM hafbe_app.account_proxies + WHERE proxy_id = _voter_id + ) row_count + + JOIN ( + SELECT name, id + FROM hive.accounts_view + ) hav ON hav.id = account_id + + JOIN ( + SELECT + CASE WHEN balance < 0 THEN 0 ELSE balance END AS balance, + account + FROM btracker_app.current_account_balances cab + WHERE nai = 37 + ) cab ON cab.account = hav.name + + WHERE row_n = 1 AND proxy = TRUE; END $function$ LANGUAGE 'plpgsql' STABLE diff --git a/db/hafbe_app.sql b/db/hafbe_app.sql index f646219..a6c59ea 100644 --- a/db/hafbe_app.sql +++ b/db/hafbe_app.sql @@ -36,8 +36,6 @@ BEGIN CREATE INDEX IF NOT EXISTS account_proxies_account_id ON hafbe_app.account_proxies USING btree (account_id); CREATE INDEX IF NOT EXISTS account_proxies_proxy_id ON hafbe_app.account_proxies USING btree (proxy_id); CREATE INDEX IF NOT EXISTS account_proxies_operation_id ON hafbe_app.account_proxies USING btree (operation_id); - CREATE INDEX IF NOT EXISTS account_proxies_operation_id_account_id_proxy ON hafbe_app.account_proxies USING btree (operation_id, account_id, proxy); - CREATE INDEX IF NOT EXISTS account_proxies_proxy_id_account_id_proxy ON hafbe_app.account_proxies USING btree (proxy_id, account_id, proxy); CREATE TABLE IF NOT EXISTS hafbe_app.hived_account_cache ( account TEXT NOT NULL, -- GitLab From e223bfb296c51634956e6612db4ae0b7f96d77bb Mon Sep 17 00:00:00 2001 From: kristupas Date: Tue, 9 Aug 2022 20:03:09 +0000 Subject: [PATCH 27/89] Created 'hafbe_app.account_vests' as alternative to btracker table #22 --- api/backend.sql | 29 ++++++--------- db/hafbe_app.sql | 91 +++++++++++++++++++++++++++++++----------------- run.sh | 2 -- 3 files changed, 70 insertions(+), 52 deletions(-) diff --git a/api/backend.sql b/api/backend.sql index cf2371c..f170b3b 100644 --- a/api/backend.sql +++ b/api/backend.sql @@ -373,8 +373,8 @@ $function$ BEGIN RETURN QUERY SELECT hav.name::TEXT AS account, - CASE WHEN cab.balance IS NULL THEN 0 ELSE cab.balance END + proxied_vests AS vests, - CASE WHEN cab.balance IS NULL THEN 0 ELSE cab.balance END AS account_vests, + CASE WHEN av.vests IS NULL THEN 0 ELSE av.vests END + proxied_vests AS vests, + CASE WHEN av.vests IS NULL THEN 0 ELSE av.vests END AS account_vests, proxied_vests, operation_id FROM ( @@ -406,10 +406,9 @@ BEGIN ) hav ON hav.id = voter_id LEFT JOIN ( - SELECT balance, account - FROM btracker_app.current_account_balances - WHERE nai = 37 - ) cab ON is_prox.proxied IS FALSE AND cab.account = hav.name; + SELECT account_id, vests + FROM hafbe_app.account_vests + ) av ON is_prox.proxied IS FALSE AND av.account_id = voter_id; END $function$ LANGUAGE 'plpgsql' STABLE @@ -498,27 +497,19 @@ RETURNS TABLE ( AS $function$ BEGIN - RETURN QUERY SELECT (SUM(cab.balance))::NUMERIC + RETURN QUERY SELECT (SUM(av.vests))::NUMERIC FROM ( SELECT ROW_NUMBER() OVER (PARTITION BY account_id ORDER BY operation_id DESC) AS row_n, account_id, proxy, operation_id - FROM hafbe_app.account_proxies + FROM hafbe_app.account_proxies ap WHERE proxy_id = _voter_id ) row_count JOIN ( - SELECT name, id - FROM hive.accounts_view - ) hav ON hav.id = account_id - - JOIN ( - SELECT - CASE WHEN balance < 0 THEN 0 ELSE balance END AS balance, - account - FROM btracker_app.current_account_balances cab - WHERE nai = 37 - ) cab ON cab.account = hav.name + SELECT account_id, vests + FROM hafbe_app.account_vests + ) av ON av.account_id = row_count.account_id WHERE row_n = 1 AND proxy = TRUE; END diff --git a/db/hafbe_app.sql b/db/hafbe_app.sql index a6c59ea..137e3d1 100644 --- a/db/hafbe_app.sql +++ b/db/hafbe_app.sql @@ -55,6 +55,13 @@ BEGIN CREATE INDEX IF NOT EXISTS account_operation_cache_account_id ON hafbe_app.account_operation_cache USING btree (account_id); CREATE INDEX IF NOT EXISTS account_operation_cache_op_type_id ON hafbe_app.account_operation_cache USING btree (op_type_id); + CREATE TABLE IF NOT EXISTS hafbe_app.account_vests ( + account_id INT NOT NULL, + vests BIGINT NOT NULL, + + CONSTRAINT pk_account_vests_account PRIMARY KEY (account_id) + ) INHERITS (hive.hafbe_app); + --ALTER SCHEMA hafbe_app OWNER TO hafbe_owner; END $$ @@ -117,13 +124,13 @@ END $$ ; -CREATE FUNCTION hafbe_app.get_account_id(_account TEXT) +CREATE OR REPLACE FUNCTION hafbe_app.get_account_id(_account TEXT) RETURNS INT LANGUAGE 'plpgsql' AS $$ BEGIN - RETURN id FROM hive.accounts_view WHERE name = _account; + RETURN id FROM hive.btracker_app_accounts_view WHERE name = _account; END $$ ; @@ -137,10 +144,10 @@ DECLARE __last_reported_block INT := 0; __unproxy_op RECORD; __last_op_id BIGINT; + __balance_change RECORD; BEGIN FOR b IN _from .. _to LOOP - INSERT INTO hafbe_app.witness_votes (witness_id, voter_id, approve, operation_id) SELECT hafbe_app.get_account_id(approve_operation->>'witness'), @@ -151,7 +158,7 @@ BEGIN SELECT (body::JSON)->'value' AS approve_operation, id - FROM hive.operations_view + FROM hive.btracker_app_operations_view WHERE op_type_id = 12 AND block_num = b ) hov ON CONFLICT DO NOTHING; @@ -173,43 +180,65 @@ BEGIN SELECT (body::JSON)->'value' AS proxy_operation, id - FROM hive.operations_view + FROM hive.btracker_app_operations_view WHERE op_type_id = 13 AND block_num = b ) hov ) acc_ids ON CONFLICT DO NOTHING; - - -- postprocessing to fill null values of proxy_id when account does unproxy - FOR __unproxy_op IN - SELECT account_id, operation_id - FROM hafbe_app.account_proxies - WHERE operation_id > __last_op_id AND proxy_id IS NULL - LOOP - UPDATE hafbe_app.account_proxies - SET proxy_id = (SELECT proxy_id - FROM hafbe_app.account_proxies - WHERE operation_id < __unproxy_op.operation_id AND account_id = __unproxy_op.account_id AND proxy_id IS NOT NULL - ORDER BY operation_id DESC - LIMIT 1) - WHERE account_id = __unproxy_op.account_id AND proxy_id IS NULL; - END LOOP; - - + INSERT INTO hafbe_app.account_operation_cache (uq_key, account_id, op_type_id) SELECT account_id::TEXT || '-' || op_type_id::TEXT, account_id, op_type_id - FROM hive.account_operations_view haov + FROM hive.btracker_app_account_operations_view haov WHERE block_num = b ON CONFLICT DO NOTHING; - - /* - IF __balance_change.source_op_block % _report_step = 0 AND __last_reported_block != __balance_change.source_op_block THEN - RAISE NOTICE 'Processed data for block: %', __balance_change.source_op_block; - __last_reported_block := __balance_change.source_op_block; - END IF; - */ + END LOOP; + + -- postprocessing to fill null values of proxy_id when account does unproxy + FOR __unproxy_op IN + SELECT account_id, operation_id + FROM hafbe_app.account_proxies + WHERE operation_id > __last_op_id AND proxy_id IS NULL + LOOP + UPDATE hafbe_app.account_proxies + SET proxy_id = ( + SELECT proxy_id + FROM hafbe_app.account_proxies + WHERE operation_id < __unproxy_op.operation_id AND account_id = __unproxy_op.account_id AND proxy_id IS NOT NULL + ORDER BY operation_id DESC + LIMIT 1 + ) + WHERE account_id = __unproxy_op.account_id AND proxy_id IS NULL; + END LOOP; + + FOR __balance_change IN + WITH balance_impacting_ops AS ( + SELECT hot.id + FROM hive.operation_types hot + WHERE hot.name IN (SELECT * FROM hive.get_balance_impacting_operations()) + ) + + SELECT bio.account_name AS account, bio.amount AS vests + FROM hive.btracker_app_operations_view hov + JOIN balance_impacting_ops b ON hov.op_type_id = b.id + JOIN LATERAL ( + SELECT account_name, amount + FROM hive.get_impacted_balances(hov.body, TRUE) -- TODO: lookout for hardfork op + WHERE asset_symbol_nai = 37 + ) bio ON TRUE + WHERE hov.block_num BETWEEN _from AND _to + ORDER BY hov.block_num, hov.id + + LOOP + INSERT INTO hafbe_app.account_vests (account_id, vests) + SELECT hav.id, __balance_change.vests + FROM hive.btracker_app_accounts_view hav + WHERE hav.name = __balance_change.account + + ON CONFLICT ON CONSTRAINT pk_account_vests_account DO + UPDATE SET vests = hafbe_app.account_vests.vests + EXCLUDED.vests; END LOOP; END $$ @@ -284,7 +313,7 @@ $$ - creates HAF application context, - starts application main-loop (which iterates infinitely). To stop it call `hafbe_app.stopProcessing();` from another session and commit its trasaction. */ -CREATE OR REPLACE PROCEDURE hafbe_app.main(_appContext VARCHAR, _maxBlockLimit INT = NULLy) +CREATE OR REPLACE PROCEDURE hafbe_app.main(_appContext VARCHAR, _maxBlockLimit INT = NULL) LANGUAGE 'plpgsql' AS $$ diff --git a/run.sh b/run.sh index 7552fe3..cef1cd6 100755 --- a/run.sh +++ b/run.sh @@ -44,8 +44,6 @@ create_indexes() { psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "CREATE INDEX CONCURRENTLY IF NOT EXISTS hive_operations_reversible_timestamp ON hive.operations_reversible USING btree (timestamp, fork_id)" psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "CREATE INDEX CONCURRENTLY IF NOT EXISTS hive_operations_timestamp ON hive.operations USING btree (timestamp)" - - psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "CREATE INDEX CONCURRENTLY IF NOT EXISTS btracker_app_account_current_account_balances_nai ON btracker_app.current_account_balances(nai)" } start_webserver() { -- GitLab From 448d21b50768411faf0beed3d55d03843d1d7400 Mon Sep 17 00:00:00 2001 From: kristupas Date: Wed, 10 Aug 2022 13:13:06 +0000 Subject: [PATCH 28/89] Added 'history', 'current' tables for voters and proxies #22 --- api/backend.sql | 229 +++++++++++++++++++++-------------------------- db/hafbe_app.sql | 163 ++++++++++++++++++++++----------- 2 files changed, 210 insertions(+), 182 deletions(-) diff --git a/api/backend.sql b/api/backend.sql index f170b3b..f4a173c 100644 --- a/api/backend.sql +++ b/api/backend.sql @@ -4,6 +4,10 @@ CREATE SCHEMA IF NOT EXISTS hafbe_backend; CREATE EXTENSION IF NOT EXISTS plpython3u SCHEMA pg_catalog; +/* +general +*/ + CREATE FUNCTION hafbe_backend.get_head_block_num() RETURNS INT LANGUAGE 'plpgsql' @@ -48,6 +52,10 @@ END $$ ; +/* +operation types +*/ + CREATE FUNCTION hafbe_backend.format_op_types(_operation_id BIGINT, _operation_name TEXT, _is_virtual BOOLEAN) RETURNS JSON LANGUAGE 'plpgsql' @@ -173,6 +181,10 @@ END $$ ; +/* +operations +*/ + CREATE FUNCTION hafbe_backend.get_trx_hash(_block_num INT, _trx_in_block INT) RETURNS TEXT LANGUAGE 'plpgsql' @@ -264,47 +276,6 @@ END $$ ; -CREATE FUNCTION hafbe_backend.get_block(_block_num INT) -RETURNS JSON -LANGUAGE 'plpgsql' -AS -$$ -DECLARE - __block_api_data JSON = (((SELECT hafbe_backend.get_block_api_data(_block_num))->'result')->'block'); -BEGIN - RETURN json_build_object( - 'block_num', _block_num, - 'block_hash', __block_api_data->>'block_id', - 'timestamp', __block_api_data->>'timestamp', - 'witness', __block_api_data->>'witness', - 'signing_key', __block_api_data->>'signing_key' - ); -END -$$ -; - -CREATE FUNCTION hafbe_backend.get_block_api_data(_block_num INT) -RETURNS JSON -LANGUAGE 'plpython3u' -AS -$$ - import subprocess - import json - - return json.dumps( - json.loads( - subprocess.check_output([ - """ - curl -X POST https://api.hive.blog \ - -H 'Content-Type: application/json' \ - -d '{"jsonrpc": "2.0", "method": "block_api.get_block", "params": {"block_num": %d}, "id": null}' - """ % _block_num - ], shell=True).decode('utf-8') - ) - ) -$$ -; - CREATE FUNCTION hafbe_backend.get_set_of_ops_by_block(_block_num INT, _top_op_id BIGINT, _limit BIGINT, _filter SMALLINT[]) RETURNS SETOF hafbe_backend.operations AS @@ -358,12 +329,83 @@ END $$ ; +/* +Block stats +*/ + +CREATE FUNCTION hafbe_backend.get_block(_block_num INT) +RETURNS JSON +LANGUAGE 'plpgsql' +AS +$$ +DECLARE + __block_api_data JSON = (((SELECT hafbe_backend.get_block_api_data(_block_num))->'result')->'block'); +BEGIN + RETURN json_build_object( + 'block_num', _block_num, + 'block_hash', __block_api_data->>'block_id', + 'timestamp', __block_api_data->>'timestamp', + 'witness', __block_api_data->>'witness', + 'signing_key', __block_api_data->>'signing_key' + ); +END +$$ +; + +CREATE FUNCTION hafbe_backend.get_block_api_data(_block_num INT) +RETURNS JSON +LANGUAGE 'plpython3u' +AS +$$ + import subprocess + import json + + return json.dumps( + json.loads( + subprocess.check_output([ + """ + curl -X POST https://api.hive.blog \ + -H 'Content-Type: application/json' \ + -d '{"jsonrpc": "2.0", "method": "block_api.get_block", "params": {"block_num": %d}, "id": null}' + """ % _block_num + ], shell=True).decode('utf-8') + ) + ) +$$ +; + +/* +witnesses and voters +*/ + +CREATE FUNCTION hafbe_backend.get_proxied_vests(_voter_id INT) +RETURNS TABLE ( + proxied_vests NUMERIC +) +AS +$function$ +BEGIN + RETURN QUERY SELECT SUM(av.vests) + FROM hafbe_app.current_account_proxies cap + JOIN ( + SELECT account_id, vests + FROM hafbe_app.account_vests + ) av ON av.account_id = cap.account_id + WHERE proxy_id = _voter_id AND proxy = TRUE; +END +$function$ +LANGUAGE 'plpgsql' STABLE +SET JIT=OFF +SET join_collapse_limit=16 +SET from_collapse_limit=16 +; + CREATE TYPE hafbe_backend.witness_voters AS ( account TEXT, vests NUMERIC, account_vests BIGINT, proxied_vests NUMERIC, - operation_id BIGINT + timestamp TIMESTAMP ); CREATE FUNCTION hafbe_backend.get_set_of_witness_voters(_witness_id INT) @@ -376,28 +418,19 @@ BEGIN CASE WHEN av.vests IS NULL THEN 0 ELSE av.vests END + proxied_vests AS vests, CASE WHEN av.vests IS NULL THEN 0 ELSE av.vests END AS account_vests, proxied_vests, - operation_id - FROM ( - SELECT - voter_id, operation_id - FROM ( - SELECT - ROW_NUMBER() OVER (PARTITION BY voter_id ORDER BY operation_id DESC) AS row_n, - voter_id, approve, operation_id - FROM hafbe_app.witness_votes - WHERE witness_id = _witness_id - ) row_count - WHERE row_n = 1 AND approve = TRUE - ) wv + timestamp + FROM hafbe_app.witness_votes_history JOIN LATERAL ( - SELECT proxied_vests + SELECT CASE WHEN proxied_vests IS NULL THEN 0 ELSE proxied_vests END AS proxied_vests FROM hafbe_backend.get_proxied_vests(voter_id) ) prox_vests ON TRUE JOIN LATERAL ( - SELECT proxied - FROM hafbe_backend.is_voter_proxied(voter_id) + SELECT CASE WHEN proxy IS NULL THEN FALSE ELSE TRUE END AS proxied + FROM hafbe_app.current_account_proxies + WHERE account_id = voter_id AND proxy = TRUE + LIMIT 1 ) is_prox ON TRUE JOIN ( @@ -408,7 +441,9 @@ BEGIN LEFT JOIN ( SELECT account_id, vests FROM hafbe_app.account_vests - ) av ON is_prox.proxied IS FALSE AND av.account_id = voter_id; + ) av ON is_prox.proxied IS FALSE AND av.account_id = voter_id + + WHERE witness_id = _witness_id AND approve = TRUE; END $function$ LANGUAGE 'plpgsql' STABLE @@ -417,30 +452,16 @@ SET join_collapse_limit=16 SET from_collapse_limit=16 ; -CREATE TYPE hafbe_backend.witness_voters_history AS ( - account TEXT, - vests NUMERIC, - account_vests BIGINT, - proxied_vests NUMERIC, - timestamp TIMESTAMP -); - CREATE FUNCTION hafbe_backend.get_witness_voters_ordered(_witness_id INT, _limit INT, _order_by TEXT, _order_is TEXT) -RETURNS SETOF hafbe_backend.witness_voters_history +RETURNS SETOF hafbe_backend.witness_voters LANGUAGE 'plpgsql' AS $$ BEGIN RETURN QUERY EXECUTE format( $query$ - SELECT account, vests, account_vests, proxied_vests, hov.timestamp + SELECT account, vests, account_vests, proxied_vests, timestamp FROM hafbe_backend.get_set_of_witness_voters(%L) - - JOIN LATERAL ( - SELECT timestamp - FROM hive.operations_view - WHERE id = operation_id - ) hov ON TRUE ORDER BY (CASE WHEN %L = 'desc' THEN %I ELSE NULL END) DESC, (CASE WHEN %L = 'asc' THEN %I ELSE NULL END) ASC @@ -466,60 +487,6 @@ END $$ ; -CREATE FUNCTION hafbe_backend.is_voter_proxied(_voter_id INT) -RETURNS TABLE ( - proxied BOOLEAN -) -AS -$function$ -BEGIN - RETURN QUERY SELECT proxy - FROM ( - SELECT - ROW_NUMBER() OVER (PARTITION BY account_id ORDER BY operation_id DESC) AS row_n, - proxy - FROM hafbe_app.account_proxies - WHERE account_id = _voter_id - ) row_count - WHERE row_n = 1; -END -$function$ -LANGUAGE 'plpgsql' STABLE -SET JIT=OFF -SET join_collapse_limit=16 -SET from_collapse_limit=16 -; - -CREATE FUNCTION hafbe_backend.get_proxied_vests(_voter_id INT) -RETURNS TABLE ( - proxied_vests NUMERIC -) -AS -$function$ -BEGIN - RETURN QUERY SELECT (SUM(av.vests))::NUMERIC - FROM ( - SELECT - ROW_NUMBER() OVER (PARTITION BY account_id ORDER BY operation_id DESC) AS row_n, - account_id, proxy, operation_id - FROM hafbe_app.account_proxies ap - WHERE proxy_id = _voter_id - ) row_count - - JOIN ( - SELECT account_id, vests - FROM hafbe_app.account_vests - ) av ON av.account_id = row_count.account_id - - WHERE row_n = 1 AND proxy = TRUE; -END -$function$ -LANGUAGE 'plpgsql' STABLE -SET JIT=OFF -SET join_collapse_limit=16 -SET from_collapse_limit=16 -; - CREATE TYPE hafbe_backend.witnesses AS ( witness TEXT, url TEXT, @@ -896,6 +863,10 @@ SET join_collapse_limit=16 SET from_collapse_limit=16 ; +/* +account data +*/ + CREATE FUNCTION hafbe_backend.get_account(_account TEXT) RETURNS JSON LANGUAGE 'plpython3u' diff --git a/db/hafbe_app.sql b/db/hafbe_app.sql index 137e3d1..98d6deb 100644 --- a/db/hafbe_app.sql +++ b/db/hafbe_app.sql @@ -15,27 +15,49 @@ BEGIN INSERT INTO hafbe_app.app_status (continue_processing, last_processed_block) VALUES (True, 0); - CREATE TABLE IF NOT EXISTS hafbe_app.witness_votes ( + CREATE TABLE IF NOT EXISTS hafbe_app.witness_votes_history ( witness_id INT NOT NULL, voter_id INT NOT NULL, approve BOOLEAN NOT NULL, - operation_id BIGINT NOT NULL + timestamp TIMESTAMP NOT NULL ) INHERITS (hive.hafbe_app); - CREATE INDEX IF NOT EXISTS witness_votes_witness_id ON hafbe_app.witness_votes USING btree (witness_id); - CREATE INDEX IF NOT EXISTS witness_votes_voter_id ON hafbe_app.witness_votes USING btree (voter_id); - CREATE INDEX IF NOT EXISTS witness_votes_operation_id ON hafbe_app.witness_votes USING btree (operation_id); + CREATE INDEX IF NOT EXISTS witness_votes_history_witness_id ON hafbe_app.witness_votes_history USING btree (witness_id); + CREATE INDEX IF NOT EXISTS witness_votes_history_voter_id ON hafbe_app.witness_votes_history USING btree (voter_id); + CREATE INDEX IF NOT EXISTS witness_votes_history_timestamp ON hafbe_app.witness_votes_history USING btree (timestamp); - CREATE TABLE IF NOT EXISTS hafbe_app.account_proxies ( + CREATE TABLE IF NOT EXISTS hafbe_app.current_witness_votes ( + witness_id INT NOT NULL, + voter_id INT NOT NULL, + approve BOOLEAN NOT NULL, + timestamp TIMESTAMP NOT NULL, + + CONSTRAINT pk_current_witness_votes PRIMARY KEY (witness_id, voter_id) + ) INHERITS (hive.hafbe_app); + + CREATE INDEX IF NOT EXISTS current_witness_votes_approve ON hafbe_app.current_witness_votes USING btree (approve); + CREATE INDEX IF NOT EXISTS current_witness_votes_timestamp ON hafbe_app.current_witness_votes USING btree (timestamp); + + CREATE TABLE IF NOT EXISTS hafbe_app.account_proxies_history ( account_id INT NOT NULL, proxy_id INT, proxy BOOLEAN, - operation_id BIGINT NOT NULL + timestamp TIMESTAMP NOT NULL ) INHERITS (hive.hafbe_app); - CREATE INDEX IF NOT EXISTS account_proxies_account_id ON hafbe_app.account_proxies USING btree (account_id); - CREATE INDEX IF NOT EXISTS account_proxies_proxy_id ON hafbe_app.account_proxies USING btree (proxy_id); - CREATE INDEX IF NOT EXISTS account_proxies_operation_id ON hafbe_app.account_proxies USING btree (operation_id); + CREATE INDEX IF NOT EXISTS account_proxies_history_account_id ON hafbe_app.account_proxies_history USING btree (account_id); + CREATE INDEX IF NOT EXISTS account_proxies_history_proxy_id ON hafbe_app.account_proxies_history USING btree (proxy_id); + CREATE INDEX IF NOT EXISTS account_proxies_history_timestamp ON hafbe_app.account_proxies_history USING btree (timestamp); + + CREATE TABLE IF NOT EXISTS hafbe_app.current_account_proxies ( + account_id INT NOT NULL, + proxy_id INT, + proxy BOOLEAN NOT NULL, + + CONSTRAINT pk_current_account_proxies PRIMARY KEY (account_id, proxy_id) + ) INHERITS (hive.hafbe_app); + + CREATE INDEX IF NOT EXISTS current_account_proxies_proxy ON hafbe_app.current_account_proxies USING btree (proxy); CREATE TABLE IF NOT EXISTS hafbe_app.hived_account_cache ( account TEXT NOT NULL, @@ -45,16 +67,12 @@ BEGIN ); CREATE TABLE IF NOT EXISTS hafbe_app.account_operation_cache ( - uq_key TEXT NOT NULL, account_id INT NOT NULL, op_type_id INT NOT NULL, - CONSTRAINT uq_account_operation_cache UNIQUE (uq_key) + CONSTRAINT pk_account_operation_cache PRIMARY KEY (account_id, op_type_id) ) INHERITS (hive.hafbe_app); - CREATE INDEX IF NOT EXISTS account_operation_cache_account_id ON hafbe_app.account_operation_cache USING btree (account_id); - CREATE INDEX IF NOT EXISTS account_operation_cache_op_type_id ON hafbe_app.account_operation_cache USING btree (op_type_id); - CREATE TABLE IF NOT EXISTS hafbe_app.account_vests ( account_id INT NOT NULL, vests BIGINT NOT NULL, @@ -143,76 +161,112 @@ $$ DECLARE __last_reported_block INT := 0; __unproxy_op RECORD; - __last_op_id BIGINT; + __last_op_time TIMESTAMP; __balance_change RECORD; + __hardfork_one_block_num INT = 905693; BEGIN + SELECT INTO __last_op_time CASE WHEN timestamp IS NULL THEN to_timestamp(0) ELSE timestamp END + FROM hafbe_app.account_proxies_history ORDER BY timestamp DESC LIMIT 1; + + -- main processing loop FOR b IN _from .. _to LOOP - INSERT INTO hafbe_app.witness_votes (witness_id, voter_id, approve, operation_id) + INSERT INTO hafbe_app.witness_votes_history (witness_id, voter_id, approve, timestamp) SELECT - hafbe_app.get_account_id(approve_operation->>'witness'), - hafbe_app.get_account_id(approve_operation->>'account'), - (approve_operation->>'approve')::BOOLEAN, - id + hafbe_app.get_account_id((body::JSON)->'value'->>'witness'), + hafbe_app.get_account_id((body::JSON)->'value'->>'account'), + ((body::JSON)->'value'->>'approve')::BOOLEAN, + timestamp + FROM hive.btracker_app_operations_view + WHERE op_type_id = 12 AND block_num = b; + + INSERT INTO hafbe_app.current_witness_votes (witness_id, voter_id, approve, timestamp) + SELECT witness_id, voter_id, approve, timestamp FROM ( SELECT - (body::JSON)->'value' AS approve_operation, - id - FROM hive.btracker_app_operations_view - WHERE op_type_id = 12 AND block_num = b - ) hov - ON CONFLICT DO NOTHING; - - SELECT operation_id FROM hafbe_app.account_proxies ORDER BY operation_id DESC LIMIT 1 INTO __last_op_id; + -- must take latest op in block, in case voter does vote/unvote on same block + ROW_NUMBER() OVER (PARTITION BY witness_id, voter_id ORDER BY timestamp DESC) AS row_n, + witness_id, voter_id, approve, timestamp + FROM ( + SELECT + hafbe_app.get_account_id((body::JSON)->'value'->>'witness') AS witness_id, + hafbe_app.get_account_id((body::JSON)->'value'->>'account') AS voter_id, + ((body::JSON)->'value'->>'approve')::BOOLEAN AS approve, + timestamp + FROM hive.btracker_app_operations_view + WHERE op_type_id = 12 AND block_num = b + ) cur_votes + ) row_count + WHERE row_n = 1 AND approve = TRUE - INSERT INTO hafbe_app.account_proxies (account_id, proxy_id, proxy, operation_id) + ON CONFLICT ON CONSTRAINT pk_current_witness_votes DO UPDATE SET + witness_id = EXCLUDED.witness_id, + voter_id = EXCLUDED.voter_id, + approve = EXCLUDED.approve, + timestamp = EXCLUDED.timestamp + ; + + INSERT INTO hafbe_app.account_proxies_history (account_id, proxy_id, proxy, timestamp) SELECT - account_id, - proxy_id, + account_id, proxy_id, CASE WHEN proxy_id IS NULL THEN FALSE ELSE TRUE END, - id + timestamp FROM ( SELECT hafbe_app.get_account_id(proxy_operation->>'account') AS account_id, hafbe_app.get_account_id(proxy_operation->>'proxy') AS proxy_id, - id + timestamp FROM ( SELECT (body::JSON)->'value' AS proxy_operation, - id + timestamp FROM hive.btracker_app_operations_view WHERE op_type_id = 13 AND block_num = b ) hov - ) acc_ids - ON CONFLICT DO NOTHING; + ) acc_ids; - INSERT INTO hafbe_app.account_operation_cache (uq_key, account_id, op_type_id) - SELECT - account_id::TEXT || '-' || op_type_id::TEXT, - account_id, - op_type_id - FROM hive.btracker_app_account_operations_view haov + INSERT INTO hafbe_app.account_operation_cache (account_id, op_type_id) + SELECT account_id, op_type_id + FROM hive.btracker_app_account_operations_view WHERE block_num = b - ON CONFLICT DO NOTHING; + ON CONFLICT ON CONSTRAINT pk_account_operation_cache DO NOTHING; END LOOP; -- postprocessing to fill null values of proxy_id when account does unproxy FOR __unproxy_op IN - SELECT account_id, operation_id - FROM hafbe_app.account_proxies - WHERE operation_id > __last_op_id AND proxy_id IS NULL + SELECT account_id, timestamp + FROM hafbe_app.account_proxies_history + WHERE timestamp > __last_op_time AND proxy_id IS NULL LOOP - UPDATE hafbe_app.account_proxies + UPDATE hafbe_app.account_proxies_history SET proxy_id = ( SELECT proxy_id - FROM hafbe_app.account_proxies - WHERE operation_id < __unproxy_op.operation_id AND account_id = __unproxy_op.account_id AND proxy_id IS NOT NULL - ORDER BY operation_id DESC + FROM hafbe_app.account_proxies_history + WHERE timestamp < __unproxy_op.timestamp AND account_id = __unproxy_op.account_id AND proxy_id IS NOT NULL + ORDER BY timestamp DESC LIMIT 1 ) WHERE account_id = __unproxy_op.account_id AND proxy_id IS NULL; END LOOP; - + + -- create data from account_proxies_history, after null values are filled + INSERT INTO hafbe_app.current_account_proxies (account_id, proxy_id, proxy) + SELECT account_id, proxy_id, proxy + FROM ( + SELECT + ROW_NUMBER() OVER (PARTITION BY account_id, proxy_id ORDER BY timestamp DESC) AS row_n, + account_id, proxy_id, proxy + FROM hafbe_app.account_proxies_history + WHERE timestamp > __last_op_time + ) row_count + WHERE row_n = 1 AND proxy = TRUE + ON CONFLICT ON CONSTRAINT pk_current_account_proxies DO UPDATE SET + account_id = EXCLUDED.account_id, + proxy_id = EXCLUDED.proxy_id, + proxy = EXCLUDED.proxy + ; + + -- get impacted vests balance for block range and update account_vests FOR __balance_change IN WITH balance_impacting_ops AS ( SELECT hot.id @@ -225,7 +279,10 @@ BEGIN JOIN balance_impacting_ops b ON hov.op_type_id = b.id JOIN LATERAL ( SELECT account_name, amount - FROM hive.get_impacted_balances(hov.body, TRUE) -- TODO: lookout for hardfork op + FROM hive.get_impacted_balances( + hov.body, + CASE WHEN block_num >= __hardfork_one_block_num THEN TRUE ELSE FALSE END + ) WHERE asset_symbol_nai = 37 ) bio ON TRUE WHERE hov.block_num BETWEEN _from AND _to -- GitLab From 32cd39ca5eb599b737a6fe8c0ee246e30bd08767 Mon Sep 17 00:00:00 2001 From: kristupas Date: Thu, 11 Aug 2022 12:47:26 +0000 Subject: [PATCH 29/89] Fixed WHERE in 'btracker_app.sql' and other bugs #22 --- api/backend.sql | 9 +++++---- db/hafbe_app.sql | 39 +++++++++++++++++++++++---------------- 2 files changed, 28 insertions(+), 20 deletions(-) diff --git a/api/backend.sql b/api/backend.sql index f4a173c..7bab675 100644 --- a/api/backend.sql +++ b/api/backend.sql @@ -419,7 +419,7 @@ BEGIN CASE WHEN av.vests IS NULL THEN 0 ELSE av.vests END AS account_vests, proxied_vests, timestamp - FROM hafbe_app.witness_votes_history + FROM hafbe_app.current_witness_votes JOIN LATERAL ( SELECT CASE WHEN proxied_vests IS NULL THEN 0 ELSE proxied_vests END AS proxied_vests @@ -438,10 +438,11 @@ BEGIN FROM hive.accounts_view ) hav ON hav.id = voter_id - LEFT JOIN ( - SELECT account_id, vests + LEFT JOIN LATERAL ( + SELECT vests FROM hafbe_app.account_vests - ) av ON is_prox.proxied IS FALSE AND av.account_id = voter_id + WHERE account_id = voter_id + ) av ON is_prox.proxied IS FALSE WHERE witness_id = _witness_id AND approve = TRUE; END diff --git a/db/hafbe_app.sql b/db/hafbe_app.sql index 98d6deb..8547342 100644 --- a/db/hafbe_app.sql +++ b/db/hafbe_app.sql @@ -22,10 +22,6 @@ BEGIN timestamp TIMESTAMP NOT NULL ) INHERITS (hive.hafbe_app); - CREATE INDEX IF NOT EXISTS witness_votes_history_witness_id ON hafbe_app.witness_votes_history USING btree (witness_id); - CREATE INDEX IF NOT EXISTS witness_votes_history_voter_id ON hafbe_app.witness_votes_history USING btree (voter_id); - CREATE INDEX IF NOT EXISTS witness_votes_history_timestamp ON hafbe_app.witness_votes_history USING btree (timestamp); - CREATE TABLE IF NOT EXISTS hafbe_app.current_witness_votes ( witness_id INT NOT NULL, voter_id INT NOT NULL, @@ -34,9 +30,8 @@ BEGIN CONSTRAINT pk_current_witness_votes PRIMARY KEY (witness_id, voter_id) ) INHERITS (hive.hafbe_app); - - CREATE INDEX IF NOT EXISTS current_witness_votes_approve ON hafbe_app.current_witness_votes USING btree (approve); - CREATE INDEX IF NOT EXISTS current_witness_votes_timestamp ON hafbe_app.current_witness_votes USING btree (timestamp); + + CREATE INDEX IF NOT EXISTS current_witness_votes_witness_id_approve ON hafbe_app.current_witness_votes USING btree (witness_id, approve); CREATE TABLE IF NOT EXISTS hafbe_app.account_proxies_history ( account_id INT NOT NULL, @@ -44,10 +39,12 @@ BEGIN proxy BOOLEAN, timestamp TIMESTAMP NOT NULL ) INHERITS (hive.hafbe_app); - - CREATE INDEX IF NOT EXISTS account_proxies_history_account_id ON hafbe_app.account_proxies_history USING btree (account_id); - CREATE INDEX IF NOT EXISTS account_proxies_history_proxy_id ON hafbe_app.account_proxies_history USING btree (proxy_id); + CREATE INDEX IF NOT EXISTS account_proxies_history_timestamp ON hafbe_app.account_proxies_history USING btree (timestamp); + CREATE INDEX IF NOT EXISTS account_proxies_history_timestamp_account_id ON hafbe_app.account_proxies_history USING btree (timestamp, account_id); + CREATE INDEX IF NOT EXISTS account_proxies_history_timestamp_proxy_id ON hafbe_app.account_proxies_history USING btree (timestamp, proxy_id); + CREATE INDEX IF NOT EXISTS account_proxies_history_timestamp_proxy_id_proxy ON hafbe_app.account_proxies_history USING btree (timestamp, proxy_id, proxy); + CREATE INDEX IF NOT EXISTS account_proxies_history_account_id_proxy_id ON hafbe_app.account_proxies_history USING btree (account_id, proxy_id); CREATE TABLE IF NOT EXISTS hafbe_app.current_account_proxies ( account_id INT NOT NULL, @@ -56,8 +53,9 @@ BEGIN CONSTRAINT pk_current_account_proxies PRIMARY KEY (account_id, proxy_id) ) INHERITS (hive.hafbe_app); - - CREATE INDEX IF NOT EXISTS current_account_proxies_proxy ON hafbe_app.current_account_proxies USING btree (proxy); + + CREATE INDEX IF NOT EXISTS current_account_proxies_proxy_id_proxy ON hafbe_app.current_account_proxies USING btree (proxy_id, proxy); + CREATE INDEX IF NOT EXISTS current_account_proxies_account_id_proxy ON hafbe_app.current_account_proxies USING btree (account_id, proxy); CREATE TABLE IF NOT EXISTS hafbe_app.hived_account_cache ( account TEXT NOT NULL, @@ -163,11 +161,19 @@ DECLARE __unproxy_op RECORD; __last_op_time TIMESTAMP; __balance_change RECORD; - __hardfork_one_block_num INT = 905693; + __hardfork_one_op_id INT = 1176568; BEGIN SELECT INTO __last_op_time CASE WHEN timestamp IS NULL THEN to_timestamp(0) ELSE timestamp END FROM hafbe_app.account_proxies_history ORDER BY timestamp DESC LIMIT 1; + IF ( + SELECT ((body::JSON)->'value'->>'hardfork_id')::INT + FROM hive.operations_view + WHERE id = 1176568 + ) != 1 THEN + SELECT id FROM hive.operations_view WHERE op_type_id = 60 ORDER BY id LIMIT 1 INTO __hardfork_one_op_id; + END IF; + -- main processing loop FOR b IN _from .. _to LOOP @@ -197,7 +203,7 @@ BEGIN WHERE op_type_id = 12 AND block_num = b ) cur_votes ) row_count - WHERE row_n = 1 AND approve = TRUE + WHERE row_n = 1 ON CONFLICT ON CONSTRAINT pk_current_witness_votes DO UPDATE SET witness_id = EXCLUDED.witness_id, @@ -259,7 +265,8 @@ BEGIN FROM hafbe_app.account_proxies_history WHERE timestamp > __last_op_time ) row_count - WHERE row_n = 1 AND proxy = TRUE + WHERE row_n = 1 + ON CONFLICT ON CONSTRAINT pk_current_account_proxies DO UPDATE SET account_id = EXCLUDED.account_id, proxy_id = EXCLUDED.proxy_id, @@ -281,7 +288,7 @@ BEGIN SELECT account_name, amount FROM hive.get_impacted_balances( hov.body, - CASE WHEN block_num >= __hardfork_one_block_num THEN TRUE ELSE FALSE END + CASE WHEN hov.id > __hardfork_one_op_id THEN TRUE ELSE FALSE END ) WHERE asset_symbol_nai = 37 ) bio ON TRUE -- GitLab From 21d7bad59c937f71f631460cadf90107ce5a3c6d Mon Sep 17 00:00:00 2001 From: kristupas Date: Thu, 11 Aug 2022 14:55:28 +0000 Subject: [PATCH 30/89] Added 'get_witness_voters_vests()', updated 'get_witnesses()' #22 --- api/backend.sql | 234 +++++++++++++++++++++++++++-------------------- db/hafbe_app.sql | 2 + 2 files changed, 138 insertions(+), 98 deletions(-) diff --git a/api/backend.sql b/api/backend.sql index 7bab675..35e92b3 100644 --- a/api/backend.sql +++ b/api/backend.sql @@ -408,17 +408,98 @@ CREATE TYPE hafbe_backend.witness_voters AS ( timestamp TIMESTAMP ); -CREATE FUNCTION hafbe_backend.get_set_of_witness_voters(_witness_id INT) +CREATE FUNCTION hafbe_backend.get_set_of_witness_voters(_witness_id INT, _limit INT = 2147483647, _order_by TEXT = 'vests', _order_is TEXT = 'asc') RETURNS SETOF hafbe_backend.witness_voters AS $function$ +BEGIN + RETURN QUERY EXECUTE format( + $query$ + + SELECT account, vests, account_vests, proxied_vests, timestamp + FROM ( + SELECT + hav.name::TEXT AS account, + CASE WHEN av.vests IS NULL THEN 0 ELSE av.vests END + proxied_vests AS vests, + CASE WHEN av.vests IS NULL THEN 0 ELSE av.vests END AS account_vests, + proxied_vests, timestamp + FROM hafbe_app.current_witness_votes + + JOIN LATERAL ( + SELECT CASE WHEN proxied_vests IS NULL THEN 0 ELSE proxied_vests END AS proxied_vests + FROM hafbe_backend.get_proxied_vests(voter_id) + ) prox_vests ON TRUE + + JOIN LATERAL ( + SELECT CASE WHEN proxy IS NULL THEN FALSE ELSE TRUE END AS proxied + FROM hafbe_app.current_account_proxies + WHERE account_id = voter_id AND proxy = TRUE + LIMIT 1 + ) is_prox ON TRUE + + JOIN ( + SELECT name, id + FROM hive.accounts_view + ) hav ON hav.id = voter_id + + LEFT JOIN LATERAL ( + SELECT vests + FROM hafbe_app.account_vests + WHERE account_id = voter_id + ) av ON is_prox.proxied IS FALSE + + WHERE witness_id = %L AND approve = TRUE + ) not_ordered + + ORDER BY + (CASE WHEN %L = 'desc' THEN %I ELSE NULL END) DESC, + (CASE WHEN %L = 'asc' THEN %I ELSE NULL END) ASC + LIMIT %L; + + $query$, + _witness_id, _order_is, _order_by, _order_is, _order_by, _limit + ) res; +END +$function$ +LANGUAGE 'plpgsql' STABLE +SET JIT=OFF +SET join_collapse_limit=16 +SET from_collapse_limit=16 +; + +CREATE FUNCTION hafbe_backend.get_witness_voters(_witness_id INT, _limit INT, _order_by TEXT, _order_is TEXT) +RETURNS JSON +LANGUAGE 'plpgsql' +AS +$$ +BEGIN + RETURN CASE WHEN arr IS NOT NULL THEN to_json(arr) ELSE '[]'::JSON END FROM ( + SELECT ARRAY( + SELECT hafbe_backend.get_set_of_witness_voters(_witness_id, _limit, _order_by, _order_is) + ) arr + ) result; +END +$$ +; + +CREATE FUNCTION hafbe_backend.get_witness_voters_vests(_witness_id INT, _include_today BOOLEAN) +RETURNS TABLE ( + _vests NUMERIC +) +AS +$function$ +DECLARE + __timestamp_upper_lim TIMESTAMP = ( + SELECT CASE WHEN _include_today IS TRUE THEN + now() + '1 day' + ELSE + '2018-07-16 04:23:12' + --(SELECT timestamp FROM hive.operations_view WHERE timestamp >= 'today' ORDER BY id LIMIT 1) + END + ); BEGIN RETURN QUERY SELECT - hav.name::TEXT AS account, - CASE WHEN av.vests IS NULL THEN 0 ELSE av.vests END + proxied_vests AS vests, - CASE WHEN av.vests IS NULL THEN 0 ELSE av.vests END AS account_vests, - proxied_vests, - timestamp + CASE WHEN av.vests IS NULL THEN 0 ELSE av.vests END + proxied_vests FROM hafbe_app.current_witness_votes JOIN LATERAL ( @@ -433,18 +514,15 @@ BEGIN LIMIT 1 ) is_prox ON TRUE - JOIN ( - SELECT name, id - FROM hive.accounts_view - ) hav ON hav.id = voter_id - LEFT JOIN LATERAL ( SELECT vests FROM hafbe_app.account_vests WHERE account_id = voter_id ) av ON is_prox.proxied IS FALSE - - WHERE witness_id = _witness_id AND approve = TRUE; + + WHERE + witness_id = _witness_id AND approve = TRUE AND + timestamp < __timestamp_upper_lim; END $function$ LANGUAGE 'plpgsql' STABLE @@ -453,48 +531,13 @@ SET join_collapse_limit=16 SET from_collapse_limit=16 ; -CREATE FUNCTION hafbe_backend.get_witness_voters_ordered(_witness_id INT, _limit INT, _order_by TEXT, _order_is TEXT) -RETURNS SETOF hafbe_backend.witness_voters -LANGUAGE 'plpgsql' -AS -$$ -BEGIN - RETURN QUERY EXECUTE format( - $query$ - SELECT account, vests, account_vests, proxied_vests, timestamp - FROM hafbe_backend.get_set_of_witness_voters(%L) - ORDER BY - (CASE WHEN %L = 'desc' THEN %I ELSE NULL END) DESC, - (CASE WHEN %L = 'asc' THEN %I ELSE NULL END) ASC - LIMIT %L; - $query$, _witness_id, _order_is, _order_by, _order_is, _order_by, _limit - ) res; -END -$$ -; - -CREATE FUNCTION hafbe_backend.get_witness_voters(_witness_id INT, _limit INT, _order_by TEXT, _order_is TEXT) -RETURNS JSON -LANGUAGE 'plpgsql' -AS -$$ -BEGIN - RETURN CASE WHEN arr IS NOT NULL THEN to_json(arr) ELSE '[]'::JSON END FROM ( - SELECT ARRAY( - SELECT hafbe_backend.get_witness_voters_ordered(_witness_id, _limit, _order_by, _order_is) - ) arr - ) result; -END -$$ -; - CREATE TYPE hafbe_backend.witnesses AS ( witness TEXT, url TEXT, votes NUMERIC, - votes_daily_change BIGINT, + votes_daily_change NUMERIC, voters_num INT, - voters_num_change INT, + voters_num_daily_change INT, price_feed TEXT, --JSON, bias INT, feed_age INTERVAL, @@ -507,16 +550,14 @@ CREATE FUNCTION hafbe_backend.get_set_of_witnesses(_limit INT) RETURNS SETOF hafbe_backend.witnesses AS $function$ -DECLARE - __first_op_today BIGINT = (SELECT id FROM hive.operations_view WHERE timestamp >= 'today'::TIMESTAMP ORDER BY id LIMIT 1); BEGIN RETURN QUERY SELECT witness::TEXT, url_data->>'url' AS url, votes, - ((votes_change_data->>'votes')::NUMERIC - votes)::BIGINT AS votes_daily_change, + votes_daily_change, voters_num, - ((votes_change_data->>'voters_num')::INT - voters_num)::INT AS voters_num_change, + voters_num_daily_change, feed_data->>'exchange_rate' AS price_feed, --(feed_data->'exchange_rate'->'quote'->>'amount')::INT - 1000 AS bias 0 AS bias, @@ -528,34 +569,57 @@ BEGIN SELECT witness, votes, + votes_daily_change, voters_num, - hafbe_backend.get_witness_votes_stats(witness_id, __first_op_today) AS votes_change_data, + voters_num_daily_change, hafbe_backend.get_witness_url(witness_id) AS url_data, hafbe_backend.get_witness_exchange_rate(witness_id) AS feed_data, hafbe_backend.get_witness_block_size(witness_id) AS block_size_data, hafbe_backend.get_witness_signing_key(witness_id) AS signing_data FROM ( SELECT - witness_id, - witness, - (votes_data->>'votes')::NUMERIC AS votes, - (votes_data->>'voters_num')::INT AS voters_num + wv.witness_id AS witness_id, + hav.name AS witness, + + CASE WHEN all_votes.votes IS NULL THEN 0 ELSE all_votes.votes END AS votes, + (CASE WHEN all_votes.votes IS NULL THEN 0 ELSE all_votes.votes END) + - + (CASE WHEN not_today_votes.votes IS NULL THEN 0 ELSE not_today_votes.votes END) + AS votes_daily_change, + + CASE WHEN all_votes.voters_num IS NULL THEN 0 ELSE all_votes.voters_num END AS voters_num, + + (CASE WHEN all_votes.voters_num IS NULL THEN 0 ELSE all_votes.voters_num END) + - + (CASE WHEN not_today_votes.voters_num IS NULL THEN 0 ELSE not_today_votes.voters_num END) + AS voters_num_daily_change + FROM ( + SELECT DISTINCT witness_id + FROM hafbe_app.current_witness_votes + ) wv + + JOIN ( + SELECT name, id + FROM hive.accounts_view + ) hav ON hav.id = wv.witness_id + + JOIN LATERAL ( SELECT - wv.witness_id AS witness_id, - hav.name AS witness, - hafbe_backend.get_witness_votes_stats(wv.witness_id) AS votes_data - FROM ( - SELECT DISTINCT witness_id - FROM hafbe_app.witness_votes - ) wv - - JOIN ( - SELECT name, id - FROM hive.accounts_view - ) hav ON hav.id = wv.witness_id - ) witness_votes + SUM(_vests)::NUMERIC AS votes, + COUNT(*)::INT AS voters_num + FROM hafbe_backend.get_witness_voters_vests(wv.witness_id, TRUE) + ) all_votes ON TRUE + + JOIN LATERAL ( + SELECT + SUM(_vests)::NUMERIC AS votes, + COUNT(*)::INT AS voters_num + FROM hafbe_backend.get_witness_voters_vests(wv.witness_id, FALSE) + ) not_today_votes ON TRUE + ) votes_and_num + ORDER BY votes DESC LIMIT _limit ) daily_change; @@ -582,32 +646,6 @@ END $$ ; -CREATE FUNCTION hafbe_backend.get_witness_votes_stats(_witness_id INT, _first_op_today BIGINT = 9223372036854775807) -RETURNS TABLE ( - votes NUMERIC, - voters_num INT -) -AS -$function$ -BEGIN - RETURN QUERY SELECT - CASE WHEN votes IS NULL THEN 0 ELSE votes END, - voters_num - FROM ( - SELECT - SUM(vests)::NUMERIC AS votes, - COUNT(*)::INT AS voters_num - FROM hafbe_backend.get_set_of_witness_voters(_witness_id) - WHERE operation_id < _first_op_today - ) result; -END -$function$ -LANGUAGE 'plpgsql' STABLE -SET JIT=OFF -SET join_collapse_limit=16 -SET from_collapse_limit=16 -; - CREATE FUNCTION hafbe_backend.latest_op_id() RETURNS JSON LANGUAGE 'plpgsql' diff --git a/db/hafbe_app.sql b/db/hafbe_app.sql index 8547342..0660af4 100644 --- a/db/hafbe_app.sql +++ b/db/hafbe_app.sql @@ -78,6 +78,8 @@ BEGIN CONSTRAINT pk_account_vests_account PRIMARY KEY (account_id) ) INHERITS (hive.hafbe_app); + CREATE INDEX IF NOT EXISTS account_vests_vests ON hafbe_app.account_vests USING btree (vests); + --ALTER SCHEMA hafbe_app OWNER TO hafbe_owner; END $$ -- GitLab From 024b4b7d3512d8bd23dcc4caab860ce17df9745b Mon Sep 17 00:00:00 2001 From: kristupas Date: Fri, 12 Aug 2022 14:20:18 +0000 Subject: [PATCH 31/89] Added 'get_witness_votes()' and 'get_witness_votes_change()' #22 --- api/backend.sql | 164 +++++++++++++++++++++++++++++++----------------- 1 file changed, 107 insertions(+), 57 deletions(-) diff --git a/api/backend.sql b/api/backend.sql index 35e92b3..93c7d3b 100644 --- a/api/backend.sql +++ b/api/backend.sql @@ -482,28 +482,25 @@ END $$ ; -CREATE FUNCTION hafbe_backend.get_witness_voters_vests(_witness_id INT, _include_today BOOLEAN) +CREATE FUNCTION hafbe_backend.get_witness_votes(_witness_id INT) RETURNS TABLE ( - _vests NUMERIC + _votes NUMERIC, + _voters_num INT ) AS $function$ -DECLARE - __timestamp_upper_lim TIMESTAMP = ( - SELECT CASE WHEN _include_today IS TRUE THEN - now() + '1 day' - ELSE - '2018-07-16 04:23:12' - --(SELECT timestamp FROM hive.operations_view WHERE timestamp >= 'today' ORDER BY id LIMIT 1) - END - ); BEGIN RETURN QUERY SELECT - CASE WHEN av.vests IS NULL THEN 0 ELSE av.vests END + proxied_vests + SUM( + CASE WHEN vests IS NULL THEN 0 ELSE vests END + + + CASE WHEN proxied_vests IS NULL THEN 0 ELSE proxied_vests END + ) AS votes, + COUNT(*)::INT AS voters_num FROM hafbe_app.current_witness_votes JOIN LATERAL ( - SELECT CASE WHEN proxied_vests IS NULL THEN 0 ELSE proxied_vests END AS proxied_vests + SELECT proxied_vests FROM hafbe_backend.get_proxied_vests(voter_id) ) prox_vests ON TRUE @@ -520,9 +517,68 @@ BEGIN WHERE account_id = voter_id ) av ON is_prox.proxied IS FALSE - WHERE - witness_id = _witness_id AND approve = TRUE AND - timestamp < __timestamp_upper_lim; + WHERE witness_id = _witness_id AND approve = TRUE; +END +$function$ +LANGUAGE 'plpgsql' STABLE +SET JIT=OFF +SET join_collapse_limit=16 +SET from_collapse_limit=16 +; + +CREATE FUNCTION hafbe_backend.get_witness_votes_change(_witness_id INT, _today DATE) +RETURNS TABLE ( + _votes NUMERIC, + _voters_num INT +) +AS +$function$ +BEGIN + IF _today IS NULL THEN + + -- in case hafbe is not up to sync with head block yet + RETURN QUERY SELECT + 0::NUMERIC, + 0::INT + ; + ELSE + + RETURN QUERY SELECT + SUM( + CASE WHEN vests IS NULL THEN 0 ELSE ( + CASE WHEN approve IS TRUE THEN vests ELSE -1 * vests END + ) END + + + CASE WHEN proxied_vests IS NULL THEN 0 ELSE ( + CASE WHEN approve IS TRUE THEN proxied_vests ELSE -1 * proxied_vests END + ) END + ) AS votes, + SUM( + CASE WHEN approve IS TRUE THEN 1 ELSE -1 END + )::INT AS voters_num + FROM hafbe_app.witness_votes_history + + JOIN LATERAL ( + SELECT proxied_vests + FROM hafbe_backend.get_proxied_vests(voter_id) + ) prox_vests ON TRUE + + JOIN LATERAL ( + SELECT CASE WHEN proxy IS NULL THEN FALSE ELSE TRUE END AS proxied + FROM hafbe_app.current_account_proxies + WHERE account_id = voter_id AND proxy = TRUE + LIMIT 1 + ) is_prox ON TRUE + + LEFT JOIN LATERAL ( + SELECT vests + FROM hafbe_app.account_vests + WHERE account_id = voter_id + ) av ON proxied IS FALSE + + WHERE witness_id = _witness_id AND timestamp >= _today; + + END IF; END $function$ LANGUAGE 'plpgsql' STABLE @@ -550,7 +606,17 @@ CREATE FUNCTION hafbe_backend.get_set_of_witnesses(_limit INT) RETURNS SETOF hafbe_backend.witnesses AS $function$ +DECLARE + __today DATE; BEGIN + IF ( + SELECT timestamp::DATE FROM hafbe_app.witness_votes_history ORDER BY timestamp DESC LIMIT 1 + ) != 'today'::DATE THEN + __today = NULL; + ELSE + __today = 'today'::DATE; + END IF; + RETURN QUERY SELECT witness::TEXT, url_data->>'url' AS url, @@ -567,62 +633,46 @@ BEGIN '1.25.0' AS version FROM ( SELECT - witness, - votes, - votes_daily_change, - voters_num, - voters_num_daily_change, hafbe_backend.get_witness_url(witness_id) AS url_data, hafbe_backend.get_witness_exchange_rate(witness_id) AS feed_data, hafbe_backend.get_witness_block_size(witness_id) AS block_size_data, - hafbe_backend.get_witness_signing_key(witness_id) AS signing_data + hafbe_backend.get_witness_signing_key(witness_id) AS signing_data, + + hav.name AS witness, + all_stats.votes AS votes, + CASE WHEN todays_votes.votes IS NULL THEN 0 ELSE todays_votes.votes END AS votes_daily_change, + all_stats.voters_num AS voters_num, + CASE WHEN todays_votes.voters_num IS NULL THEN 0 ELSE todays_votes.voters_num END voters_num_daily_change FROM ( SELECT - wv.witness_id AS witness_id, - hav.name AS witness, - + witness_id, CASE WHEN all_votes.votes IS NULL THEN 0 ELSE all_votes.votes END AS votes, - (CASE WHEN all_votes.votes IS NULL THEN 0 ELSE all_votes.votes END) - - - (CASE WHEN not_today_votes.votes IS NULL THEN 0 ELSE not_today_votes.votes END) - AS votes_daily_change, - - CASE WHEN all_votes.voters_num IS NULL THEN 0 ELSE all_votes.voters_num END AS voters_num, - - (CASE WHEN all_votes.voters_num IS NULL THEN 0 ELSE all_votes.voters_num END) - - - (CASE WHEN not_today_votes.voters_num IS NULL THEN 0 ELSE not_today_votes.voters_num END) - AS voters_num_daily_change - + CASE WHEN all_votes.voters_num IS NULL THEN 0 ELSE all_votes.voters_num END AS voters_num FROM ( SELECT DISTINCT witness_id FROM hafbe_app.current_witness_votes ) wv - JOIN ( - SELECT name, id - FROM hive.accounts_view - ) hav ON hav.id = wv.witness_id - JOIN LATERAL ( - SELECT - SUM(_vests)::NUMERIC AS votes, - COUNT(*)::INT AS voters_num - FROM hafbe_backend.get_witness_voters_vests(wv.witness_id, TRUE) + SELECT _votes AS votes, _voters_num AS voters_num + FROM hafbe_backend.get_witness_votes(witness_id) ) all_votes ON TRUE - JOIN LATERAL ( - SELECT - SUM(_vests)::NUMERIC AS votes, - COUNT(*)::INT AS voters_num - FROM hafbe_backend.get_witness_voters_vests(wv.witness_id, FALSE) - ) not_today_votes ON TRUE - - ) votes_and_num + ORDER BY votes DESC + LIMIT _limit + ) all_stats + + JOIN LATERAL ( + SELECT _votes AS votes, _voters_num AS voters_num + FROM hafbe_backend.get_witness_votes_change(witness_id, __today) + ) todays_votes ON TRUE + + JOIN ( + SELECT name, id + FROM hive.accounts_view + ) hav ON hav.id = witness_id - ORDER BY votes DESC - LIMIT _limit - ) daily_change; + ) daily_change_stats; END $function$ LANGUAGE 'plpgsql' STABLE -- GitLab From ed499eb43cd259334b4809b161cdaf12084ac34c Mon Sep 17 00:00:00 2001 From: kristupas Date: Tue, 16 Aug 2022 13:56:34 +0000 Subject: [PATCH 32/89] Updated block processing code in 'btracker_app.sql' #22 --- db/hafbe_app.sql | 179 +++++++++++++++++++++-------------------------- 1 file changed, 78 insertions(+), 101 deletions(-) diff --git a/db/hafbe_app.sql b/db/hafbe_app.sql index 0660af4..f526d1e 100644 --- a/db/hafbe_app.sql +++ b/db/hafbe_app.sql @@ -5,6 +5,8 @@ RETURNS VOID LANGUAGE 'plpgsql' AS $$ +DECLARE + __hardfork_one_op_id INT = 1176568; BEGIN RAISE NOTICE 'Attempting to create an application schema tables...'; @@ -15,6 +17,26 @@ BEGIN INSERT INTO hafbe_app.app_status (continue_processing, last_processed_block) VALUES (True, 0); + CREATE TABLE IF NOT EXISTS hafbe_app.hardfork_operations ( + operation_id INT NOT NULL, + hardfork_num INT NOT NULL, + + CONSTRAINT pk_hardfork_operations PRIMARY KEY (operation_id, hardfork_num) + ); + + INSERT INTO hafbe_app.hardfork_operations (operation_id, hardfork_num) + SELECT CASE WHEN ( + SELECT ((body::JSON)->'value'->>'hardfork_id')::INT + FROM hive.operations_view + WHERE id = __hardfork_one_op_id + ) != 1 THEN + (SELECT id FROM hive.operations_view WHERE op_type_id = 60 ORDER BY id LIMIT 1) + ELSE + __hardfork_one_op_id + END, + 1 + ; + CREATE TABLE IF NOT EXISTS hafbe_app.witness_votes_history ( witness_id INT NOT NULL, voter_id INT NOT NULL, @@ -36,7 +58,7 @@ BEGIN CREATE TABLE IF NOT EXISTS hafbe_app.account_proxies_history ( account_id INT NOT NULL, proxy_id INT, - proxy BOOLEAN, + proxy BOOLEAN NOT NULL, timestamp TIMESTAMP NOT NULL ) INHERITS (hive.hafbe_app); @@ -51,11 +73,12 @@ BEGIN proxy_id INT, proxy BOOLEAN NOT NULL, - CONSTRAINT pk_current_account_proxies PRIMARY KEY (account_id, proxy_id) + CONSTRAINT pk_current_account_proxies PRIMARY KEY (account_id) ) INHERITS (hive.hafbe_app); CREATE INDEX IF NOT EXISTS current_account_proxies_proxy_id_proxy ON hafbe_app.current_account_proxies USING btree (proxy_id, proxy); CREATE INDEX IF NOT EXISTS current_account_proxies_account_id_proxy ON hafbe_app.current_account_proxies USING btree (account_id, proxy); + CREATE INDEX IF NOT EXISTS current_account_proxies_account_id_proxy_id ON hafbe_app.current_account_proxies USING btree (account_id, proxy_id); CREATE TABLE IF NOT EXISTS hafbe_app.hived_account_cache ( account TEXT NOT NULL, @@ -160,79 +183,66 @@ AS $$ DECLARE __last_reported_block INT := 0; - __unproxy_op RECORD; - __last_op_time TIMESTAMP; + __proxy_op RECORD; + __vote_op RECORD; __balance_change RECORD; - __hardfork_one_op_id INT = 1176568; BEGIN - SELECT INTO __last_op_time CASE WHEN timestamp IS NULL THEN to_timestamp(0) ELSE timestamp END - FROM hafbe_app.account_proxies_history ORDER BY timestamp DESC LIMIT 1; - - IF ( - SELECT ((body::JSON)->'value'->>'hardfork_id')::INT - FROM hive.operations_view - WHERE id = 1176568 - ) != 1 THEN - SELECT id FROM hive.operations_view WHERE op_type_id = 60 ORDER BY id LIMIT 1 INTO __hardfork_one_op_id; - END IF; - -- main processing loop FOR b IN _from .. _to LOOP - INSERT INTO hafbe_app.witness_votes_history (witness_id, voter_id, approve, timestamp) - SELECT - hafbe_app.get_account_id((body::JSON)->'value'->>'witness'), - hafbe_app.get_account_id((body::JSON)->'value'->>'account'), - ((body::JSON)->'value'->>'approve')::BOOLEAN, - timestamp - FROM hive.btracker_app_operations_view - WHERE op_type_id = 12 AND block_num = b; - - INSERT INTO hafbe_app.current_witness_votes (witness_id, voter_id, approve, timestamp) - SELECT witness_id, voter_id, approve, timestamp - FROM ( + FOR __vote_op IN SELECT - -- must take latest op in block, in case voter does vote/unvote on same block - ROW_NUMBER() OVER (PARTITION BY witness_id, voter_id ORDER BY timestamp DESC) AS row_n, - witness_id, voter_id, approve, timestamp - FROM ( - SELECT - hafbe_app.get_account_id((body::JSON)->'value'->>'witness') AS witness_id, - hafbe_app.get_account_id((body::JSON)->'value'->>'account') AS voter_id, - ((body::JSON)->'value'->>'approve')::BOOLEAN AS approve, - timestamp - FROM hive.btracker_app_operations_view - WHERE op_type_id = 12 AND block_num = b - ) cur_votes - ) row_count - WHERE row_n = 1 + hafbe_app.get_account_id((body::JSON)->'value'->>'witness') AS witness_id, + hafbe_app.get_account_id((body::JSON)->'value'->>'account') AS voter_id, + ((body::JSON)->'value'->>'approve')::BOOLEAN AS approve, + timestamp + FROM hive.btracker_app_operations_view + WHERE op_type_id = 12 AND block_num = b - ON CONFLICT ON CONSTRAINT pk_current_witness_votes DO UPDATE SET - witness_id = EXCLUDED.witness_id, - voter_id = EXCLUDED.voter_id, - approve = EXCLUDED.approve, - timestamp = EXCLUDED.timestamp - ; + LOOP + INSERT INTO hafbe_app.witness_votes_history (witness_id, voter_id, approve, timestamp) + VALUES (__vote_op.witness_id, __vote_op.voter_id, __vote_op.approve, __vote_op.timestamp); + + INSERT INTO hafbe_app.current_witness_votes (witness_id, voter_id, approve, timestamp) + SELECT __vote_op.witness_id, __vote_op.voter_id, __vote_op.approve, __vote_op.timestamp + ON CONFLICT ON CONSTRAINT pk_current_witness_votes DO UPDATE SET + witness_id = EXCLUDED.witness_id, + voter_id = EXCLUDED.voter_id, + approve = EXCLUDED.approve, + timestamp = EXCLUDED.timestamp + ; + END LOOP; - INSERT INTO hafbe_app.account_proxies_history (account_id, proxy_id, proxy, timestamp) - SELECT - account_id, proxy_id, - CASE WHEN proxy_id IS NULL THEN FALSE ELSE TRUE END, - timestamp - FROM ( + FOR __proxy_op IN SELECT - hafbe_app.get_account_id(proxy_operation->>'account') AS account_id, - hafbe_app.get_account_id(proxy_operation->>'proxy') AS proxy_id, + hafbe_app.get_account_id((body::JSON)->'value'->>'account') AS account_id, + hafbe_app.get_account_id((body::JSON)->'value'->>'proxy') AS proxy_id, timestamp - FROM ( - SELECT - (body::JSON)->'value' AS proxy_operation, - timestamp - FROM hive.btracker_app_operations_view - WHERE op_type_id = 13 AND block_num = b - ) hov - ) acc_ids; - + FROM hive.btracker_app_operations_view + WHERE op_type_id = 13 AND block_num = b + LOOP + INSERT INTO hafbe_app.account_proxies_history (account_id, proxy_id, proxy, timestamp) + SELECT + __proxy_op.account_id, + CASE WHEN __proxy_op.proxy_id IS NULL THEN ( + SELECT proxy_id + FROM hafbe_app.account_proxies_history aph + WHERE aph.timestamp < __proxy_op.timestamp AND aph.account_id = __proxy_op.account_id AND aph.proxy_id IS NOT NULL + ORDER BY aph.timestamp DESC + LIMIT 1 + ) ELSE __proxy_op.proxy_id END, + CASE WHEN __proxy_op.proxy_id IS NULL THEN FALSE ELSE TRUE END, + __proxy_op.timestamp + ; + + INSERT INTO hafbe_app.current_account_proxies AS cap (account_id, proxy_id, proxy) + SELECT __proxy_op.account_id, __proxy_op.proxy_id, TRUE + ON CONFLICT ON CONSTRAINT pk_current_account_proxies DO UPDATE SET + proxy_id = CASE WHEN __proxy_op.proxy_id IS NULL THEN cap.proxy_id ELSE EXCLUDED.proxy_id END, + proxy = CASE WHEN __proxy_op.proxy_id IS NULL THEN FALSE ELSE TRUE END + ; + END LOOP; + INSERT INTO hafbe_app.account_operation_cache (account_id, op_type_id) SELECT account_id, op_type_id FROM hive.btracker_app_account_operations_view @@ -240,41 +250,6 @@ BEGIN ON CONFLICT ON CONSTRAINT pk_account_operation_cache DO NOTHING; END LOOP; - -- postprocessing to fill null values of proxy_id when account does unproxy - FOR __unproxy_op IN - SELECT account_id, timestamp - FROM hafbe_app.account_proxies_history - WHERE timestamp > __last_op_time AND proxy_id IS NULL - LOOP - UPDATE hafbe_app.account_proxies_history - SET proxy_id = ( - SELECT proxy_id - FROM hafbe_app.account_proxies_history - WHERE timestamp < __unproxy_op.timestamp AND account_id = __unproxy_op.account_id AND proxy_id IS NOT NULL - ORDER BY timestamp DESC - LIMIT 1 - ) - WHERE account_id = __unproxy_op.account_id AND proxy_id IS NULL; - END LOOP; - - -- create data from account_proxies_history, after null values are filled - INSERT INTO hafbe_app.current_account_proxies (account_id, proxy_id, proxy) - SELECT account_id, proxy_id, proxy - FROM ( - SELECT - ROW_NUMBER() OVER (PARTITION BY account_id, proxy_id ORDER BY timestamp DESC) AS row_n, - account_id, proxy_id, proxy - FROM hafbe_app.account_proxies_history - WHERE timestamp > __last_op_time - ) row_count - WHERE row_n = 1 - - ON CONFLICT ON CONSTRAINT pk_current_account_proxies DO UPDATE SET - account_id = EXCLUDED.account_id, - proxy_id = EXCLUDED.proxy_id, - proxy = EXCLUDED.proxy - ; - -- get impacted vests balance for block range and update account_vests FOR __balance_change IN WITH balance_impacting_ops AS ( @@ -290,7 +265,9 @@ BEGIN SELECT account_name, amount FROM hive.get_impacted_balances( hov.body, - CASE WHEN hov.id > __hardfork_one_op_id THEN TRUE ELSE FALSE END + CASE WHEN hov.id > ( + SELECT operation_id FROM hafbe_app.hardfork_operations WHERE hardfork_num = 1 + ) THEN TRUE ELSE FALSE END ) WHERE asset_symbol_nai = 37 ) bio ON TRUE -- GitLab From 36ab950d9a99234de896533a133c48d610a5c308 Mon Sep 17 00:00:00 2001 From: kristupas Date: Wed, 17 Aug 2022 12:39:44 +0000 Subject: [PATCH 33/89] Removed INSERT for each op in block processing, created 'parse_and_unpack_witness_data()' #22 --- api/backend.sql | 344 ++++++++++++----------------------------------- db/hafbe_app.sql | 54 ++++---- 2 files changed, 120 insertions(+), 278 deletions(-) diff --git a/api/backend.sql b/api/backend.sql index 93c7d3b..ff0fc3b 100644 --- a/api/backend.sql +++ b/api/backend.sql @@ -408,7 +408,7 @@ CREATE TYPE hafbe_backend.witness_voters AS ( timestamp TIMESTAMP ); -CREATE FUNCTION hafbe_backend.get_set_of_witness_voters(_witness_id INT, _limit INT = 2147483647, _order_by TEXT = 'vests', _order_is TEXT = 'asc') +CREATE FUNCTION hafbe_backend.get_set_of_witness_voters(_witness_id INT, _limit INT, _order_by TEXT, _order_is TEXT) RETURNS SETOF hafbe_backend.witness_voters AS $function$ @@ -538,8 +538,8 @@ BEGIN -- in case hafbe is not up to sync with head block yet RETURN QUERY SELECT - 0::NUMERIC, - 0::INT + NULL::NUMERIC, + NULL::INT ; ELSE @@ -618,61 +618,59 @@ BEGIN END IF; RETURN QUERY SELECT - witness::TEXT, - url_data->>'url' AS url, - votes, - votes_daily_change, - voters_num, - voters_num_daily_change, + hav.name::TEXT, + url, + CASE WHEN all_stats.votes IS NULL THEN 0 ELSE all_stats.votes END AS votes, + CASE WHEN todays_votes.votes IS NULL THEN 0 ELSE todays_votes.votes END AS votes_daily_change, + CASE WHEN all_stats.voters_num IS NULL THEN 0 ELSE all_stats.voters_num END voters_num, + CASE WHEN todays_votes.voters_num IS NULL THEN 0 ELSE todays_votes.voters_num END voters_num_daily_change, feed_data->>'exchange_rate' AS price_feed, --(feed_data->'exchange_rate'->'quote'->>'amount')::INT - 1000 AS bias 0 AS bias, (NOW() - (feed_data->>'timestamp')::TIMESTAMP)::INTERVAL AS feed_age, - (block_size_data->>'block_size')::INT AS block_size, - signing_data->>'signing_key' AS signing_key, + block_size::INT AS block_size, + signing_key, '1.25.0' AS version FROM ( SELECT - hafbe_backend.get_witness_url(witness_id) AS url_data, - hafbe_backend.get_witness_exchange_rate(witness_id) AS feed_data, - hafbe_backend.get_witness_block_size(witness_id) AS block_size_data, - hafbe_backend.get_witness_signing_key(witness_id) AS signing_data, - - hav.name AS witness, - all_stats.votes AS votes, - CASE WHEN todays_votes.votes IS NULL THEN 0 ELSE todays_votes.votes END AS votes_daily_change, - all_stats.voters_num AS voters_num, - CASE WHEN todays_votes.voters_num IS NULL THEN 0 ELSE todays_votes.voters_num END voters_num_daily_change - FROM ( - SELECT - witness_id, - CASE WHEN all_votes.votes IS NULL THEN 0 ELSE all_votes.votes END AS votes, - CASE WHEN all_votes.voters_num IS NULL THEN 0 ELSE all_votes.voters_num END AS voters_num - FROM ( - SELECT DISTINCT witness_id - FROM hafbe_app.current_witness_votes - ) wv - - JOIN LATERAL ( - SELECT _votes AS votes, _voters_num AS voters_num - FROM hafbe_backend.get_witness_votes(witness_id) - ) all_votes ON TRUE - - ORDER BY votes DESC - LIMIT _limit - ) all_stats - + witness_id, + CASE WHEN all_votes.votes IS NULL THEN 0 ELSE all_votes.votes END AS votes, + CASE WHEN all_votes.voters_num IS NULL THEN 0 ELSE all_votes.voters_num END AS voters_num + FROM hafbe_app.current_witnesses JOIN LATERAL ( SELECT _votes AS votes, _voters_num AS voters_num - FROM hafbe_backend.get_witness_votes_change(witness_id, __today) - ) todays_votes ON TRUE + FROM hafbe_backend.get_witness_votes(witness_id) + ) all_votes ON TRUE - JOIN ( - SELECT name, id - FROM hive.accounts_view - ) hav ON hav.id = witness_id + ORDER BY votes DESC + LIMIT _limit + ) all_stats + + JOIN LATERAL ( + SELECT _votes AS votes, _voters_num AS voters_num + FROM hafbe_backend.get_witness_votes_change(witness_id, __today) + ) todays_votes ON TRUE - ) daily_change_stats; + JOIN ( + SELECT name, id + FROM hive.accounts_view + ) hav ON hav.id = witness_id + + JOIN LATERAL( + SELECT hafbe_backend.parse_and_unpack_witness_data(witness_id, 'url', '{42,11}')->>'url' AS url + ) wd_url ON TRUE + + JOIN LATERAL( + SELECT hafbe_backend.parse_and_unpack_witness_data(witness_id, 'exchange_rate', '{42,7}') AS feed_data + ) wd_rate ON TRUE + + JOIN LATERAL( + SELECT hafbe_backend.parse_and_unpack_witness_data(witness_id, 'block_size', '{42,30,14,11}')->>'maximum_block_size' AS block_size + ) wd_size ON TRUE + + JOIN LATERAL( + SELECT hafbe_backend.parse_and_unpack_witness_data(witness_id, 'signing_key', '{42,11}')->>'signing_key' AS signing_key + ) wd_key ON TRUE; END $function$ LANGUAGE 'plpgsql' STABLE @@ -696,17 +694,6 @@ END $$ ; -CREATE FUNCTION hafbe_backend.latest_op_id() -RETURNS JSON -LANGUAGE 'plpgsql' -AS -$$ -BEGIN - RETURN id FROM hive.operations_view ORDER BY id DESC LIMIT 1; -END -$$ -; - CREATE FUNCTION hafbe_backend.parse_witness_set_props(_op_value JSON, _attr_name TEXT) RETURNS TEXT LANGUAGE 'plpgsql' @@ -734,216 +721,63 @@ END $$ ; -CREATE FUNCTION hafbe_backend.get_witness_url(_witness_id INT, _last_op_id BIGINT = NULL) +CREATE FUNCTION hafbe_backend.parse_and_unpack_witness_data(_witness_id INT, _attr_name TEXT, _op_type_array INT[], _last_op_id BIGINT = NULL) RETURNS JSON AS $function$ +DECLARE + __most_recent_op RECORD; + __result TEXT; + __witness_set_props_attr_name TEXT; BEGIN - IF _last_op_id IS NULL THEN - SELECT hafbe_backend.latest_op_id() INTO _last_op_id; + IF _last_op_id <= 0 THEN + RETURN json_build_object ( + _attr_name, NULL + ); END IF; - RETURN to_json(result) FROM ( - SELECT - CASE WHEN op_type_id = 42 AND url IS NOT NULL THEN - hafbe_backend.unpack_from_vector(url) - ELSE url END AS url - FROM ( - SELECT - CASE WHEN op_type_id = 42 AND url IS NULL THEN - (SELECT f->>'url' FROM hafbe_backend.get_witness_url(_witness_id, op_id - 1) f) - ELSE url END AS url, - op_type_id - FROM ( - SELECT - CASE WHEN op_type_id = 42 THEN - hafbe_backend.parse_witness_set_props(op, 'url') - ELSE - op->>'url' - END AS url, - op_type_id, - id AS op_id - FROM ( - SELECT - (body::JSON)->'value' AS op, - op_type_id, id - FROM hive.operations_view - - JOIN ( - SELECT operation_id - FROM hive.account_operations_view - WHERE account_id = _witness_id AND (op_type_id = 42 OR op_type_id = 11) AND operation_id <= _last_op_id - ORDER BY operation_id DESC - LIMIT 1 - ) haov ON id = haov.operation_id - ) op - ) price - ) recur - ) result; -END -$function$ -LANGUAGE 'plpgsql' STABLE -SET JIT=OFF -SET join_collapse_limit=16 -SET from_collapse_limit=16 -; - -CREATE FUNCTION hafbe_backend.get_witness_block_size(_witness_id INT, _last_op_id BIGINT = NULL) -RETURNS JSON -AS -$function$ -BEGIN IF _last_op_id IS NULL THEN - SELECT hafbe_backend.latest_op_id() INTO _last_op_id; + SELECT id FROM hive.operations_view ORDER BY id DESC LIMIT 1 INTO _last_op_id; END IF; - RETURN to_json(result) FROM ( - SELECT - CASE WHEN op_type_id = 42 AND block_size IS NOT NULL THEN - hafbe_backend.unpack_from_vector(block_size) - ELSE block_size END AS block_size - FROM ( - SELECT - CASE WHEN op_type_id = 42 AND block_size IS NULL THEN - (SELECT f->>'block_size' FROM hafbe_backend.get_witness_block_size(_witness_id, op_id - 1) f) - ELSE block_size END AS block_size, - op_type_id - FROM ( - SELECT - CASE WHEN op_type_id = 42 THEN - hafbe_backend.parse_witness_set_props(op, 'maximum_block_size') - ELSE - op->'props'->>'maximum_block_size' - END AS block_size, - op_type_id, - id AS op_id - FROM ( - SELECT - (body::JSON)->'value' AS op, - op_type_id, id, timestamp - FROM hive.operations_view - - JOIN ( - SELECT operation_id - FROM hive.account_operations_view - WHERE account_id = _witness_id AND op_type_id = ANY('{42,30,14,11}'::INT[]) AND operation_id <= _last_op_id - ORDER BY operation_id DESC - LIMIT 1 - ) haov ON id = haov.operation_id - ) op - ) price - ) recur - ) result; -END -$function$ -LANGUAGE 'plpgsql' STABLE -SET JIT=OFF -SET join_collapse_limit=16 -SET from_collapse_limit=16 -; - -CREATE FUNCTION hafbe_backend.get_witness_exchange_rate(_witness_id INT, _last_op_id BIGINT = NULL) -RETURNS JSON -AS -$function$ -BEGIN - IF _last_op_id IS NULL THEN - SELECT hafbe_backend.latest_op_id() INTO _last_op_id; + SELECT INTO __most_recent_op + (hov.body::JSON)->'value' AS value, + hov.op_type_id, hov.id, hov.timestamp + FROM hive.operations_view hov + WHERE ( + SELECT operation_id + FROM hive.account_operations_view + WHERE account_id = _witness_id AND op_type_id = ANY(_op_type_array) + ORDER BY operation_id DESC + LIMIT 1 + ) = id; + + IF _attr_name = 'url' THEN + SELECT __most_recent_op.value->>'url' INTO __result; + SELECT 'url' INTO __witness_set_props_attr_name; + ELSIF _attr_name = 'exchange_rate' THEN + SELECT __most_recent_op.value->>'exchange_rate' INTO __result; + SELECT 'hbd_exchange_rate' INTO __witness_set_props_attr_name; + ELSIF _attr_name = 'maximum_block_size' THEN + SELECT __most_recent_op.value->'props'->>'maximum_block_size' INTO __result; + SELECT 'maximum_block_size' INTO __witness_set_props_attr_name; + ELSIF _attr_name = 'signing_key' THEN + SELECT __most_recent_op.value->>'block_signing_key' INTO __result; + SELECT 'new_signing_key' INTO __witness_set_props_attr_name; END IF; - RETURN to_json(result) FROM ( - SELECT - CASE WHEN op_type_id = 42 AND exchange_rate IS NOT NULL THEN - hafbe_backend.unpack_from_vector(exchange_rate) - ELSE exchange_rate END AS exchange_rate, - timestamp - FROM ( - SELECT - CASE WHEN op_type_id = 42 AND exchange_rate IS NULL THEN - (SELECT f->>'exchange_rate' FROM hafbe_backend.get_witness_exchange_rate(_witness_id, op_id - 1) f) - ELSE exchange_rate END AS exchange_rate, - op_type_id, timestamp - FROM ( - SELECT - CASE WHEN op_type_id = 42 THEN - hafbe_backend.parse_witness_set_props(op, 'hbd_exchange_rate') - ELSE - op->>'exchange_rate' - END AS exchange_rate, - op_type_id, - id AS op_id, - timestamp - FROM ( - SELECT - (body::JSON)->'value' AS op, - op_type_id, id, timestamp - FROM hive.operations_view - - JOIN ( - SELECT operation_id - FROM hive.account_operations_view - WHERE account_id = _witness_id AND (op_type_id = 42 OR op_type_id = 7) AND operation_id <= _last_op_id - ORDER BY operation_id DESC - LIMIT 1 - ) haov ON id = haov.operation_id - ) op - ) price - ) recur - ) result; -END -$function$ -LANGUAGE 'plpgsql' STABLE -SET JIT=OFF -SET join_collapse_limit=16 -SET from_collapse_limit=16 -; - -CREATE FUNCTION hafbe_backend.get_witness_signing_key(_witness_id INT, _last_op_id BIGINT = NULL) -RETURNS JSON -AS -$function$ -BEGIN - IF _last_op_id IS NULL THEN - SELECT hafbe_backend.latest_op_id() INTO _last_op_id; + IF __result IS NULL AND __most_recent_op.op_type_id = 42 THEN + SELECT hafbe_backend.parse_witness_set_props(__most_recent_op.value, _attr_name) INTO __result; + ELSIF __result IS NULL AND __most_recent_op.op_type_id != 42 THEN + RETURN hafbe_backend.parse_and_unpack_witness_data( + _witness_id, __witness_set_props_attr_name, _op_type_array, __most_recent_op.id - 1) + ; END IF; - RETURN to_json(result) FROM ( - SELECT - CASE WHEN op_type_id = 42 AND signing_key IS NULL THEN - (SELECT f->>'signing_key' FROM hafbe_backend.get_witness_signing_key(_witness_id, op_id - 1) f) - ELSE signing_key END AS signing_key - FROM ( - SELECT - CASE WHEN op_type_id = 42 AND signing_key IS NULL THEN - hafbe_backend.parse_witness_set_props(signing_key::JSON, 'key') - ELSE signing_key END AS signing_key, - op_type_id, op_id - FROM ( - SELECT - CASE WHEN op_type_id = 42 THEN - hafbe_backend.parse_witness_set_props(op, 'new_signing_key') - ELSE - op->>'block_signing_key' - END AS signing_key, - op_type_id, - id AS op_id - FROM ( - SELECT - (body::JSON)->'value' AS op, - op_type_id, id - FROM hive.operations_view - - JOIN ( - SELECT operation_id - FROM hive.account_operations_view - WHERE account_id = _witness_id AND (op_type_id = 42 OR op_type_id = 11) AND operation_id <= _last_op_id - ORDER BY operation_id DESC - LIMIT 1 - ) haov ON id = haov.operation_id - ) key_op - ) new_key_val - ) key_val - ) result; + RETURN json_build_object( + _attr_name, __result, + 'timestamp', __most_recent_op.timestamp + ); END $function$ LANGUAGE 'plpgsql' STABLE diff --git a/db/hafbe_app.sql b/db/hafbe_app.sql index f526d1e..7890a50 100644 --- a/db/hafbe_app.sql +++ b/db/hafbe_app.sql @@ -55,6 +55,12 @@ BEGIN CREATE INDEX IF NOT EXISTS current_witness_votes_witness_id_approve ON hafbe_app.current_witness_votes USING btree (witness_id, approve); + CREATE TABLE IF NOT EXISTS hafbe_app.current_witnesses ( + witness_id INT NOT NULL, + + CONSTRAINT pk_current_witnesses PRIMARY KEY (witness_id) + ) INHERITS (hive.hafbe_app); + CREATE TABLE IF NOT EXISTS hafbe_app.account_proxies_history ( account_id INT NOT NULL, proxy_id INT, @@ -182,7 +188,6 @@ LANGUAGE 'plpgsql' AS $$ DECLARE - __last_reported_block INT := 0; __proxy_op RECORD; __vote_op RECORD; __balance_change RECORD; @@ -190,37 +195,40 @@ BEGIN -- main processing loop FOR b IN _from .. _to LOOP - FOR __vote_op IN - SELECT - hafbe_app.get_account_id((body::JSON)->'value'->>'witness') AS witness_id, - hafbe_app.get_account_id((body::JSON)->'value'->>'account') AS voter_id, - ((body::JSON)->'value'->>'approve')::BOOLEAN AS approve, - timestamp - FROM hive.btracker_app_operations_view - WHERE op_type_id = 12 AND block_num = b - - LOOP + SELECT INTO __vote_op + hafbe_app.get_account_id((body::JSON)->'value'->>'witness') AS witness_id, + hafbe_app.get_account_id((body::JSON)->'value'->>'account') AS voter_id, + ((body::JSON)->'value'->>'approve')::BOOLEAN AS approve, + timestamp + FROM hive.btracker_app_operations_view + WHERE op_type_id = 12 AND block_num = b; + + IF __vote_op.witness_id IS NOT NULL THEN INSERT INTO hafbe_app.witness_votes_history (witness_id, voter_id, approve, timestamp) VALUES (__vote_op.witness_id, __vote_op.voter_id, __vote_op.approve, __vote_op.timestamp); INSERT INTO hafbe_app.current_witness_votes (witness_id, voter_id, approve, timestamp) - SELECT __vote_op.witness_id, __vote_op.voter_id, __vote_op.approve, __vote_op.timestamp + VALUES (__vote_op.witness_id, __vote_op.voter_id, __vote_op.approve, __vote_op.timestamp) ON CONFLICT ON CONSTRAINT pk_current_witness_votes DO UPDATE SET witness_id = EXCLUDED.witness_id, voter_id = EXCLUDED.voter_id, approve = EXCLUDED.approve, timestamp = EXCLUDED.timestamp ; - END LOOP; + + INSERT INTO hafbe_app.current_witnesses (witness_id) + VALUES (__vote_op.witness_id) + ON CONFLICT ON CONSTRAINT pk_current_witnesses DO NOTHING; + END IF; - FOR __proxy_op IN - SELECT - hafbe_app.get_account_id((body::JSON)->'value'->>'account') AS account_id, - hafbe_app.get_account_id((body::JSON)->'value'->>'proxy') AS proxy_id, - timestamp - FROM hive.btracker_app_operations_view - WHERE op_type_id = 13 AND block_num = b - LOOP + SELECT INTO __proxy_op + hafbe_app.get_account_id((body::JSON)->'value'->>'account') AS account_id, + hafbe_app.get_account_id((body::JSON)->'value'->>'proxy') AS proxy_id, + timestamp + FROM hive.btracker_app_operations_view + WHERE op_type_id = 13 AND block_num = b; + + IF __proxy_op.account_id IS NOT NULL THEN INSERT INTO hafbe_app.account_proxies_history (account_id, proxy_id, proxy, timestamp) SELECT __proxy_op.account_id, @@ -236,12 +244,12 @@ BEGIN ; INSERT INTO hafbe_app.current_account_proxies AS cap (account_id, proxy_id, proxy) - SELECT __proxy_op.account_id, __proxy_op.proxy_id, TRUE + VALUES (__proxy_op.account_id, __proxy_op.proxy_id, TRUE) ON CONFLICT ON CONSTRAINT pk_current_account_proxies DO UPDATE SET proxy_id = CASE WHEN __proxy_op.proxy_id IS NULL THEN cap.proxy_id ELSE EXCLUDED.proxy_id END, proxy = CASE WHEN __proxy_op.proxy_id IS NULL THEN FALSE ELSE TRUE END ; - END LOOP; + END IF; INSERT INTO hafbe_app.account_operation_cache (account_id, op_type_id) SELECT account_id, op_type_id -- GitLab From 1a90cb170aabff3776bf07a5272f98038810e805 Mon Sep 17 00:00:00 2001 From: kristupas Date: Thu, 18 Aug 2022 09:35:42 +0000 Subject: [PATCH 34/89] Fixed bug of wrong arg being passed #22 --- api/backend.sql | 32 +++++++++++++++++++++++--------- 1 file changed, 23 insertions(+), 9 deletions(-) diff --git a/api/backend.sql b/api/backend.sql index ff0fc3b..9a97627 100644 --- a/api/backend.sql +++ b/api/backend.sql @@ -665,7 +665,7 @@ BEGIN ) wd_rate ON TRUE JOIN LATERAL( - SELECT hafbe_backend.parse_and_unpack_witness_data(witness_id, 'block_size', '{42,30,14,11}')->>'maximum_block_size' AS block_size + SELECT hafbe_backend.parse_and_unpack_witness_data(witness_id, 'maximum_block_size', '{42,30,14,11}')->>'maximum_block_size' AS block_size ) wd_size ON TRUE JOIN LATERAL( @@ -699,12 +699,26 @@ RETURNS TEXT LANGUAGE 'plpgsql' AS $$ +DECLARE + __result TEXT; BEGIN - RETURN props->>1 + SELECT INTO __result + props->>1 FROM ( SELECT json_array_elements(_op_value->'props') AS props ) to_arr WHERE props->>0 = _attr_name; + + IF _attr_name = 'new_signing_key' AND __result IS NULL THEN + SELECT INTO __result + props->>1 + FROM ( + SELECT json_array_elements(_op_value->'props') AS props + ) to_arr + WHERE props->>0 = 'key'; + END IF; + + RETURN __result; END $$ ; @@ -741,16 +755,16 @@ BEGIN END IF; SELECT INTO __most_recent_op - (hov.body::JSON)->'value' AS value, - hov.op_type_id, hov.id, hov.timestamp - FROM hive.operations_view hov - WHERE ( + (body::JSON)->'value' AS value, + op_type_id, id, timestamp + FROM hive.operations_view + JOIN ( SELECT operation_id FROM hive.account_operations_view WHERE account_id = _witness_id AND op_type_id = ANY(_op_type_array) ORDER BY operation_id DESC - LIMIT 1 - ) = id; + ) haov ON haov.operation_id = id + LIMIT 1; IF _attr_name = 'url' THEN SELECT __most_recent_op.value->>'url' INTO __result; @@ -767,7 +781,7 @@ BEGIN END IF; IF __result IS NULL AND __most_recent_op.op_type_id = 42 THEN - SELECT hafbe_backend.parse_witness_set_props(__most_recent_op.value, _attr_name) INTO __result; + SELECT hafbe_backend.parse_witness_set_props(__most_recent_op.value, __witness_set_props_attr_name) INTO __result; ELSIF __result IS NULL AND __most_recent_op.op_type_id != 42 THEN RETURN hafbe_backend.parse_and_unpack_witness_data( _witness_id, __witness_set_props_attr_name, _op_type_array, __most_recent_op.id - 1) -- GitLab From d19b0fdee7fde6196884cacfb5cec8f6824a168e Mon Sep 17 00:00:00 2001 From: kristupas Date: Wed, 24 Aug 2022 11:04:42 +0000 Subject: [PATCH 35/89] Added 'hafbe_app.balance_impacting_op_ids', 'get_set_of_voters_stats()' #22 --- api/backend.sql | 234 ++++++++++++++--------------------------------- db/hafbe_app.sql | 41 +++++---- 2 files changed, 95 insertions(+), 180 deletions(-) diff --git a/api/backend.sql b/api/backend.sql index 9a97627..d2f6c35 100644 --- a/api/backend.sql +++ b/api/backend.sql @@ -378,20 +378,48 @@ $$ witnesses and voters */ -CREATE FUNCTION hafbe_backend.get_proxied_vests(_voter_id INT) -RETURNS TABLE ( - proxied_vests NUMERIC -) +CREATE TYPE hafbe_backend.voters_stats AS ( + voter_id INT, + account_vests NUMERIC, + proxied_vests NUMERIC, + timestamp TIMESTAMP +); + +CREATE FUNCTION hafbe_backend.get_set_of_voters_stats(_witness_id INT) +RETURNS SETOF hafbe_backend.voters_stats AS $function$ BEGIN - RETURN QUERY SELECT SUM(av.vests) - FROM hafbe_app.current_account_proxies cap - JOIN ( - SELECT account_id, vests + RETURN QUERY SELECT + cwv.voter_id, + SUM(COALESCE(account.vests, 0)) AS account_vests, + SUM(COALESCE(proxied.vests, 0)) AS proxied_vests, + cwv.timestamp + FROM hafbe_app.current_witness_votes cwv + + LEFT JOIN ( + SELECT account_id, proxy_id + FROM hafbe_app.current_account_proxies + WHERE proxy = TRUE + ) acc_as_proxy ON acc_as_proxy.proxy_id = cwv.voter_id + + LEFT JOIN ( + SELECT vests, account_id FROM hafbe_app.account_vests - ) av ON av.account_id = cap.account_id - WHERE proxy_id = _voter_id AND proxy = TRUE; + ) proxied ON proxied.account_id = acc_as_proxy.account_id + + LEFT JOIN ( + SELECT account_id, proxy + FROM hafbe_app.current_account_proxies + ) acc_as_proxied ON acc_as_proxied.account_id = cwv.voter_id + + LEFT JOIN ( + SELECT vests, account_id + FROM hafbe_app.account_vests + ) account ON account.account_id = acc_as_proxied.account_id AND COALESCE(acc_as_proxied.proxy, FALSE) IS FALSE + + WHERE cwv.witness_id = _witness_id AND cwv.approve = TRUE + GROUP BY cwv.voter_id, cwv.timestamp; END $function$ LANGUAGE 'plpgsql' STABLE @@ -403,7 +431,7 @@ SET from_collapse_limit=16 CREATE TYPE hafbe_backend.witness_voters AS ( account TEXT, vests NUMERIC, - account_vests BIGINT, + account_vests NUMERIC, proxied_vests NUMERIC, timestamp TIMESTAMP ); @@ -420,36 +448,17 @@ BEGIN FROM ( SELECT hav.name::TEXT AS account, - CASE WHEN av.vests IS NULL THEN 0 ELSE av.vests END + proxied_vests AS vests, - CASE WHEN av.vests IS NULL THEN 0 ELSE av.vests END AS account_vests, - proxied_vests, timestamp - FROM hafbe_app.current_witness_votes - - JOIN LATERAL ( - SELECT CASE WHEN proxied_vests IS NULL THEN 0 ELSE proxied_vests END AS proxied_vests - FROM hafbe_backend.get_proxied_vests(voter_id) - ) prox_vests ON TRUE - - JOIN LATERAL ( - SELECT CASE WHEN proxy IS NULL THEN FALSE ELSE TRUE END AS proxied - FROM hafbe_app.current_account_proxies - WHERE account_id = voter_id AND proxy = TRUE - LIMIT 1 - ) is_prox ON TRUE + proxied_vests + account_vests AS vests, + account_vests, + proxied_vests, + timestamp + FROM hafbe_backend.get_set_of_voters_stats(%L) JOIN ( SELECT name, id FROM hive.accounts_view ) hav ON hav.id = voter_id - - LEFT JOIN LATERAL ( - SELECT vests - FROM hafbe_app.account_vests - WHERE account_id = voter_id - ) av ON is_prox.proxied IS FALSE - - WHERE witness_id = %L AND approve = TRUE - ) not_ordered + ) voters_stats ORDER BY (CASE WHEN %L = 'desc' THEN %I ELSE NULL END) DESC, @@ -482,116 +491,11 @@ END $$ ; -CREATE FUNCTION hafbe_backend.get_witness_votes(_witness_id INT) -RETURNS TABLE ( - _votes NUMERIC, - _voters_num INT -) -AS -$function$ -BEGIN - RETURN QUERY SELECT - SUM( - CASE WHEN vests IS NULL THEN 0 ELSE vests END - + - CASE WHEN proxied_vests IS NULL THEN 0 ELSE proxied_vests END - ) AS votes, - COUNT(*)::INT AS voters_num - FROM hafbe_app.current_witness_votes - - JOIN LATERAL ( - SELECT proxied_vests - FROM hafbe_backend.get_proxied_vests(voter_id) - ) prox_vests ON TRUE - - JOIN LATERAL ( - SELECT CASE WHEN proxy IS NULL THEN FALSE ELSE TRUE END AS proxied - FROM hafbe_app.current_account_proxies - WHERE account_id = voter_id AND proxy = TRUE - LIMIT 1 - ) is_prox ON TRUE - - LEFT JOIN LATERAL ( - SELECT vests - FROM hafbe_app.account_vests - WHERE account_id = voter_id - ) av ON is_prox.proxied IS FALSE - - WHERE witness_id = _witness_id AND approve = TRUE; -END -$function$ -LANGUAGE 'plpgsql' STABLE -SET JIT=OFF -SET join_collapse_limit=16 -SET from_collapse_limit=16 -; - -CREATE FUNCTION hafbe_backend.get_witness_votes_change(_witness_id INT, _today DATE) -RETURNS TABLE ( - _votes NUMERIC, - _voters_num INT -) -AS -$function$ -BEGIN - IF _today IS NULL THEN - - -- in case hafbe is not up to sync with head block yet - RETURN QUERY SELECT - NULL::NUMERIC, - NULL::INT - ; - ELSE - - RETURN QUERY SELECT - SUM( - CASE WHEN vests IS NULL THEN 0 ELSE ( - CASE WHEN approve IS TRUE THEN vests ELSE -1 * vests END - ) END - + - CASE WHEN proxied_vests IS NULL THEN 0 ELSE ( - CASE WHEN approve IS TRUE THEN proxied_vests ELSE -1 * proxied_vests END - ) END - ) AS votes, - SUM( - CASE WHEN approve IS TRUE THEN 1 ELSE -1 END - )::INT AS voters_num - FROM hafbe_app.witness_votes_history - - JOIN LATERAL ( - SELECT proxied_vests - FROM hafbe_backend.get_proxied_vests(voter_id) - ) prox_vests ON TRUE - - JOIN LATERAL ( - SELECT CASE WHEN proxy IS NULL THEN FALSE ELSE TRUE END AS proxied - FROM hafbe_app.current_account_proxies - WHERE account_id = voter_id AND proxy = TRUE - LIMIT 1 - ) is_prox ON TRUE - - LEFT JOIN LATERAL ( - SELECT vests - FROM hafbe_app.account_vests - WHERE account_id = voter_id - ) av ON proxied IS FALSE - - WHERE witness_id = _witness_id AND timestamp >= _today; - - END IF; -END -$function$ -LANGUAGE 'plpgsql' STABLE -SET JIT=OFF -SET join_collapse_limit=16 -SET from_collapse_limit=16 -; - CREATE TYPE hafbe_backend.witnesses AS ( witness TEXT, url TEXT, votes NUMERIC, - votes_daily_change NUMERIC, + votes_daily_change BIGINT, voters_num INT, voters_num_daily_change INT, price_feed TEXT, --JSON, @@ -618,12 +522,14 @@ BEGIN END IF; RETURN QUERY SELECT - hav.name::TEXT, + hav.name::TEXT AS witness, url, - CASE WHEN all_stats.votes IS NULL THEN 0 ELSE all_stats.votes END AS votes, - CASE WHEN todays_votes.votes IS NULL THEN 0 ELSE todays_votes.votes END AS votes_daily_change, - CASE WHEN all_stats.voters_num IS NULL THEN 0 ELSE all_stats.voters_num END voters_num, - CASE WHEN todays_votes.voters_num IS NULL THEN 0 ELSE todays_votes.voters_num END voters_num_daily_change, + all_votes.votes::NUMERIC AS votes, + --todays_votes.votes::BIGINT AS votes_daily_change, + 0::BIGINT, + all_votes.voters_num::INT AS voters_num, + --todays_votes.voters_num::INT AS voters_num_daily_change, + 0::INT, feed_data->>'exchange_rate' AS price_feed, --(feed_data->'exchange_rate'->'quote'->>'amount')::INT - 1000 AS bias 0 AS bias, @@ -631,25 +537,24 @@ BEGIN block_size::INT AS block_size, signing_key, '1.25.0' AS version - FROM ( + FROM hafbe_app.current_witnesses + + JOIN LATERAL ( SELECT - witness_id, - CASE WHEN all_votes.votes IS NULL THEN 0 ELSE all_votes.votes END AS votes, - CASE WHEN all_votes.voters_num IS NULL THEN 0 ELSE all_votes.voters_num END AS voters_num - FROM hafbe_app.current_witnesses - JOIN LATERAL ( - SELECT _votes AS votes, _voters_num AS voters_num - FROM hafbe_backend.get_witness_votes(witness_id) - ) all_votes ON TRUE - - ORDER BY votes DESC - LIMIT _limit - ) all_stats + SUM(account_vests + proxied_vests) AS votes, + COUNT(*) AS voters_num + FROM hafbe_backend.get_set_of_voters_stats(witness_id) + ) all_votes ON TRUE + /* JOIN LATERAL ( - SELECT _votes AS votes, _voters_num AS voters_num - FROM hafbe_backend.get_witness_votes_change(witness_id, __today) + SELECT + SUM(account_vests + proxied_vests) AS votes, + COUNT(*) AS voters_num + FROM hafbe_backend.get_set_of_voters_stats(witness_id) + WHERE timestamp >= __today ) todays_votes ON TRUE + */ JOIN ( SELECT name, id @@ -670,7 +575,10 @@ BEGIN JOIN LATERAL( SELECT hafbe_backend.parse_and_unpack_witness_data(witness_id, 'signing_key', '{42,11}')->>'signing_key' AS signing_key - ) wd_key ON TRUE; + ) wd_key ON TRUE + + ORDER BY all_votes.votes DESC + LIMIT _limit; END $function$ LANGUAGE 'plpgsql' STABLE diff --git a/db/hafbe_app.sql b/db/hafbe_app.sql index 7890a50..e775f88 100644 --- a/db/hafbe_app.sql +++ b/db/hafbe_app.sql @@ -100,11 +100,22 @@ BEGIN CONSTRAINT pk_account_operation_cache PRIMARY KEY (account_id, op_type_id) ) INHERITS (hive.hafbe_app); + CREATE TABLE IF NOT EXISTS hafbe_app.balance_impacting_op_ids ( + op_type_id INT NOT NULL, + + CONSTRAINT pk_balance_impacting_op_ids PRIMARY KEY(op_type_id) + ); + + INSERT INTO hafbe_app.balance_impacting_op_ids (op_type_id) + SELECT hot.id + FROM hive.operation_types hot + WHERE hot.name IN (SELECT * FROM hive.get_balance_impacting_operations()); + CREATE TABLE IF NOT EXISTS hafbe_app.account_vests ( account_id INT NOT NULL, vests BIGINT NOT NULL, - CONSTRAINT pk_account_vests_account PRIMARY KEY (account_id) + CONSTRAINT pk_account_vests PRIMARY KEY (account_id) ) INHERITS (hive.hafbe_app); CREATE INDEX IF NOT EXISTS account_vests_vests ON hafbe_app.account_vests USING btree (vests); @@ -191,6 +202,7 @@ DECLARE __proxy_op RECORD; __vote_op RECORD; __balance_change RECORD; + __balance_impacting_ops INT[] = (SELECT array_agg(op_type_id) FROM hafbe_app.balance_impacting_op_ids); BEGIN -- main processing loop FOR b IN _from .. _to @@ -260,15 +272,9 @@ BEGIN -- get impacted vests balance for block range and update account_vests FOR __balance_change IN - WITH balance_impacting_ops AS ( - SELECT hot.id - FROM hive.operation_types hot - WHERE hot.name IN (SELECT * FROM hive.get_balance_impacting_operations()) - ) - SELECT bio.account_name AS account, bio.amount AS vests FROM hive.btracker_app_operations_view hov - JOIN balance_impacting_ops b ON hov.op_type_id = b.id + JOIN LATERAL ( SELECT account_name, amount FROM hive.get_impacted_balances( @@ -279,18 +285,19 @@ BEGIN ) WHERE asset_symbol_nai = 37 ) bio ON TRUE - WHERE hov.block_num BETWEEN _from AND _to + + WHERE hov.op_type_id = ANY(__balance_impacting_ops) AND hov.block_num BETWEEN _from AND _to ORDER BY hov.block_num, hov.id - LOOP - INSERT INTO hafbe_app.account_vests (account_id, vests) - SELECT hav.id, __balance_change.vests - FROM hive.btracker_app_accounts_view hav - WHERE hav.name = __balance_change.account + LOOP + INSERT INTO hafbe_app.account_vests (account_id, vests) + SELECT hav.id, __balance_change.vests + FROM hive.btracker_app_accounts_view hav + WHERE hav.name = __balance_change.account - ON CONFLICT ON CONSTRAINT pk_account_vests_account DO - UPDATE SET vests = hafbe_app.account_vests.vests + EXCLUDED.vests; - END LOOP; + ON CONFLICT ON CONSTRAINT pk_account_vests DO + UPDATE SET vests = hafbe_app.account_vests.vests + EXCLUDED.vests; + END LOOP; END $$ SET from_collapse_limit = 16 -- GitLab From 7782efed0d59a2199801c533db80f8e53ed038a2 Mon Sep 17 00:00:00 2001 From: kristupas Date: Thu, 25 Aug 2022 12:11:45 +0000 Subject: [PATCH 36/89] Created 'get_set_of_voters_stats_change()' #22 --- api/backend.sql | 70 +++++++++++++++++++++++++++++++++++++++++------- db/hafbe_app.sql | 2 ++ 2 files changed, 62 insertions(+), 10 deletions(-) diff --git a/api/backend.sql b/api/backend.sql index d2f6c35..970fe71 100644 --- a/api/backend.sql +++ b/api/backend.sql @@ -491,6 +491,61 @@ END $$ ; +CREATE TYPE hafbe_backend.voters_stats_change AS ( + votes BIGINT, + voters_num INT +); + +CREATE FUNCTION hafbe_backend.get_set_of_voters_stats_change(_witness_id INT, _today DATE) +RETURNS SETOF hafbe_backend.voters_stats_change +AS +$function$ +BEGIN + IF _today IS NULL THEN + RETURN QUERY SELECT 0::INT, 0::INT; + ELSE + RETURN QUERY SELECT + SUM( + COALESCE(CASE WHEN acc_as_proxy.proxy IS FALSE THEN -1 * proxied.vests ELSE proxied.vests END, 0) + + + COALESCE(CASE WHEN acc_as_proxied.proxy IS FALSE THEN account.vests ELSE 0 END, 0) + )::BIGINT, + CASE WHEN wvh.approve IS FALSE THEN -1 ELSE 1 END + FROM hafbe_app.witness_votes_history wvh + + LEFT JOIN ( + SELECT account_id, proxy_id, proxy + FROM hafbe_app.account_proxies_history + WHERE timestamp >= _today + ) acc_as_proxy ON acc_as_proxy.proxy_id = wvh.voter_id + + LEFT JOIN ( + SELECT vests, account_id + FROM hafbe_app.account_vests + ) proxied ON proxied.account_id = acc_as_proxy.account_id + + LEFT JOIN ( + SELECT account_id, proxy + FROM hafbe_app.account_proxies_history + WHERE timestamp >= _today + ) acc_as_proxied ON acc_as_proxied.account_id = wvh.voter_id + + LEFT JOIN ( + SELECT vests, account_id + FROM hafbe_app.account_vests + ) account ON account.account_id = acc_as_proxied.account_id + + WHERE wvh.witness_id = _witness_id AND wvh.timestamp >= _today + GROUP BY wvh.voter_id, wvh.timestamp, wvh.approve; + END IF; +END +$function$ +LANGUAGE 'plpgsql' STABLE +SET JIT=OFF +SET join_collapse_limit=16 +SET from_collapse_limit=16 +; + CREATE TYPE hafbe_backend.witnesses AS ( witness TEXT, url TEXT, @@ -525,11 +580,9 @@ BEGIN hav.name::TEXT AS witness, url, all_votes.votes::NUMERIC AS votes, - --todays_votes.votes::BIGINT AS votes_daily_change, - 0::BIGINT, + COALESCE(todays_votes.votes, 0)::BIGINT AS votes_daily_change, all_votes.voters_num::INT AS voters_num, - --todays_votes.voters_num::INT AS voters_num_daily_change, - 0::INT, + COALESCE(todays_votes.voters_num, 0)::INT AS voters_num_daily_change, feed_data->>'exchange_rate' AS price_feed, --(feed_data->'exchange_rate'->'quote'->>'amount')::INT - 1000 AS bias 0 AS bias, @@ -546,15 +599,12 @@ BEGIN FROM hafbe_backend.get_set_of_voters_stats(witness_id) ) all_votes ON TRUE - /* JOIN LATERAL ( SELECT - SUM(account_vests + proxied_vests) AS votes, - COUNT(*) AS voters_num - FROM hafbe_backend.get_set_of_voters_stats(witness_id) - WHERE timestamp >= __today + SUM(votes) AS votes, + SUM(voters_num) AS voters_num + FROM hafbe_backend.get_set_of_voters_stats_change(witness_id, __today) ) todays_votes ON TRUE - */ JOIN ( SELECT name, id diff --git a/db/hafbe_app.sql b/db/hafbe_app.sql index e775f88..98a13f1 100644 --- a/db/hafbe_app.sql +++ b/db/hafbe_app.sql @@ -44,6 +44,8 @@ BEGIN timestamp TIMESTAMP NOT NULL ) INHERITS (hive.hafbe_app); + CREATE INDEX IF NOT EXISTS witness_votes_history_witness_id_timestamp ON hafbe_app.witness_votes_history USING btree (witness_id, timestamp); + CREATE TABLE IF NOT EXISTS hafbe_app.current_witness_votes ( witness_id INT NOT NULL, voter_id INT NOT NULL, -- GitLab From 58161cd31b7d999dbfad197c49dbc61afd3bca0e Mon Sep 17 00:00:00 2001 From: kristupas Date: Mon, 5 Sep 2022 21:06:29 +0200 Subject: [PATCH 37/89] Moved 'get_voter_stats' functions to views #22 --- api/backend.sql | 164 +++++++++-------------------------------------- db/hafbe_app.sql | 105 ++++++++++++++++++++++++++++-- 2 files changed, 130 insertions(+), 139 deletions(-) diff --git a/api/backend.sql b/api/backend.sql index 970fe71..e4170e3 100644 --- a/api/backend.sql +++ b/api/backend.sql @@ -378,56 +378,6 @@ $$ witnesses and voters */ -CREATE TYPE hafbe_backend.voters_stats AS ( - voter_id INT, - account_vests NUMERIC, - proxied_vests NUMERIC, - timestamp TIMESTAMP -); - -CREATE FUNCTION hafbe_backend.get_set_of_voters_stats(_witness_id INT) -RETURNS SETOF hafbe_backend.voters_stats -AS -$function$ -BEGIN - RETURN QUERY SELECT - cwv.voter_id, - SUM(COALESCE(account.vests, 0)) AS account_vests, - SUM(COALESCE(proxied.vests, 0)) AS proxied_vests, - cwv.timestamp - FROM hafbe_app.current_witness_votes cwv - - LEFT JOIN ( - SELECT account_id, proxy_id - FROM hafbe_app.current_account_proxies - WHERE proxy = TRUE - ) acc_as_proxy ON acc_as_proxy.proxy_id = cwv.voter_id - - LEFT JOIN ( - SELECT vests, account_id - FROM hafbe_app.account_vests - ) proxied ON proxied.account_id = acc_as_proxy.account_id - - LEFT JOIN ( - SELECT account_id, proxy - FROM hafbe_app.current_account_proxies - ) acc_as_proxied ON acc_as_proxied.account_id = cwv.voter_id - - LEFT JOIN ( - SELECT vests, account_id - FROM hafbe_app.account_vests - ) account ON account.account_id = acc_as_proxied.account_id AND COALESCE(acc_as_proxied.proxy, FALSE) IS FALSE - - WHERE cwv.witness_id = _witness_id AND cwv.approve = TRUE - GROUP BY cwv.voter_id, cwv.timestamp; -END -$function$ -LANGUAGE 'plpgsql' STABLE -SET JIT=OFF -SET join_collapse_limit=16 -SET from_collapse_limit=16 -; - CREATE TYPE hafbe_backend.witness_voters AS ( account TEXT, vests NUMERIC, @@ -444,21 +394,20 @@ BEGIN RETURN QUERY EXECUTE format( $query$ - SELECT account, vests, account_vests, proxied_vests, timestamp - FROM ( - SELECT - hav.name::TEXT AS account, - proxied_vests + account_vests AS vests, - account_vests, - proxied_vests, - timestamp - FROM hafbe_backend.get_set_of_voters_stats(%L) - - JOIN ( - SELECT name, id - FROM hive.accounts_view - ) hav ON hav.id = voter_id - ) voters_stats + SELECT name::TEXT, vsv.vests, vsv.account_vests, vsv.proxied_vests, vsv.timestamp + FROM hive.accounts_view + + JOIN ( + SELECT voter_id + FROM hafbe_app.current_witness_votes + WHERE witness_id = 440 + ) cwv ON cwv.voter_id = id + + JOIN ( + SELECT voter_id, proxied_vests + account_vests AS vests, account_vests, proxied_vests, timestamp + FROM hafbe_app.voters_stats_view + WHERE witness_id = %L + ) vsv ON vsv.voter_id = id ORDER BY (CASE WHEN %L = 'desc' THEN %I ELSE NULL END) DESC, @@ -491,61 +440,6 @@ END $$ ; -CREATE TYPE hafbe_backend.voters_stats_change AS ( - votes BIGINT, - voters_num INT -); - -CREATE FUNCTION hafbe_backend.get_set_of_voters_stats_change(_witness_id INT, _today DATE) -RETURNS SETOF hafbe_backend.voters_stats_change -AS -$function$ -BEGIN - IF _today IS NULL THEN - RETURN QUERY SELECT 0::INT, 0::INT; - ELSE - RETURN QUERY SELECT - SUM( - COALESCE(CASE WHEN acc_as_proxy.proxy IS FALSE THEN -1 * proxied.vests ELSE proxied.vests END, 0) - + - COALESCE(CASE WHEN acc_as_proxied.proxy IS FALSE THEN account.vests ELSE 0 END, 0) - )::BIGINT, - CASE WHEN wvh.approve IS FALSE THEN -1 ELSE 1 END - FROM hafbe_app.witness_votes_history wvh - - LEFT JOIN ( - SELECT account_id, proxy_id, proxy - FROM hafbe_app.account_proxies_history - WHERE timestamp >= _today - ) acc_as_proxy ON acc_as_proxy.proxy_id = wvh.voter_id - - LEFT JOIN ( - SELECT vests, account_id - FROM hafbe_app.account_vests - ) proxied ON proxied.account_id = acc_as_proxy.account_id - - LEFT JOIN ( - SELECT account_id, proxy - FROM hafbe_app.account_proxies_history - WHERE timestamp >= _today - ) acc_as_proxied ON acc_as_proxied.account_id = wvh.voter_id - - LEFT JOIN ( - SELECT vests, account_id - FROM hafbe_app.account_vests - ) account ON account.account_id = acc_as_proxied.account_id - - WHERE wvh.witness_id = _witness_id AND wvh.timestamp >= _today - GROUP BY wvh.voter_id, wvh.timestamp, wvh.approve; - END IF; -END -$function$ -LANGUAGE 'plpgsql' STABLE -SET JIT=OFF -SET join_collapse_limit=16 -SET from_collapse_limit=16 -; - CREATE TYPE hafbe_backend.witnesses AS ( witness TEXT, url TEXT, @@ -590,44 +484,48 @@ BEGIN block_size::INT AS block_size, signing_key, '1.25.0' AS version - FROM hafbe_app.current_witnesses + FROM hafbe_app.current_witnesses cw - JOIN LATERAL ( + JOIN ( SELECT - SUM(account_vests + proxied_vests) AS votes, - COUNT(*) AS voters_num - FROM hafbe_backend.get_set_of_voters_stats(witness_id) + SUM(votes) AS votes, + SUM(voters_num) AS voters_num + FROM hafbe_app.voters_stats_view + GROUP BY witness_id ) all_votes ON TRUE - JOIN LATERAL ( + LEFT JOIN ( SELECT SUM(votes) AS votes, SUM(voters_num) AS voters_num - FROM hafbe_backend.get_set_of_voters_stats_change(witness_id, __today) + FROM hafbe_app.voters_stats_change_view + WHERE timestamp >= _today + GROUP BY witness_id ) todays_votes ON TRUE JOIN ( SELECT name, id FROM hive.accounts_view - ) hav ON hav.id = witness_id + ) hav ON hav.id = cw.witness_id JOIN LATERAL( - SELECT hafbe_backend.parse_and_unpack_witness_data(witness_id, 'url', '{42,11}')->>'url' AS url + SELECT hafbe_backend.parse_and_unpack_witness_data(cw.witness_id, 'url', '{42,11}')->>'url' AS url ) wd_url ON TRUE JOIN LATERAL( - SELECT hafbe_backend.parse_and_unpack_witness_data(witness_id, 'exchange_rate', '{42,7}') AS feed_data + SELECT hafbe_backend.parse_and_unpack_witness_data(cw.witness_id, 'exchange_rate', '{42,7}') AS feed_data ) wd_rate ON TRUE JOIN LATERAL( - SELECT hafbe_backend.parse_and_unpack_witness_data(witness_id, 'maximum_block_size', '{42,30,14,11}')->>'maximum_block_size' AS block_size + SELECT hafbe_backend.parse_and_unpack_witness_data(cw.witness_id, 'maximum_block_size', '{42,30,14,11}')->>'maximum_block_size' AS block_size ) wd_size ON TRUE JOIN LATERAL( - SELECT hafbe_backend.parse_and_unpack_witness_data(witness_id, 'signing_key', '{42,11}')->>'signing_key' AS signing_key + SELECT hafbe_backend.parse_and_unpack_witness_data(cw.witness_id, 'signing_key', '{42,11}')->>'signing_key' AS signing_key ) wd_key ON TRUE - ORDER BY all_votes.votes DESC + GROUP BY cw.witness_id + LIMIT _limit; END $function$ diff --git a/db/hafbe_app.sql b/db/hafbe_app.sql index 98a13f1..c6b8106 100644 --- a/db/hafbe_app.sql +++ b/db/hafbe_app.sql @@ -122,6 +122,99 @@ BEGIN CREATE INDEX IF NOT EXISTS account_vests_vests ON hafbe_app.account_vests USING btree (vests); + CREATE VIEW hafbe_app.voters_stats_view AS + SELECT + witness_id, + voter_id, + COALESCE(account.vests, 0)::NUMERIC AS account_vests, + proxied_vests::NUMERIC, + timestamp + FROM ( + SELECT + witness_id AS witness_id, + voter_id AS voter_id, + COALESCE(acc_as_proxied.proxy, FALSE) AS proxy, + SUM(COALESCE(proxied.vests, 0)) AS proxied_vests, + timestamp AS timestamp + FROM hafbe_app.current_witness_votes + + LEFT JOIN ( + SELECT account_id, proxy_id + FROM hafbe_app.current_account_proxies + WHERE proxy = TRUE + ) acc_as_proxy ON acc_as_proxy.proxy_id = voter_id + + LEFT JOIN ( + SELECT vests, account_id + FROM hafbe_app.account_vests + ) proxied ON proxied.account_id = acc_as_proxy.account_id + + LEFT JOIN ( + SELECT account_id, proxy + FROM hafbe_app.current_account_proxies + ) acc_as_proxied ON acc_as_proxied.account_id = voter_id + + WHERE approve IS TRUE + + GROUP BY witness_id, voter_id, acc_as_proxied.proxy + ) proxy_ops + + LEFT JOIN ( + SELECT vests, account_id + FROM hafbe_app.account_vests + ) account ON account.account_id = voter_id AND proxy IS FALSE + ; + + CREATE VIEW hafbe_app.voters_stats_change_view AS + SELECT + witness_id, + SUM(account_vests + proxied_vests) AS votes, + SUM(approve) AS voters_num, + timestamp + FROM ( + SELECT + witness_id, + CASE WHEN approve IS FALSE THEN -1 ELSE 1 END AS approve, + SUM( + CASE WHEN COALESCE(acc_as_proxy.proxy, FALSE) IS TRUE THEN + COALESCE(proxied.vests, 0) + ELSE + -1 * COALESCE(proxied.vests, 0) + END + ) AS proxied_vests, + CASE WHEN COALESCE(acc_as_proxied.proxy, FALSE) IS FALSE THEN + COALESCE(account.vests, 0) + ELSE + -1 * COALESCE(account.vests, 0) + END AS account_vests, + timestamp + FROM hafbe_app.witness_votes_history + + LEFT JOIN ( + SELECT account_id, proxy_id, proxy + FROM hafbe_app.account_proxies_history + ) acc_as_proxy ON acc_as_proxy.proxy_id = voter_id + + LEFT JOIN ( + SELECT vests, account_id + FROM hafbe_app.account_vests + ) proxied ON proxied.account_id = acc_as_proxy.account_id + + LEFT JOIN ( + SELECT account_id, proxy + FROM hafbe_app.account_proxies_history + ) acc_as_proxied ON acc_as_proxied.account_id = voter_id + + LEFT JOIN ( + SELECT vests, account_id + FROM hafbe_app.account_vests + ) account ON account.account_id = voter_id + + GROUP BY witness_id, approve, account_vests, timestamp + ) proxy_ops + + GROUP BY witness_id, timestamp; + --ALTER SCHEMA hafbe_app OWNER TO hafbe_owner; END $$ @@ -190,7 +283,7 @@ LANGUAGE 'plpgsql' AS $$ BEGIN - RETURN id FROM hive.btracker_app_accounts_view WHERE name = _account; + RETURN id FROM hive.hafbe_app_accounts_view WHERE name = _account; END $$ ; @@ -214,7 +307,7 @@ BEGIN hafbe_app.get_account_id((body::JSON)->'value'->>'account') AS voter_id, ((body::JSON)->'value'->>'approve')::BOOLEAN AS approve, timestamp - FROM hive.btracker_app_operations_view + FROM hive.hafbe_app_operations_view WHERE op_type_id = 12 AND block_num = b; IF __vote_op.witness_id IS NOT NULL THEN @@ -239,7 +332,7 @@ BEGIN hafbe_app.get_account_id((body::JSON)->'value'->>'account') AS account_id, hafbe_app.get_account_id((body::JSON)->'value'->>'proxy') AS proxy_id, timestamp - FROM hive.btracker_app_operations_view + FROM hive.hafbe_app_operations_view WHERE op_type_id = 13 AND block_num = b; IF __proxy_op.account_id IS NOT NULL THEN @@ -267,7 +360,7 @@ BEGIN INSERT INTO hafbe_app.account_operation_cache (account_id, op_type_id) SELECT account_id, op_type_id - FROM hive.btracker_app_account_operations_view + FROM hive.hafbe_app_account_operations_view WHERE block_num = b ON CONFLICT ON CONSTRAINT pk_account_operation_cache DO NOTHING; END LOOP; @@ -275,7 +368,7 @@ BEGIN -- get impacted vests balance for block range and update account_vests FOR __balance_change IN SELECT bio.account_name AS account, bio.amount AS vests - FROM hive.btracker_app_operations_view hov + FROM hive.hafbe_app_operations_view hov JOIN LATERAL ( SELECT account_name, amount @@ -294,7 +387,7 @@ BEGIN LOOP INSERT INTO hafbe_app.account_vests (account_id, vests) SELECT hav.id, __balance_change.vests - FROM hive.btracker_app_accounts_view hav + FROM hive.hafbe_app_accounts_view hav WHERE hav.name = __balance_change.account ON CONFLICT ON CONSTRAINT pk_account_vests DO -- GitLab From e405b3352fe94bc1cefd049f93abfb60d88d1f74 Mon Sep 17 00:00:00 2001 From: kristupas Date: Tue, 6 Sep 2022 14:44:10 +0200 Subject: [PATCH 38/89] Moved views to 'views.sql', removed LATERAL JOIN for function calls #22 --- api/backend.sql | 93 +++++++++++++++++++++--------------------------- api/views.sql | 68 +++++++++++++++++++++++++++++++++++ db/hafbe_app.sql | 93 ------------------------------------------------ 3 files changed, 109 insertions(+), 145 deletions(-) create mode 100644 api/views.sql diff --git a/api/backend.sql b/api/backend.sql index e4170e3..138f855 100644 --- a/api/backend.sql +++ b/api/backend.sql @@ -405,7 +405,7 @@ BEGIN JOIN ( SELECT voter_id, proxied_vests + account_vests AS vests, account_vests, proxied_vests, timestamp - FROM hafbe_app.voters_stats_view + FROM hafbe_views.voters_stats_view WHERE witness_id = %L ) vsv ON vsv.voter_id = id @@ -471,61 +471,50 @@ BEGIN END IF; RETURN QUERY SELECT - hav.name::TEXT AS witness, - url, - all_votes.votes::NUMERIC AS votes, - COALESCE(todays_votes.votes, 0)::BIGINT AS votes_daily_change, - all_votes.voters_num::INT AS voters_num, - COALESCE(todays_votes.voters_num, 0)::INT AS voters_num_daily_change, + witness, URL, votes, votes_daily_change, voters_num, voters_num_daily_change, feed_data->>'exchange_rate' AS price_feed, - --(feed_data->'exchange_rate'->'quote'->>'amount')::INT - 1000 AS bias - 0 AS bias, + 0 AS bias, --(feed_data->'exchange_rate'->'quote'->>'amount')::INT - 1000 AS bias (NOW() - (feed_data->>'timestamp')::TIMESTAMP)::INTERVAL AS feed_age, - block_size::INT AS block_size, - signing_key, + block_size, signing_key, '1.25.0' AS version - FROM hafbe_app.current_witnesses cw - - JOIN ( + FROM ( SELECT - SUM(votes) AS votes, - SUM(voters_num) AS voters_num - FROM hafbe_app.voters_stats_view - GROUP BY witness_id - ) all_votes ON TRUE + hav.name::TEXT AS witness, + (SELECT hafbe_backend.parse_and_unpack_witness_data(cw.witness_id, 'url', '{42,11}')->>'url') AS url, + all_votes.votes::NUMERIC AS votes, + COALESCE(todays_votes.votes, 0)::BIGINT AS votes_daily_change, + all_votes.voters_num::INT AS voters_num, + COALESCE(todays_votes.voters_num, 0)::INT AS voters_num_daily_change, + (SELECT hafbe_backend.parse_and_unpack_witness_data(cw.witness_id, 'exchange_rate', '{42,7}')) AS feed_data, + (SELECT hafbe_backend.parse_and_unpack_witness_data(cw.witness_id, 'maximum_block_size', '{42,30,14,11}')->>'maximum_block_size')::INT AS block_size, + (SELECT hafbe_backend.parse_and_unpack_witness_data(cw.witness_id, 'signing_key', '{42,11}')->>'signing_key') AS signing_key + FROM hafbe_app.current_witnesses cw - LEFT JOIN ( - SELECT - SUM(votes) AS votes, - SUM(voters_num) AS voters_num - FROM hafbe_app.voters_stats_change_view - WHERE timestamp >= _today - GROUP BY witness_id - ) todays_votes ON TRUE + JOIN ( + SELECT + witness_id, + SUM(account_vests + proxied_vests) AS votes, + COUNT(voter_id) AS voters_num + FROM hafbe_views.voters_stats_view + GROUP BY witness_id + ) all_votes ON all_votes.witness_id = cw.witness_id + + LEFT JOIN ( + SELECT + witness_id, + SUM(CASE WHEN approve IS TRUE THEN votes ELSE -1 * votes END) AS votes, + SUM(CASE WHEN approve IS TRUE THEN 1 ELSE -1 END) AS voters_num + FROM hafbe_views.voters_stats_change_view + WHERE timestamp >= __today + GROUP BY witness_id + ) todays_votes ON todays_votes.witness_id = cw.witness_id - JOIN ( - SELECT name, id - FROM hive.accounts_view - ) hav ON hav.id = cw.witness_id - - JOIN LATERAL( - SELECT hafbe_backend.parse_and_unpack_witness_data(cw.witness_id, 'url', '{42,11}')->>'url' AS url - ) wd_url ON TRUE - - JOIN LATERAL( - SELECT hafbe_backend.parse_and_unpack_witness_data(cw.witness_id, 'exchange_rate', '{42,7}') AS feed_data - ) wd_rate ON TRUE - - JOIN LATERAL( - SELECT hafbe_backend.parse_and_unpack_witness_data(cw.witness_id, 'maximum_block_size', '{42,30,14,11}')->>'maximum_block_size' AS block_size - ) wd_size ON TRUE - - JOIN LATERAL( - SELECT hafbe_backend.parse_and_unpack_witness_data(cw.witness_id, 'signing_key', '{42,11}')->>'signing_key' AS signing_key - ) wd_key ON TRUE - - GROUP BY cw.witness_id - + JOIN ( + SELECT name, id + FROM hive.accounts_view + ) hav ON hav.id = cw.witness_id + ) votes_stats + ORDER BY votes DESC LIMIT _limit; END $function$ @@ -619,8 +608,8 @@ BEGIN FROM hive.account_operations_view WHERE account_id = _witness_id AND op_type_id = ANY(_op_type_array) ORDER BY operation_id DESC - ) haov ON haov.operation_id = id - LIMIT 1; + LIMIT 1 + ) haov ON haov.operation_id = id; IF _attr_name = 'url' THEN SELECT __most_recent_op.value->>'url' INTO __result; diff --git a/api/views.sql b/api/views.sql new file mode 100644 index 0000000..3c9075a --- /dev/null +++ b/api/views.sql @@ -0,0 +1,68 @@ +CREATE SCHEMA IF NOT EXISTS hafbe_views; + +DROP VIEW IF EXISTS hafbe_views.voters_stats_view; +CREATE VIEW hafbe_views.voters_stats_view AS +SELECT + witness_id, voter_id, timestamp, + COALESCE(account.vests, 0)::NUMERIC AS account_vests, + SUM(COALESCE(proxied.vests, 0)) AS proxied_vests +FROM hafbe_app.current_witness_votes + +LEFT JOIN ( + SELECT account_id, proxy_id + FROM hafbe_app.current_account_proxies + WHERE proxy = TRUE +) acc_as_proxy ON acc_as_proxy.proxy_id = voter_id + +LEFT JOIN ( + SELECT vests, account_id + FROM hafbe_app.account_vests +) proxied ON proxied.account_id = acc_as_proxy.account_id + +LEFT JOIN ( + SELECT account_id, proxy + FROM hafbe_app.current_account_proxies +) acc_as_proxied ON acc_as_proxied.account_id = voter_id + +LEFT JOIN ( + SELECT vests, account_id + FROM hafbe_app.account_vests +) account ON account.account_id = voter_id AND COALESCE(acc_as_proxied.proxy, FALSE) IS FALSE + +WHERE approve IS TRUE +GROUP BY witness_id, voter_id, account.vests; + +------ + +DROP VIEW IF EXISTS hafbe_views.voters_stats_change_view; +CREATE VIEW hafbe_views.voters_stats_change_view AS +SELECT + witness_id, voter_id, approve, timestamp, + ( + SUM(CASE WHEN acc_as_proxy.proxy IS TRUE THEN proxied.vests ELSE -1 * proxied.vests END) + + + CASE WHEN acc_as_proxied.proxy IS FALSE THEN account.vests ELSE -1 * account.vests END + ) AS votes +FROM hafbe_app.witness_votes_history + +LEFT JOIN ( + SELECT account_id, proxy_id, proxy + FROM hafbe_app.account_proxies_history +) acc_as_proxy ON acc_as_proxy.proxy_id = voter_id + +LEFT JOIN ( + SELECT vests, account_id + FROM hafbe_app.account_vests +) proxied ON proxied.account_id = acc_as_proxy.account_id + +LEFT JOIN ( + SELECT account_id, proxy + FROM hafbe_app.account_proxies_history +) acc_as_proxied ON acc_as_proxied.account_id = voter_id + +LEFT JOIN ( + SELECT vests, account_id + FROM hafbe_app.account_vests +) account ON account.account_id = acc_as_proxied.account_id + +GROUP BY witness_id, voter_id, approve, timestamp, acc_as_proxied.proxy, account.vests; \ No newline at end of file diff --git a/db/hafbe_app.sql b/db/hafbe_app.sql index c6b8106..56b3ee5 100644 --- a/db/hafbe_app.sql +++ b/db/hafbe_app.sql @@ -122,99 +122,6 @@ BEGIN CREATE INDEX IF NOT EXISTS account_vests_vests ON hafbe_app.account_vests USING btree (vests); - CREATE VIEW hafbe_app.voters_stats_view AS - SELECT - witness_id, - voter_id, - COALESCE(account.vests, 0)::NUMERIC AS account_vests, - proxied_vests::NUMERIC, - timestamp - FROM ( - SELECT - witness_id AS witness_id, - voter_id AS voter_id, - COALESCE(acc_as_proxied.proxy, FALSE) AS proxy, - SUM(COALESCE(proxied.vests, 0)) AS proxied_vests, - timestamp AS timestamp - FROM hafbe_app.current_witness_votes - - LEFT JOIN ( - SELECT account_id, proxy_id - FROM hafbe_app.current_account_proxies - WHERE proxy = TRUE - ) acc_as_proxy ON acc_as_proxy.proxy_id = voter_id - - LEFT JOIN ( - SELECT vests, account_id - FROM hafbe_app.account_vests - ) proxied ON proxied.account_id = acc_as_proxy.account_id - - LEFT JOIN ( - SELECT account_id, proxy - FROM hafbe_app.current_account_proxies - ) acc_as_proxied ON acc_as_proxied.account_id = voter_id - - WHERE approve IS TRUE - - GROUP BY witness_id, voter_id, acc_as_proxied.proxy - ) proxy_ops - - LEFT JOIN ( - SELECT vests, account_id - FROM hafbe_app.account_vests - ) account ON account.account_id = voter_id AND proxy IS FALSE - ; - - CREATE VIEW hafbe_app.voters_stats_change_view AS - SELECT - witness_id, - SUM(account_vests + proxied_vests) AS votes, - SUM(approve) AS voters_num, - timestamp - FROM ( - SELECT - witness_id, - CASE WHEN approve IS FALSE THEN -1 ELSE 1 END AS approve, - SUM( - CASE WHEN COALESCE(acc_as_proxy.proxy, FALSE) IS TRUE THEN - COALESCE(proxied.vests, 0) - ELSE - -1 * COALESCE(proxied.vests, 0) - END - ) AS proxied_vests, - CASE WHEN COALESCE(acc_as_proxied.proxy, FALSE) IS FALSE THEN - COALESCE(account.vests, 0) - ELSE - -1 * COALESCE(account.vests, 0) - END AS account_vests, - timestamp - FROM hafbe_app.witness_votes_history - - LEFT JOIN ( - SELECT account_id, proxy_id, proxy - FROM hafbe_app.account_proxies_history - ) acc_as_proxy ON acc_as_proxy.proxy_id = voter_id - - LEFT JOIN ( - SELECT vests, account_id - FROM hafbe_app.account_vests - ) proxied ON proxied.account_id = acc_as_proxy.account_id - - LEFT JOIN ( - SELECT account_id, proxy - FROM hafbe_app.account_proxies_history - ) acc_as_proxied ON acc_as_proxied.account_id = voter_id - - LEFT JOIN ( - SELECT vests, account_id - FROM hafbe_app.account_vests - ) account ON account.account_id = voter_id - - GROUP BY witness_id, approve, account_vests, timestamp - ) proxy_ops - - GROUP BY witness_id, timestamp; - --ALTER SCHEMA hafbe_app OWNER TO hafbe_owner; END $$ -- GitLab From cef378047051a2f22f857ead58813efb3d37ca4d Mon Sep 17 00:00:00 2001 From: kristupas Date: Wed, 7 Sep 2022 15:42:01 +0200 Subject: [PATCH 39/89] Moved witness props to 'current_witnesses' table #22 --- api/backend.sql | 107 +---------------------------- api/views.sql | 20 +++++- db/hafbe_app.sql | 175 +++++++++++++++++++++++++++++++++++++++++++++-- 3 files changed, 190 insertions(+), 112 deletions(-) diff --git a/api/backend.sql b/api/backend.sql index 138f855..15ef369 100644 --- a/api/backend.sql +++ b/api/backend.sql @@ -513,6 +513,7 @@ BEGIN SELECT name, id FROM hive.accounts_view ) hav ON hav.id = cw.witness_id + ) votes_stats ORDER BY votes DESC LIMIT _limit; @@ -539,112 +540,6 @@ END $$ ; -CREATE FUNCTION hafbe_backend.parse_witness_set_props(_op_value JSON, _attr_name TEXT) -RETURNS TEXT -LANGUAGE 'plpgsql' -AS -$$ -DECLARE - __result TEXT; -BEGIN - SELECT INTO __result - props->>1 - FROM ( - SELECT json_array_elements(_op_value->'props') AS props - ) to_arr - WHERE props->>0 = _attr_name; - - IF _attr_name = 'new_signing_key' AND __result IS NULL THEN - SELECT INTO __result - props->>1 - FROM ( - SELECT json_array_elements(_op_value->'props') AS props - ) to_arr - WHERE props->>0 = 'key'; - END IF; - - RETURN __result; -END -$$ -; - -CREATE FUNCTION hafbe_backend.unpack_from_vector(_vector TEXT) -RETURNS TEXT -LANGUAGE 'plpgsql' -AS -$$ -BEGIN - -- TODO: to be replaced by hive fork manager method - RETURN _vector; -END -$$ -; - -CREATE FUNCTION hafbe_backend.parse_and_unpack_witness_data(_witness_id INT, _attr_name TEXT, _op_type_array INT[], _last_op_id BIGINT = NULL) -RETURNS JSON -AS -$function$ -DECLARE - __most_recent_op RECORD; - __result TEXT; - __witness_set_props_attr_name TEXT; -BEGIN - IF _last_op_id <= 0 THEN - RETURN json_build_object ( - _attr_name, NULL - ); - END IF; - - IF _last_op_id IS NULL THEN - SELECT id FROM hive.operations_view ORDER BY id DESC LIMIT 1 INTO _last_op_id; - END IF; - - SELECT INTO __most_recent_op - (body::JSON)->'value' AS value, - op_type_id, id, timestamp - FROM hive.operations_view - JOIN ( - SELECT operation_id - FROM hive.account_operations_view - WHERE account_id = _witness_id AND op_type_id = ANY(_op_type_array) - ORDER BY operation_id DESC - LIMIT 1 - ) haov ON haov.operation_id = id; - - IF _attr_name = 'url' THEN - SELECT __most_recent_op.value->>'url' INTO __result; - SELECT 'url' INTO __witness_set_props_attr_name; - ELSIF _attr_name = 'exchange_rate' THEN - SELECT __most_recent_op.value->>'exchange_rate' INTO __result; - SELECT 'hbd_exchange_rate' INTO __witness_set_props_attr_name; - ELSIF _attr_name = 'maximum_block_size' THEN - SELECT __most_recent_op.value->'props'->>'maximum_block_size' INTO __result; - SELECT 'maximum_block_size' INTO __witness_set_props_attr_name; - ELSIF _attr_name = 'signing_key' THEN - SELECT __most_recent_op.value->>'block_signing_key' INTO __result; - SELECT 'new_signing_key' INTO __witness_set_props_attr_name; - END IF; - - IF __result IS NULL AND __most_recent_op.op_type_id = 42 THEN - SELECT hafbe_backend.parse_witness_set_props(__most_recent_op.value, __witness_set_props_attr_name) INTO __result; - ELSIF __result IS NULL AND __most_recent_op.op_type_id != 42 THEN - RETURN hafbe_backend.parse_and_unpack_witness_data( - _witness_id, __witness_set_props_attr_name, _op_type_array, __most_recent_op.id - 1) - ; - END IF; - - RETURN json_build_object( - _attr_name, __result, - 'timestamp', __most_recent_op.timestamp - ); -END -$function$ -LANGUAGE 'plpgsql' STABLE -SET JIT=OFF -SET join_collapse_limit=16 -SET from_collapse_limit=16 -; - /* account data */ diff --git a/api/views.sql b/api/views.sql index 3c9075a..da01e28 100644 --- a/api/views.sql +++ b/api/views.sql @@ -65,4 +65,22 @@ LEFT JOIN ( FROM hafbe_app.account_vests ) account ON account.account_id = acc_as_proxied.account_id -GROUP BY witness_id, voter_id, approve, timestamp, acc_as_proxied.proxy, account.vests; \ No newline at end of file +GROUP BY witness_id, voter_id, approve, timestamp, acc_as_proxied.proxy, account.vests; + +----- + +DROP VIEW IF EXISTS hafbe_views.witness_prop_op_view; +CREATE VIEW hafbe_views.witness_prop_op_view AS +SELECT + account_id AS witness_id, + (hov.body::JSON)->'value' AS value, + hov.timestamp AS timestamp, + block_num, op_type_id, operation_id +FROM hive.account_operations_view haov + +JOIN ( + SELECT body, id, timestamp + FROM hive.operations_view +) hov ON hov.id = haov.operation_id + +ORDER BY operation_id DESC; \ No newline at end of file diff --git a/db/hafbe_app.sql b/db/hafbe_app.sql index 56b3ee5..c977a73 100644 --- a/db/hafbe_app.sql +++ b/db/hafbe_app.sql @@ -57,10 +57,20 @@ BEGIN CREATE INDEX IF NOT EXISTS current_witness_votes_witness_id_approve ON hafbe_app.current_witness_votes USING btree (witness_id, approve); + CREATE TABLE IF NOT EXISTS hafbe_app.witness_prop_types ( + prop_type_id SERIAL PRIMARY KEY, + prop_name TEXT NOT NULL + ); + + INSERT INTO hafbe_app.witness_prop_types (prop_name) VALUES + ('url'), ('price_feed'), ('bias'), ('feed_age'), ('block_size'), ('signing_key'), ('version'); + CREATE TABLE IF NOT EXISTS hafbe_app.current_witnesses ( witness_id INT NOT NULL, + prop_type_id INT NOT NULL, + prop_value TEXT NOT NULL, - CONSTRAINT pk_current_witnesses PRIMARY KEY (witness_id) + CONSTRAINT pk_current_witnesses PRIMARY KEY (witness_id, prop_type_id) ) INHERITS (hive.hafbe_app); CREATE TABLE IF NOT EXISTS hafbe_app.account_proxies_history ( @@ -195,12 +205,55 @@ END $$ ; +CREATE OR REPLACE FUNCTION hafbe_app.unpack_from_vector(_vector TEXT) +RETURNS TEXT +LANGUAGE 'plpgsql' +AS +$$ +BEGIN + -- TODO: to be replaced by hive fork manager method + RETURN _vector; +END +$$ +; + +CREATE OR REPLACE FUNCTION hafbe_app.parse_witness_set_props(_op_value JSON, _attr_name TEXT) +RETURNS TEXT +LANGUAGE 'plpgsql' +AS +$$ +DECLARE + __result TEXT; +BEGIN + SELECT INTO __result + props->>1 + FROM ( + SELECT json_array_elements(_op_value->'props') AS props + ) to_arr + WHERE props->>0 = _attr_name; + + IF _attr_name = 'new_signing_key' AND __result IS NULL THEN + SELECT INTO __result + props->>1 + FROM ( + SELECT json_array_elements(_op_value->'props') AS props + ) to_arr + WHERE props->>0 = 'key'; + END IF; + + RETURN hafbe_app.unpack_from_vector(__result); +END +$$ +; + CREATE OR REPLACE FUNCTION hafbe_app.process_block_range_data_c(_from INT, _to INT, _report_step INT = 1000) RETURNS VOID LANGUAGE 'plpgsql' AS $$ DECLARE + __prop_value TEXT; + __prop_op RECORD; __proxy_op RECORD; __vote_op RECORD; __balance_change RECORD; @@ -209,6 +262,122 @@ BEGIN -- main processing loop FOR b IN _from .. _to LOOP + -- parse witness url + FOR __prop_op IN + SELECT witness_id, value, op_type_id + FROM hafbe_views.witness_prop_op_view + WHERE block_num = b AND op_type_id = ANY('{42,11}'::INT[]) + + LOOP + IF __prop_op.op_type_id = 42 THEN + SELECT hafbe_app.parse_witness_set_props(__prop_op.value, 'url') INTO __prop_value; + ELSE + SELECT __prop_op.value->>'url' INTO __prop_value; + END IF; + + IF __prop_value IS NOT NULL THEN + INSERT INTO hafbe_app.current_witnesses (witness_id, prop_type_id, prop_value) + SELECT + __prop_op.witness_id, + (SELECT prop_type_id FROM hafbe_app.witness_prop_types WHERE prop_name = 'url'), + __prop_value + ON CONFLICT ON CONSTRAINT pk_current_witnesses DO + UPDATE SET prop_value = EXCLUDED.prop_value; + END IF; + END LOOP; + + -- parse witness feed_data + FOR __prop_op IN + SELECT witness_id, value, op_type_id, timestamp + FROM hafbe_views.witness_prop_op_view + WHERE block_num = b AND op_type_id = ANY('{42,7}'::INT[]) + + LOOP + IF __prop_op.op_type_id = 42 THEN + SELECT hafbe_app.parse_witness_set_props(__prop_op.value, 'hbd_exchange_rate') INTO __prop_value; + ELSE + SELECT __prop_op.value->>'exchange_rate' INTO __prop_value; + END IF; + + IF __prop_value IS NOT NULL THEN + -- price_feed + INSERT INTO hafbe_app.current_witnesses (witness_id, prop_type_id, prop_value) + SELECT + __prop_op.witness_id, + (SELECT prop_type_id FROM hafbe_app.witness_prop_types WHERE prop_name = 'price_feed'), + __prop_value + ON CONFLICT ON CONSTRAINT pk_current_witnesses DO + UPDATE SET prop_value = EXCLUDED.prop_value; + + -- bias + INSERT INTO hafbe_app.current_witnesses (witness_id, prop_type_id, prop_value) + SELECT + __prop_op.witness_id, + (SELECT prop_type_id FROM hafbe_app.witness_prop_types WHERE prop_name = 'bias'), + --(((__prop_value::JSON)->'quote'->>'amount')::INT - 1000)::TEXT + 0::TEXT + ON CONFLICT ON CONSTRAINT pk_current_witnesses DO + UPDATE SET prop_value = EXCLUDED.prop_value; + + -- feed_age + INSERT INTO hafbe_app.current_witnesses (witness_id, prop_type_id, prop_value) + SELECT + __prop_op.witness_id, + (SELECT prop_type_id FROM hafbe_app.witness_prop_types WHERE prop_name = 'feed_age'), + ((NOW() - __prop_op.timestamp)::INTERVAL)::TEXT + ON CONFLICT ON CONSTRAINT pk_current_witnesses DO + UPDATE SET prop_value = EXCLUDED.prop_value; + END IF; + END LOOP; + + -- parse witness block_size + FOR __prop_op IN + SELECT witness_id, value, op_type_id + FROM hafbe_views.witness_prop_op_view + WHERE block_num = b AND op_type_id = ANY('{42,30,14,11}'::INT[]) + + LOOP + IF __prop_op.op_type_id = 42 THEN + SELECT hafbe_app.parse_witness_set_props(__prop_op.value, 'maximum_block_size') INTO __prop_value; + ELSE + SELECT __prop_op.value->>'maximum_block_size' INTO __prop_value; + END IF; + + IF __prop_value IS NOT NULL THEN + INSERT INTO hafbe_app.current_witnesses (witness_id, prop_type_id, prop_value) + SELECT + __prop_op.witness_id, + (SELECT prop_type_id FROM hafbe_app.witness_prop_types WHERE prop_name = 'block_size'), + __prop_value + ON CONFLICT ON CONSTRAINT pk_current_witnesses DO + UPDATE SET prop_value = EXCLUDED.prop_value; + END IF; + END LOOP; + + -- parse witness signing_key + FOR __prop_op IN + SELECT witness_id, value, op_type_id + FROM hafbe_views.witness_prop_op_view + WHERE block_num = b AND op_type_id = ANY('{42,30,14,11}'::INT[]) + + LOOP + IF __prop_op.op_type_id = 42 THEN + SELECT hafbe_app.parse_witness_set_props(__prop_op.value, 'new_signing_key') INTO __prop_value; + ELSE + SELECT __prop_op.value->>'block_signing_key' INTO __prop_value; + END IF; + + IF __prop_value IS NOT NULL THEN + INSERT INTO hafbe_app.current_witnesses (witness_id, prop_type_id, prop_value) + SELECT + __prop_op.witness_id, + (SELECT prop_type_id FROM hafbe_app.witness_prop_types WHERE prop_name = 'signing_key'), + __prop_value + ON CONFLICT ON CONSTRAINT pk_current_witnesses DO + UPDATE SET prop_value = EXCLUDED.prop_value; + END IF; + END LOOP; + SELECT INTO __vote_op hafbe_app.get_account_id((body::JSON)->'value'->>'witness') AS witness_id, hafbe_app.get_account_id((body::JSON)->'value'->>'account') AS voter_id, @@ -229,10 +398,6 @@ BEGIN approve = EXCLUDED.approve, timestamp = EXCLUDED.timestamp ; - - INSERT INTO hafbe_app.current_witnesses (witness_id) - VALUES (__vote_op.witness_id) - ON CONFLICT ON CONSTRAINT pk_current_witnesses DO NOTHING; END IF; SELECT INTO __proxy_op -- GitLab From d8631ba3c0b458d9c6692cb84336dc117536b6b9 Mon Sep 17 00:00:00 2001 From: kristupas Date: Thu, 8 Sep 2022 11:01:28 +0000 Subject: [PATCH 40/89] Changed 'current_witnesses' to vertical table, added dynamic sorting #22 --- api/backend.sql | 59 ++++++++-------- api/views.sql | 176 +++++++++++++++++++++++++---------------------- db/hafbe_app.sql | 98 ++++++++++---------------- run.sh | 1 + 4 files changed, 160 insertions(+), 174 deletions(-) diff --git a/api/backend.sql b/api/backend.sql index 15ef369..a8731b7 100644 --- a/api/backend.sql +++ b/api/backend.sql @@ -455,7 +455,7 @@ CREATE TYPE hafbe_backend.witnesses AS ( version TEXT ); -CREATE FUNCTION hafbe_backend.get_set_of_witnesses(_limit INT) +CREATE FUNCTION hafbe_backend.get_set_of_witnesses(_limit INT, _order_by TEXT, _order_is TEXT) RETURNS SETOF hafbe_backend.witnesses AS $function$ @@ -470,25 +470,19 @@ BEGIN __today = 'today'::DATE; END IF; - RETURN QUERY SELECT - witness, URL, votes, votes_daily_change, voters_num, voters_num_daily_change, - feed_data->>'exchange_rate' AS price_feed, - 0 AS bias, --(feed_data->'exchange_rate'->'quote'->>'amount')::INT - 1000 AS bias - (NOW() - (feed_data->>'timestamp')::TIMESTAMP)::INTERVAL AS feed_age, - block_size, signing_key, - '1.25.0' AS version - FROM ( + RETURN QUERY EXECUTE format( + $query$ + SELECT - hav.name::TEXT AS witness, - (SELECT hafbe_backend.parse_and_unpack_witness_data(cw.witness_id, 'url', '{42,11}')->>'url') AS url, - all_votes.votes::NUMERIC AS votes, - COALESCE(todays_votes.votes, 0)::BIGINT AS votes_daily_change, - all_votes.voters_num::INT AS voters_num, - COALESCE(todays_votes.voters_num, 0)::INT AS voters_num_daily_change, - (SELECT hafbe_backend.parse_and_unpack_witness_data(cw.witness_id, 'exchange_rate', '{42,7}')) AS feed_data, - (SELECT hafbe_backend.parse_and_unpack_witness_data(cw.witness_id, 'maximum_block_size', '{42,30,14,11}')->>'maximum_block_size')::INT AS block_size, - (SELECT hafbe_backend.parse_and_unpack_witness_data(cw.witness_id, 'signing_key', '{42,11}')->>'signing_key') AS signing_key - FROM hafbe_app.current_witnesses cw + name::TEXT, url, + votes::NUMERIC, + votes_daily_change::BIGINT, + voters_num::INT, + voters_num_daily_change::INT, + price_feed, bias, feed_age, block_size, signing_key, version + FROM hive.accounts_view + + JOIN hafbe_app.current_witnesses cw ON cw.witness_id = id JOIN ( SELECT @@ -502,21 +496,26 @@ BEGIN LEFT JOIN ( SELECT witness_id, - SUM(CASE WHEN approve IS TRUE THEN votes ELSE -1 * votes END) AS votes, - SUM(CASE WHEN approve IS TRUE THEN 1 ELSE -1 END) AS voters_num + COALESCE( + SUM(CASE WHEN approve IS TRUE THEN votes ELSE -1 * votes END), + 0) AS votes_daily_change, + COALESCE(SUM(CASE WHEN approve IS TRUE THEN 1 ELSE -1 END), + 0) AS voters_num_daily_change FROM hafbe_views.voters_stats_change_view - WHERE timestamp >= __today + WHERE timestamp >= %L GROUP BY witness_id ) todays_votes ON todays_votes.witness_id = cw.witness_id - JOIN ( - SELECT name, id - FROM hive.accounts_view - ) hav ON hav.id = cw.witness_id - - ) votes_stats - ORDER BY votes DESC - LIMIT _limit; + WHERE %I IS NOT NULL + + ORDER BY + (CASE WHEN %L = 'desc' THEN %I ELSE NULL END) DESC, + (CASE WHEN %L = 'asc' THEN %I ELSE NULL END) ASC + LIMIT %L; + + $query$, + __today, _order_by, _order_is, _order_by, _order_is, _order_by, _limit + ) res; END $function$ LANGUAGE 'plpgsql' STABLE diff --git a/api/views.sql b/api/views.sql index da01e28..4f41a29 100644 --- a/api/views.sql +++ b/api/views.sql @@ -1,86 +1,94 @@ CREATE SCHEMA IF NOT EXISTS hafbe_views; -DROP VIEW IF EXISTS hafbe_views.voters_stats_view; -CREATE VIEW hafbe_views.voters_stats_view AS -SELECT - witness_id, voter_id, timestamp, - COALESCE(account.vests, 0)::NUMERIC AS account_vests, - SUM(COALESCE(proxied.vests, 0)) AS proxied_vests -FROM hafbe_app.current_witness_votes - -LEFT JOIN ( - SELECT account_id, proxy_id - FROM hafbe_app.current_account_proxies - WHERE proxy = TRUE -) acc_as_proxy ON acc_as_proxy.proxy_id = voter_id - -LEFT JOIN ( - SELECT vests, account_id - FROM hafbe_app.account_vests -) proxied ON proxied.account_id = acc_as_proxy.account_id - -LEFT JOIN ( - SELECT account_id, proxy - FROM hafbe_app.current_account_proxies -) acc_as_proxied ON acc_as_proxied.account_id = voter_id - -LEFT JOIN ( - SELECT vests, account_id - FROM hafbe_app.account_vests -) account ON account.account_id = voter_id AND COALESCE(acc_as_proxied.proxy, FALSE) IS FALSE - -WHERE approve IS TRUE -GROUP BY witness_id, voter_id, account.vests; - ------- - -DROP VIEW IF EXISTS hafbe_views.voters_stats_change_view; -CREATE VIEW hafbe_views.voters_stats_change_view AS -SELECT - witness_id, voter_id, approve, timestamp, - ( - SUM(CASE WHEN acc_as_proxy.proxy IS TRUE THEN proxied.vests ELSE -1 * proxied.vests END) - + - CASE WHEN acc_as_proxied.proxy IS FALSE THEN account.vests ELSE -1 * account.vests END - ) AS votes -FROM hafbe_app.witness_votes_history - -LEFT JOIN ( - SELECT account_id, proxy_id, proxy - FROM hafbe_app.account_proxies_history -) acc_as_proxy ON acc_as_proxy.proxy_id = voter_id - -LEFT JOIN ( - SELECT vests, account_id - FROM hafbe_app.account_vests -) proxied ON proxied.account_id = acc_as_proxy.account_id - -LEFT JOIN ( - SELECT account_id, proxy - FROM hafbe_app.account_proxies_history -) acc_as_proxied ON acc_as_proxied.account_id = voter_id - -LEFT JOIN ( - SELECT vests, account_id - FROM hafbe_app.account_vests -) account ON account.account_id = acc_as_proxied.account_id - -GROUP BY witness_id, voter_id, approve, timestamp, acc_as_proxied.proxy, account.vests; - ------ - -DROP VIEW IF EXISTS hafbe_views.witness_prop_op_view; -CREATE VIEW hafbe_views.witness_prop_op_view AS -SELECT - account_id AS witness_id, - (hov.body::JSON)->'value' AS value, - hov.timestamp AS timestamp, - block_num, op_type_id, operation_id -FROM hive.account_operations_view haov - -JOIN ( - SELECT body, id, timestamp - FROM hive.operations_view -) hov ON hov.id = haov.operation_id - -ORDER BY operation_id DESC; \ No newline at end of file +CREATE PROCEDURE hafbe_views.create_views() +LANGUAGE 'plpgsql' +AS +$$ +BEGIN + DROP VIEW IF EXISTS hafbe_views.voters_stats_view; + CREATE VIEW hafbe_views.voters_stats_view AS + SELECT + witness_id, voter_id, timestamp, + COALESCE(account.vests, 0)::NUMERIC AS account_vests, + SUM(COALESCE(proxied.vests, 0)) AS proxied_vests + FROM hafbe_app.current_witness_votes + + LEFT JOIN ( + SELECT account_id, proxy_id + FROM hafbe_app.current_account_proxies + WHERE proxy = TRUE + ) acc_as_proxy ON acc_as_proxy.proxy_id = voter_id + + LEFT JOIN ( + SELECT vests, account_id + FROM hafbe_app.account_vests + ) proxied ON proxied.account_id = acc_as_proxy.account_id + + LEFT JOIN ( + SELECT account_id, proxy + FROM hafbe_app.current_account_proxies + ) acc_as_proxied ON acc_as_proxied.account_id = voter_id + + LEFT JOIN ( + SELECT vests, account_id + FROM hafbe_app.account_vests + ) account ON account.account_id = voter_id AND COALESCE(acc_as_proxied.proxy, FALSE) IS FALSE + + WHERE approve IS TRUE + GROUP BY witness_id, voter_id, account.vests; + + ------ + + DROP VIEW IF EXISTS hafbe_views.voters_stats_change_view; + CREATE VIEW hafbe_views.voters_stats_change_view AS + SELECT + witness_id, voter_id, approve, timestamp, + ( + SUM(CASE WHEN acc_as_proxy.proxy IS TRUE THEN proxied.vests ELSE -1 * proxied.vests END) + + + CASE WHEN acc_as_proxied.proxy IS FALSE THEN account.vests ELSE -1 * account.vests END + ) AS votes + FROM hafbe_app.witness_votes_history + + LEFT JOIN ( + SELECT account_id, proxy_id, proxy + FROM hafbe_app.account_proxies_history + ) acc_as_proxy ON acc_as_proxy.proxy_id = voter_id + + LEFT JOIN ( + SELECT vests, account_id + FROM hafbe_app.account_vests + ) proxied ON proxied.account_id = acc_as_proxy.account_id + + LEFT JOIN ( + SELECT account_id, proxy + FROM hafbe_app.account_proxies_history + ) acc_as_proxied ON acc_as_proxied.account_id = voter_id + + LEFT JOIN ( + SELECT vests, account_id + FROM hafbe_app.account_vests + ) account ON account.account_id = acc_as_proxied.account_id + + GROUP BY witness_id, voter_id, approve, timestamp, acc_as_proxied.proxy, account.vests; + + ----- + + DROP VIEW IF EXISTS hafbe_views.witness_prop_op_view; + CREATE VIEW hafbe_views.witness_prop_op_view AS + SELECT + account_id AS witness_id, + (hov.body::JSON)->'value' AS value, + hov.timestamp AS timestamp, + block_num, op_type_id, operation_id + FROM hive.account_operations_view haov + + JOIN ( + SELECT body, id, timestamp + FROM hive.operations_view + ) hov ON hov.id = haov.operation_id + + ORDER BY operation_id DESC; +END +$$ +; \ No newline at end of file diff --git a/db/hafbe_app.sql b/db/hafbe_app.sql index c977a73..1672b82 100644 --- a/db/hafbe_app.sql +++ b/db/hafbe_app.sql @@ -57,20 +57,17 @@ BEGIN CREATE INDEX IF NOT EXISTS current_witness_votes_witness_id_approve ON hafbe_app.current_witness_votes USING btree (witness_id, approve); - CREATE TABLE IF NOT EXISTS hafbe_app.witness_prop_types ( - prop_type_id SERIAL PRIMARY KEY, - prop_name TEXT NOT NULL - ); - - INSERT INTO hafbe_app.witness_prop_types (prop_name) VALUES - ('url'), ('price_feed'), ('bias'), ('feed_age'), ('block_size'), ('signing_key'), ('version'); - CREATE TABLE IF NOT EXISTS hafbe_app.current_witnesses ( witness_id INT NOT NULL, - prop_type_id INT NOT NULL, - prop_value TEXT NOT NULL, - - CONSTRAINT pk_current_witnesses PRIMARY KEY (witness_id, prop_type_id) + url TEXT, + price_feed TEXT, + bias INT, + feed_age INTERVAL, + block_size INT, + signing_key TEXT, + version TEXT, + + CONSTRAINT pk_current_witnesses PRIMARY KEY (witness_id) ) INHERITS (hive.hafbe_app); CREATE TABLE IF NOT EXISTS hafbe_app.account_proxies_history ( @@ -132,6 +129,8 @@ BEGIN CREATE INDEX IF NOT EXISTS account_vests_vests ON hafbe_app.account_vests USING btree (vests); + CALL hafbe_views.create_views(); + --ALTER SCHEMA hafbe_app OWNER TO hafbe_owner; END $$ @@ -246,6 +245,18 @@ END $$ ; +CREATE OR REPLACE PROCEDURE hafbe_app.add_new_witness(witness_id INT) +LANGUAGE 'plpgsql' +AS +$$ +BEGIN + INSERT INTO hafbe_app.current_witnesses (witness_id, url, price_feed, bias, feed_age, block_size, signing_key, version) + VALUES (witness_id, NULL, NULL, NULL, NULL, NULL, NULL, '1.25.0') + ON CONFLICT ON CONSTRAINT pk_current_witnesses DO NOTHING; +END +$$ +; + CREATE OR REPLACE FUNCTION hafbe_app.process_block_range_data_c(_from INT, _to INT, _report_step INT = 1000) RETURNS VOID LANGUAGE 'plpgsql' @@ -275,14 +286,10 @@ BEGIN SELECT __prop_op.value->>'url' INTO __prop_value; END IF; + CALL hafbe_app.add_new_witness(__prop_op.witness_id); + IF __prop_value IS NOT NULL THEN - INSERT INTO hafbe_app.current_witnesses (witness_id, prop_type_id, prop_value) - SELECT - __prop_op.witness_id, - (SELECT prop_type_id FROM hafbe_app.witness_prop_types WHERE prop_name = 'url'), - __prop_value - ON CONFLICT ON CONSTRAINT pk_current_witnesses DO - UPDATE SET prop_value = EXCLUDED.prop_value; + UPDATE hafbe_app.current_witnesses cw SET url = __prop_value WHERE witness_id = __prop_op.witness_id; END IF; END LOOP; @@ -299,34 +306,13 @@ BEGIN SELECT __prop_op.value->>'exchange_rate' INTO __prop_value; END IF; + CALL hafbe_app.add_new_witness(__prop_op.witness_id); + IF __prop_value IS NOT NULL THEN - -- price_feed - INSERT INTO hafbe_app.current_witnesses (witness_id, prop_type_id, prop_value) - SELECT - __prop_op.witness_id, - (SELECT prop_type_id FROM hafbe_app.witness_prop_types WHERE prop_name = 'price_feed'), - __prop_value - ON CONFLICT ON CONSTRAINT pk_current_witnesses DO - UPDATE SET prop_value = EXCLUDED.prop_value; - - -- bias - INSERT INTO hafbe_app.current_witnesses (witness_id, prop_type_id, prop_value) - SELECT - __prop_op.witness_id, - (SELECT prop_type_id FROM hafbe_app.witness_prop_types WHERE prop_name = 'bias'), - --(((__prop_value::JSON)->'quote'->>'amount')::INT - 1000)::TEXT - 0::TEXT - ON CONFLICT ON CONSTRAINT pk_current_witnesses DO - UPDATE SET prop_value = EXCLUDED.prop_value; - - -- feed_age - INSERT INTO hafbe_app.current_witnesses (witness_id, prop_type_id, prop_value) - SELECT - __prop_op.witness_id, - (SELECT prop_type_id FROM hafbe_app.witness_prop_types WHERE prop_name = 'feed_age'), - ((NOW() - __prop_op.timestamp)::INTERVAL)::TEXT - ON CONFLICT ON CONSTRAINT pk_current_witnesses DO - UPDATE SET prop_value = EXCLUDED.prop_value; + UPDATE hafbe_app.current_witnesses cw SET price_feed = __prop_value WHERE witness_id = __prop_op.witness_id; + -- (((__prop_value::JSON)->'quote'->>'amount')::INT - 1000)::INT + UPDATE hafbe_app.current_witnesses cw SET bias = 0::INT WHERE witness_id = __prop_op.witness_id; + UPDATE hafbe_app.current_witnesses cw SET feed_age = (NOW() - __prop_op.timestamp)::INTERVAL WHERE witness_id = __prop_op.witness_id; END IF; END LOOP; @@ -343,14 +329,10 @@ BEGIN SELECT __prop_op.value->>'maximum_block_size' INTO __prop_value; END IF; + CALL hafbe_app.add_new_witness(__prop_op.witness_id); + IF __prop_value IS NOT NULL THEN - INSERT INTO hafbe_app.current_witnesses (witness_id, prop_type_id, prop_value) - SELECT - __prop_op.witness_id, - (SELECT prop_type_id FROM hafbe_app.witness_prop_types WHERE prop_name = 'block_size'), - __prop_value - ON CONFLICT ON CONSTRAINT pk_current_witnesses DO - UPDATE SET prop_value = EXCLUDED.prop_value; + UPDATE hafbe_app.current_witnesses cw SET block_size = __prop_value WHERE witness_id = __prop_op.witness_id; END IF; END LOOP; @@ -367,14 +349,10 @@ BEGIN SELECT __prop_op.value->>'block_signing_key' INTO __prop_value; END IF; + CALL hafbe_app.add_new_witness(__prop_op.witness_id); + IF __prop_value IS NOT NULL THEN - INSERT INTO hafbe_app.current_witnesses (witness_id, prop_type_id, prop_value) - SELECT - __prop_op.witness_id, - (SELECT prop_type_id FROM hafbe_app.witness_prop_types WHERE prop_name = 'signing_key'), - __prop_value - ON CONFLICT ON CONSTRAINT pk_current_witnesses DO - UPDATE SET prop_value = EXCLUDED.prop_value; + UPDATE hafbe_app.current_witnesses cw SET signing_key = __prop_value WHERE witness_id = __prop_op.witness_id; END IF; END LOOP; diff --git a/run.sh b/run.sh index cef1cd6..4a77e69 100755 --- a/run.sh +++ b/run.sh @@ -9,6 +9,7 @@ drop_db() { } create_db() { + psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -f api/views.sql psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -f db/hafbe_app.sql process_blocks $@ } -- GitLab From ad19fdd82f372b17a685e51899dfb974e0aec119 Mon Sep 17 00:00:00 2001 From: kristupas Date: Thu, 8 Sep 2022 15:02:04 +0000 Subject: [PATCH 41/89] Added index for op view, updated 'get_witnesses()' method #22 --- api/backend.sql | 65 ++++++++++++++++++++++++----------------------- api/endpoints.sql | 19 ++++++++++++-- api/roles.sql | 4 +++ api/views.sql | 4 ++- db/hafbe_app.sql | 29 ++++++++++++++++----- run.sh | 3 +++ 6 files changed, 83 insertions(+), 41 deletions(-) diff --git a/api/backend.sql b/api/backend.sql index a8731b7..2a773f1 100644 --- a/api/backend.sql +++ b/api/backend.sql @@ -474,40 +474,41 @@ BEGIN $query$ SELECT - name::TEXT, url, - votes::NUMERIC, - votes_daily_change::BIGINT, - voters_num::INT, - voters_num_daily_change::INT, + witness::TEXT, url, votes::NUMERIC, votes_daily_change::BIGINT, voters_num::INT, voters_num_daily_change::INT, price_feed, bias, feed_age, block_size, signing_key, version - FROM hive.accounts_view - - JOIN hafbe_app.current_witnesses cw ON cw.witness_id = id - - JOIN ( + FROM ( SELECT - witness_id, - SUM(account_vests + proxied_vests) AS votes, - COUNT(voter_id) AS voters_num - FROM hafbe_views.voters_stats_view - GROUP BY witness_id - ) all_votes ON all_votes.witness_id = cw.witness_id - - LEFT JOIN ( - SELECT - witness_id, - COALESCE( - SUM(CASE WHEN approve IS TRUE THEN votes ELSE -1 * votes END), - 0) AS votes_daily_change, - COALESCE(SUM(CASE WHEN approve IS TRUE THEN 1 ELSE -1 END), - 0) AS voters_num_daily_change - FROM hafbe_views.voters_stats_change_view - WHERE timestamp >= %L - GROUP BY witness_id - ) todays_votes ON todays_votes.witness_id = cw.witness_id + name AS witness, url, + votes, + COALESCE(votes_daily_change, 0) AS votes_daily_change, + voters_num, + COALESCE(voters_num_daily_change, 0) AS voters_num_daily_change, + price_feed, bias, feed_age, block_size, signing_key, version + FROM hive.accounts_view + + JOIN hafbe_app.current_witnesses cw ON cw.witness_id = id + + JOIN ( + SELECT + witness_id, + SUM(account_vests + proxied_vests) AS votes, + COUNT(voter_id) AS voters_num + FROM hafbe_views.voters_stats_view + GROUP BY witness_id + ) all_votes ON all_votes.witness_id = cw.witness_id + + LEFT JOIN ( + SELECT + witness_id, + SUM(CASE WHEN approve IS TRUE THEN votes ELSE -1 * votes END) AS votes_daily_change, + SUM(CASE WHEN approve IS TRUE THEN 1 ELSE -1 END) AS voters_num_daily_change + FROM hafbe_views.voters_stats_change_view + WHERE timestamp >= %L + GROUP BY witness_id + ) todays_votes ON todays_votes.witness_id = cw.witness_id + ) witnesses WHERE %I IS NOT NULL - ORDER BY (CASE WHEN %L = 'desc' THEN %I ELSE NULL END) DESC, (CASE WHEN %L = 'asc' THEN %I ELSE NULL END) ASC @@ -524,7 +525,7 @@ SET join_collapse_limit=16 SET from_collapse_limit=16 ; -CREATE FUNCTION hafbe_backend.get_witnesses(_limit INT) +CREATE FUNCTION hafbe_backend.get_witnesses(_limit INT, _order_by TEXT, _order_is TEXT) RETURNS JSON LANGUAGE 'plpgsql' AS @@ -532,7 +533,7 @@ $$ BEGIN RETURN CASE WHEN arr IS NOT NULL THEN to_json(arr) ELSE '[]'::JSON END FROM ( SELECT ARRAY( - SELECT hafbe_backend.get_set_of_witnesses(_limit) + SELECT hafbe_backend.get_set_of_witnesses(_limit, _order_by, _order_is) ) arr ) result; END diff --git a/api/endpoints.sql b/api/endpoints.sql index 125a395..9f9702f 100644 --- a/api/endpoints.sql +++ b/api/endpoints.sql @@ -239,7 +239,7 @@ END $$ ; -CREATE FUNCTION hafbe_endpoints.get_witnesses(_limit INT = 50) +CREATE FUNCTION hafbe_endpoints.get_witnesses(_limit INT = 50, _order_by TEXT = 'vests', _order_is TEXT = 'desc') RETURNS JSON LANGUAGE 'plpgsql' AS @@ -249,7 +249,22 @@ BEGIN _limit = 50; END IF; - RETURN hafbe_backend.get_witnesses(_limit); + IF _order_by NOT SIMILAR TO + '(witness|url|votes|votes_daily_change|voters_num|voters_num_daily_change|price_feed|bias|feed_age|block_size|signing_key|version)' THEN + RETURN hafbe_exceptions.raise_no_such_column_exception(_order_by); + END IF; + IF _order_by IS NULL THEN + _order_by = 'vests'; + END IF; + + IF _order_is NOT SIMILAR TO '(asc|desc)' THEN + RETURN hafbe_exceptions.raise_no_such_order_exception(_order_is); + END IF; + IF _order_is IS NULL THEN + _order_is = 'desc'; + END IF; + + RETURN hafbe_backend.get_witnesses(_limit, _order_by, _order_is); END $$ ; diff --git a/api/roles.sql b/api/roles.sql index 419202f..ab5431e 100755 --- a/api/roles.sql +++ b/api/roles.sql @@ -5,6 +5,7 @@ CREATE ROLE hafbe_owner LOGIN INHERIT IN ROLE hive_applications_group; ALTER SCHEMA hafbe_backend OWNER TO hafbe_owner; ALTER SCHEMA hafbe_endpoints OWNER TO hafbe_owner; ALTER SCHEMA hafbe_exceptions OWNER TO hafbe_owner; +ALTER SCHEMA hafbe_views OWNER TO hafbe_owner; -- drop priviliges of schemas user DO $$ @@ -30,6 +31,9 @@ GRANT SELECT ON ALL TABLES IN SCHEMA hafbe_endpoints TO hafbe_user; GRANT USAGE ON SCHEMA hafbe_exceptions TO hafbe_user; GRANT SELECT ON ALL TABLES IN SCHEMA hafbe_exceptions TO hafbe_user; +GRANT USAGE ON SCHEMA hafbe_views TO hafbe_user; +GRANT SELECT ON ALL TABLES IN SCHEMA hafbe_views TO hafbe_user; + GRANT USAGE ON SCHEMA btracker_app TO hafbe_user; GRANT SELECT ON ALL TABLES IN SCHEMA btracker_app TO hafbe_user; GRANT EXECUTE ON ALL FUNCTIONS IN SCHEMA btracker_app TO hafbe_user; diff --git a/api/views.sql b/api/views.sql index 4f41a29..e955186 100644 --- a/api/views.sql +++ b/api/views.sql @@ -1,4 +1,6 @@ -CREATE SCHEMA IF NOT EXISTS hafbe_views; +DROP SCHEMA IF EXISTS hafbe_views CASCADE; + +CREATE SCHEMA hafbe_views; CREATE PROCEDURE hafbe_views.create_views() LANGUAGE 'plpgsql' diff --git a/db/hafbe_app.sql b/db/hafbe_app.sql index 1672b82..8e3c089 100644 --- a/db/hafbe_app.sql +++ b/db/hafbe_app.sql @@ -12,10 +12,13 @@ BEGIN CREATE TABLE IF NOT EXISTS hafbe_app.app_status ( continue_processing BOOLEAN, - last_processed_block INT + last_processed_block INT, + started_processing_at TIMESTAMP, + last_reported_at TIMESTAMP, + report_time BOOLEAN ); - INSERT INTO hafbe_app.app_status (continue_processing, last_processed_block) - VALUES (True, 0); + INSERT INTO hafbe_app.app_status (continue_processing, last_processed_block, started_processing_at, last_reported_at, report_time) + VALUES (True, 0, NULL, to_timestamp(0), TRUE); CREATE TABLE IF NOT EXISTS hafbe_app.hardfork_operations ( operation_id INT NOT NULL, @@ -130,7 +133,7 @@ BEGIN CREATE INDEX IF NOT EXISTS account_vests_vests ON hafbe_app.account_vests USING btree (vests); CALL hafbe_views.create_views(); - + --ALTER SCHEMA hafbe_app OWNER TO hafbe_owner; END $$ @@ -468,13 +471,25 @@ BEGIN _last_block := _to; END IF; - RAISE NOTICE 'Attempting to process a block range: <%, %>', b, _last_block; + --RAISE NOTICE 'Attempting to process a block range: <%, %>', b, _last_block; PERFORM hafbe_app.process_block_range_data_c(b, _last_block); COMMIT; - RAISE NOTICE 'Block range: <%, %> processed successfully.', b, _last_block; + --RAISE NOTICE 'Block range: <%, %> processed successfully.', b, _last_block; + + IF (SELECT report_time FROM hafbe_app.app_status) IS TRUE AND + (NOW() - (SELECT last_reported_at FROM hafbe_app.app_status))::INTERVAL >= '5 second'::INTERVAL THEN + + RAISE NOTICE 'Last processed block %', _last_block; + RAISE NOTICE 'Block processing running for % minutes', + ROUND((EXTRACT(epoch FROM ( + SELECT NOW() - started_processing_at FROM hafbe_app.app_status + )) / 60)::NUMERIC, 2); + + UPDATE hafbe_app.app_status SET last_reported_at = NOW(); + END IF; EXIT WHEN NOT hafbe_app.continueProcessing(); @@ -548,6 +563,8 @@ BEGIN _maxBlockLimit = 2147483647; END IF; + UPDATE hafbe_app.app_status SET started_processing_at = NOW(); + WHILE hafbe_app.continueProcessing() AND (_maxBlockLimit = 0 OR __last_block < _maxBlockLimit) LOOP __next_block_range := hive.app_next_block(_appContext); diff --git a/run.sh b/run.sh index 4a77e69..115ce44 100755 --- a/run.sh +++ b/run.sh @@ -40,6 +40,9 @@ create_indexes() { psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "CREATE UNIQUE INDEX CONCURRENTLY IF NOT EXISTS hive_account_operations_reversible_uq2 ON hive.account_operations_reversible USING btree (account_id, op_type_id, operation_id, fork_id)" psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "CREATE UNIQUE INDEX CONCURRENTLY IF NOT EXISTS hive_account_operations_uq2 ON hive.account_operations USING btree (account_id, op_type_id, operation_id)" + psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "CREATE INDEX CONCURRENTLY IF NOT EXISTS hive_account_operations_reversible_block_num_op_type_id ON hive.account_operations_reversible USING btree (block_num, op_type_id, fork_id)" + psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "CREATE INDEX CONCURRENTLY IF NOT EXISTS hive_account_operations_block_num_op_type_id ON hive.account_operations USING btree (block_num, op_type_id)" + psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "CREATE INDEX CONCURRENTLY IF NOT EXISTS hive_account_operations_reversible_block_num ON hive.account_operations_reversible USING btree (block_num, fork_id)" psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "CREATE INDEX CONCURRENTLY IF NOT EXISTS hive_account_operations_block_num ON hive.account_operations USING btree (block_num)" -- GitLab From 4f814ff766c28f3ed520d5535fca0dbc5941156c Mon Sep 17 00:00:00 2001 From: kristupas Date: Fri, 9 Sep 2022 12:41:19 +0000 Subject: [PATCH 42/89] Updated indexes, reduced query number #22 --- api/backend.sql | 5 +- api/views.sql | 18 ------ db/hafbe_app.sql | 157 ++++++++++++++++++++++------------------------- run.sh | 7 +-- 4 files changed, 77 insertions(+), 110 deletions(-) diff --git a/api/backend.sql b/api/backend.sql index 2a773f1..3d668cd 100644 --- a/api/backend.sql +++ b/api/backend.sql @@ -293,10 +293,7 @@ BEGIN hov.body::JSON, hov.id::BIGINT, NULL::BIGINT - FROM ( - SELECT block_num, op_type_id, trx_in_block, op_pos, timestamp, body, id - FROM hive.operations_view - ) hov + FROM hive.operations_view hov JOIN LATERAL ( SELECT id, is_virtual FROM hive.operation_types diff --git a/api/views.sql b/api/views.sql index e955186..ce6db0c 100644 --- a/api/views.sql +++ b/api/views.sql @@ -73,24 +73,6 @@ BEGIN ) account ON account.account_id = acc_as_proxied.account_id GROUP BY witness_id, voter_id, approve, timestamp, acc_as_proxied.proxy, account.vests; - - ----- - - DROP VIEW IF EXISTS hafbe_views.witness_prop_op_view; - CREATE VIEW hafbe_views.witness_prop_op_view AS - SELECT - account_id AS witness_id, - (hov.body::JSON)->'value' AS value, - hov.timestamp AS timestamp, - block_num, op_type_id, operation_id - FROM hive.account_operations_view haov - - JOIN ( - SELECT body, id, timestamp - FROM hive.operations_view - ) hov ON hov.id = haov.operation_id - - ORDER BY operation_id DESC; END $$ ; \ No newline at end of file diff --git a/db/hafbe_app.sql b/db/hafbe_app.sql index 8e3c089..1a662ad 100644 --- a/db/hafbe_app.sql +++ b/db/hafbe_app.sql @@ -248,14 +248,16 @@ END $$ ; -CREATE OR REPLACE PROCEDURE hafbe_app.add_new_witness(witness_id INT) +CREATE OR REPLACE PROCEDURE hafbe_app.add_new_witness(_witness_id INT) LANGUAGE 'plpgsql' AS $$ BEGIN - INSERT INTO hafbe_app.current_witnesses (witness_id, url, price_feed, bias, feed_age, block_size, signing_key, version) - VALUES (witness_id, NULL, NULL, NULL, NULL, NULL, NULL, '1.25.0') - ON CONFLICT ON CONSTRAINT pk_current_witnesses DO NOTHING; + IF (SELECT witness_id FROM hafbe_app.current_witnesses WHERE witness_id = _witness_id) IS NULL THEN + INSERT INTO hafbe_app.current_witnesses (witness_id, url, price_feed, bias, feed_age, block_size, signing_key, version) + VALUES (_witness_id, NULL, NULL, NULL, NULL, NULL, NULL, '1.25.0') + ON CONFLICT ON CONSTRAINT pk_current_witnesses DO NOTHING; + END IF; END $$ ; @@ -276,86 +278,73 @@ BEGIN -- main processing loop FOR b IN _from .. _to LOOP - -- parse witness url - FOR __prop_op IN - SELECT witness_id, value, op_type_id - FROM hafbe_views.witness_prop_op_view - WHERE block_num = b AND op_type_id = ANY('{42,11}'::INT[]) - - LOOP - IF __prop_op.op_type_id = 42 THEN - SELECT hafbe_app.parse_witness_set_props(__prop_op.value, 'url') INTO __prop_value; - ELSE - SELECT __prop_op.value->>'url' INTO __prop_value; - END IF; - - CALL hafbe_app.add_new_witness(__prop_op.witness_id); - - IF __prop_value IS NOT NULL THEN - UPDATE hafbe_app.current_witnesses cw SET url = __prop_value WHERE witness_id = __prop_op.witness_id; - END IF; - END LOOP; - - -- parse witness feed_data FOR __prop_op IN - SELECT witness_id, value, op_type_id, timestamp - FROM hafbe_views.witness_prop_op_view - WHERE block_num = b AND op_type_id = ANY('{42,7}'::INT[]) - - LOOP - IF __prop_op.op_type_id = 42 THEN - SELECT hafbe_app.parse_witness_set_props(__prop_op.value, 'hbd_exchange_rate') INTO __prop_value; - ELSE - SELECT __prop_op.value->>'exchange_rate' INTO __prop_value; - END IF; - - CALL hafbe_app.add_new_witness(__prop_op.witness_id); - - IF __prop_value IS NOT NULL THEN - UPDATE hafbe_app.current_witnesses cw SET price_feed = __prop_value WHERE witness_id = __prop_op.witness_id; - -- (((__prop_value::JSON)->'quote'->>'amount')::INT - 1000)::INT - UPDATE hafbe_app.current_witnesses cw SET bias = 0::INT WHERE witness_id = __prop_op.witness_id; - UPDATE hafbe_app.current_witnesses cw SET feed_age = (NOW() - __prop_op.timestamp)::INTERVAL WHERE witness_id = __prop_op.witness_id; - END IF; - END LOOP; - - -- parse witness block_size - FOR __prop_op IN - SELECT witness_id, value, op_type_id - FROM hafbe_views.witness_prop_op_view - WHERE block_num = b AND op_type_id = ANY('{42,30,14,11}'::INT[]) - - LOOP - IF __prop_op.op_type_id = 42 THEN - SELECT hafbe_app.parse_witness_set_props(__prop_op.value, 'maximum_block_size') INTO __prop_value; - ELSE - SELECT __prop_op.value->>'maximum_block_size' INTO __prop_value; - END IF; - - CALL hafbe_app.add_new_witness(__prop_op.witness_id); - - IF __prop_value IS NOT NULL THEN - UPDATE hafbe_app.current_witnesses cw SET block_size = __prop_value WHERE witness_id = __prop_op.witness_id; - END IF; - END LOOP; - - -- parse witness signing_key - FOR __prop_op IN - SELECT witness_id, value, op_type_id - FROM hafbe_views.witness_prop_op_view - WHERE block_num = b AND op_type_id = ANY('{42,30,14,11}'::INT[]) - + SELECT + haov.account_id AS witness_id, + (hov.body::JSON)->'value' AS value, + hov.op_type_id, + hov.timestamp + FROM hive.hafbe_app_operations_view hov + JOIN ( + SELECT account_id, operation_id, block_num + FROM hive.hafbe_app_account_operations_view haov + ) haov ON hov.id = haov.operation_id AND hov.block_num = haov.block_num + WHERE hov.block_num = b AND hov.op_type_id = ANY('{42,30,14,11,7}'::INT[]) + LOOP - IF __prop_op.op_type_id = 42 THEN - SELECT hafbe_app.parse_witness_set_props(__prop_op.value, 'new_signing_key') INTO __prop_value; - ELSE - SELECT __prop_op.value->>'block_signing_key' INTO __prop_value; - END IF; - CALL hafbe_app.add_new_witness(__prop_op.witness_id); + + -- parse witness url 42,11 + IF __prop_op.op_type_id = ANY('{42,11}'::INT[]) THEN + IF __prop_op.op_type_id = 42 THEN + SELECT hafbe_app.parse_witness_set_props(__prop_op.value, 'url') INTO __prop_value; + ELSE + SELECT __prop_op.value->>'url' INTO __prop_value; + END IF; + + IF __prop_value IS NOT NULL THEN + UPDATE hafbe_app.current_witnesses cw SET url = __prop_value WHERE witness_id = __prop_op.witness_id; + END IF; + + -- parse witness feed_data 42,7 + ELSIF __prop_op.op_type_id = ANY('{42,7}'::INT[]) THEN + IF __prop_op.op_type_id = 42 THEN + SELECT hafbe_app.parse_witness_set_props(__prop_op.value, 'hbd_exchange_rate') INTO __prop_value; + ELSE + SELECT __prop_op.value->>'exchange_rate' INTO __prop_value; + END IF; + + IF __prop_value IS NOT NULL THEN + UPDATE hafbe_app.current_witnesses cw SET price_feed = __prop_value WHERE witness_id = __prop_op.witness_id; + -- (((__prop_value::JSON)->'quote'->>'amount')::INT - 1000)::INT + UPDATE hafbe_app.current_witnesses cw SET bias = 0::INT WHERE witness_id = __prop_op.witness_id; + UPDATE hafbe_app.current_witnesses cw SET feed_age = (NOW() - __prop_op.timestamp)::INTERVAL WHERE witness_id = __prop_op.witness_id; + END IF; + + -- parse witness block_size 42,30,14,11 + ELSIF __prop_op.op_type_id = ANY('{42,30,14,11}'::INT[]) THEN + IF __prop_op.op_type_id = 42 THEN + SELECT hafbe_app.parse_witness_set_props(__prop_op.value, 'maximum_block_size') INTO __prop_value; + ELSE + SELECT __prop_op.value->>'maximum_block_size' INTO __prop_value; + END IF; + + IF __prop_value IS NOT NULL THEN + UPDATE hafbe_app.current_witnesses cw SET block_size = __prop_value::INT WHERE witness_id = __prop_op.witness_id; + END IF; + + -- parse witness signing_key 42,11 + ELSIF __prop_op.op_type_id = ANY('{42,11}'::INT[]) THEN + IF __prop_op.op_type_id = 42 THEN + SELECT hafbe_app.parse_witness_set_props(__prop_op.value, 'new_signing_key') INTO __prop_value; + ELSE + SELECT __prop_op.value->>'block_signing_key' INTO __prop_value; + END IF; + + IF __prop_value IS NOT NULL THEN + UPDATE hafbe_app.current_witnesses cw SET signing_key = __prop_value WHERE witness_id = __prop_op.witness_id; + END IF; - IF __prop_value IS NOT NULL THEN - UPDATE hafbe_app.current_witnesses cw SET signing_key = __prop_value WHERE witness_id = __prop_op.witness_id; END IF; END LOOP; @@ -365,7 +354,8 @@ BEGIN ((body::JSON)->'value'->>'approve')::BOOLEAN AS approve, timestamp FROM hive.hafbe_app_operations_view - WHERE op_type_id = 12 AND block_num = b; + WHERE op_type_id = 12 AND block_num = b + ORDER BY id ASC; IF __vote_op.witness_id IS NOT NULL THEN INSERT INTO hafbe_app.witness_votes_history (witness_id, voter_id, approve, timestamp) @@ -380,13 +370,14 @@ BEGIN timestamp = EXCLUDED.timestamp ; END IF; - + SELECT INTO __proxy_op hafbe_app.get_account_id((body::JSON)->'value'->>'account') AS account_id, hafbe_app.get_account_id((body::JSON)->'value'->>'proxy') AS proxy_id, timestamp FROM hive.hafbe_app_operations_view - WHERE op_type_id = 13 AND block_num = b; + WHERE op_type_id = 13 AND block_num = b + ORDER BY id ASC; IF __proxy_op.account_id IS NOT NULL THEN INSERT INTO hafbe_app.account_proxies_history (account_id, proxy_id, proxy, timestamp) diff --git a/run.sh b/run.sh index 115ce44..61d7236 100755 --- a/run.sh +++ b/run.sh @@ -40,14 +40,11 @@ create_indexes() { psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "CREATE UNIQUE INDEX CONCURRENTLY IF NOT EXISTS hive_account_operations_reversible_uq2 ON hive.account_operations_reversible USING btree (account_id, op_type_id, operation_id, fork_id)" psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "CREATE UNIQUE INDEX CONCURRENTLY IF NOT EXISTS hive_account_operations_uq2 ON hive.account_operations USING btree (account_id, op_type_id, operation_id)" - psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "CREATE INDEX CONCURRENTLY IF NOT EXISTS hive_account_operations_reversible_block_num_op_type_id ON hive.account_operations_reversible USING btree (block_num, op_type_id, fork_id)" - psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "CREATE INDEX CONCURRENTLY IF NOT EXISTS hive_account_operations_block_num_op_type_id ON hive.account_operations USING btree (block_num, op_type_id)" - psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "CREATE INDEX CONCURRENTLY IF NOT EXISTS hive_account_operations_reversible_block_num ON hive.account_operations_reversible USING btree (block_num, fork_id)" psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "CREATE INDEX CONCURRENTLY IF NOT EXISTS hive_account_operations_block_num ON hive.account_operations USING btree (block_num)" - psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "CREATE INDEX CONCURRENTLY IF NOT EXISTS hive_operations_reversible_timestamp ON hive.operations_reversible USING btree (timestamp, fork_id)" - psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "CREATE INDEX CONCURRENTLY IF NOT EXISTS hive_operations_timestamp ON hive.operations USING btree (timestamp)" + psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "CREATE INDEX CONCURRENTLY IF NOT EXISTS hive_account_operations_reversible_operation_id_block_num ON hive.account_operations_reversible USING btree (operation_id, block_num, fork_id)" + psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "CREATE INDEX CONCURRENTLY IF NOT EXISTS hive_account_operations_operation_id_block_num ON hive.account_operations USING btree (operation_id, block_num)" } start_webserver() { -- GitLab From 459d83f382c0f4a73f7f073dca817ca6a726578b Mon Sep 17 00:00:00 2001 From: kristupas Date: Mon, 12 Sep 2022 10:53:03 +0000 Subject: [PATCH 43/89] Updated how new witnesses are added to hafbe table #22 --- db/hafbe_app.sql | 183 ++++++++++++++++++++++++----------------------- 1 file changed, 93 insertions(+), 90 deletions(-) diff --git a/db/hafbe_app.sql b/db/hafbe_app.sql index 1a662ad..cf10416 100644 --- a/db/hafbe_app.sql +++ b/db/hafbe_app.sql @@ -248,20 +248,6 @@ END $$ ; -CREATE OR REPLACE PROCEDURE hafbe_app.add_new_witness(_witness_id INT) -LANGUAGE 'plpgsql' -AS -$$ -BEGIN - IF (SELECT witness_id FROM hafbe_app.current_witnesses WHERE witness_id = _witness_id) IS NULL THEN - INSERT INTO hafbe_app.current_witnesses (witness_id, url, price_feed, bias, feed_age, block_size, signing_key, version) - VALUES (_witness_id, NULL, NULL, NULL, NULL, NULL, NULL, '1.25.0') - ON CONFLICT ON CONSTRAINT pk_current_witnesses DO NOTHING; - END IF; -END -$$ -; - CREATE OR REPLACE FUNCTION hafbe_app.process_block_range_data_c(_from INT, _to INT, _report_step INT = 1000) RETURNS VOID LANGUAGE 'plpgsql' @@ -275,79 +261,9 @@ DECLARE __balance_change RECORD; __balance_impacting_ops INT[] = (SELECT array_agg(op_type_id) FROM hafbe_app.balance_impacting_op_ids); BEGIN - -- main processing loop + -- vote and proxy op processing loop FOR b IN _from .. _to LOOP - FOR __prop_op IN - SELECT - haov.account_id AS witness_id, - (hov.body::JSON)->'value' AS value, - hov.op_type_id, - hov.timestamp - FROM hive.hafbe_app_operations_view hov - JOIN ( - SELECT account_id, operation_id, block_num - FROM hive.hafbe_app_account_operations_view haov - ) haov ON hov.id = haov.operation_id AND hov.block_num = haov.block_num - WHERE hov.block_num = b AND hov.op_type_id = ANY('{42,30,14,11,7}'::INT[]) - - LOOP - CALL hafbe_app.add_new_witness(__prop_op.witness_id); - - -- parse witness url 42,11 - IF __prop_op.op_type_id = ANY('{42,11}'::INT[]) THEN - IF __prop_op.op_type_id = 42 THEN - SELECT hafbe_app.parse_witness_set_props(__prop_op.value, 'url') INTO __prop_value; - ELSE - SELECT __prop_op.value->>'url' INTO __prop_value; - END IF; - - IF __prop_value IS NOT NULL THEN - UPDATE hafbe_app.current_witnesses cw SET url = __prop_value WHERE witness_id = __prop_op.witness_id; - END IF; - - -- parse witness feed_data 42,7 - ELSIF __prop_op.op_type_id = ANY('{42,7}'::INT[]) THEN - IF __prop_op.op_type_id = 42 THEN - SELECT hafbe_app.parse_witness_set_props(__prop_op.value, 'hbd_exchange_rate') INTO __prop_value; - ELSE - SELECT __prop_op.value->>'exchange_rate' INTO __prop_value; - END IF; - - IF __prop_value IS NOT NULL THEN - UPDATE hafbe_app.current_witnesses cw SET price_feed = __prop_value WHERE witness_id = __prop_op.witness_id; - -- (((__prop_value::JSON)->'quote'->>'amount')::INT - 1000)::INT - UPDATE hafbe_app.current_witnesses cw SET bias = 0::INT WHERE witness_id = __prop_op.witness_id; - UPDATE hafbe_app.current_witnesses cw SET feed_age = (NOW() - __prop_op.timestamp)::INTERVAL WHERE witness_id = __prop_op.witness_id; - END IF; - - -- parse witness block_size 42,30,14,11 - ELSIF __prop_op.op_type_id = ANY('{42,30,14,11}'::INT[]) THEN - IF __prop_op.op_type_id = 42 THEN - SELECT hafbe_app.parse_witness_set_props(__prop_op.value, 'maximum_block_size') INTO __prop_value; - ELSE - SELECT __prop_op.value->>'maximum_block_size' INTO __prop_value; - END IF; - - IF __prop_value IS NOT NULL THEN - UPDATE hafbe_app.current_witnesses cw SET block_size = __prop_value::INT WHERE witness_id = __prop_op.witness_id; - END IF; - - -- parse witness signing_key 42,11 - ELSIF __prop_op.op_type_id = ANY('{42,11}'::INT[]) THEN - IF __prop_op.op_type_id = 42 THEN - SELECT hafbe_app.parse_witness_set_props(__prop_op.value, 'new_signing_key') INTO __prop_value; - ELSE - SELECT __prop_op.value->>'block_signing_key' INTO __prop_value; - END IF; - - IF __prop_value IS NOT NULL THEN - UPDATE hafbe_app.current_witnesses cw SET signing_key = __prop_value WHERE witness_id = __prop_op.witness_id; - END IF; - - END IF; - END LOOP; - SELECT INTO __vote_op hafbe_app.get_account_id((body::JSON)->'value'->>'witness') AS witness_id, hafbe_app.get_account_id((body::JSON)->'value'->>'account') AS voter_id, @@ -358,6 +274,11 @@ BEGIN ORDER BY id ASC; IF __vote_op.witness_id IS NOT NULL THEN + -- add new witness per vote op + INSERT INTO hafbe_app.current_witnesses (witness_id, url, price_feed, bias, feed_age, block_size, signing_key, version) + VALUES(__vote_op.witness_id, NULL, NULL, NULL, NULL, NULL, NULL, '1.25.0') + ON CONFLICT ON CONSTRAINT pk_current_witnesses DO NOTHING; + INSERT INTO hafbe_app.witness_votes_history (witness_id, voter_id, approve, timestamp) VALUES (__vote_op.witness_id, __vote_op.voter_id, __vote_op.approve, __vote_op.timestamp); @@ -401,14 +322,96 @@ BEGIN proxy = CASE WHEN __proxy_op.proxy_id IS NULL THEN FALSE ELSE TRUE END ; END IF; + END LOOP; + + -- add new witnesses per block range + INSERT INTO hafbe_app.current_witnesses (witness_id, url, price_feed, bias, feed_age, block_size, signing_key, version) + SELECT DISTINCT ON (account_id) + account_id, NULL, NULL, NULL, NULL, NULL, NULL, '1.25.0' + FROM hive.account_operations_view + WHERE op_type_id = ANY('{42,11,7}') AND block_num BETWEEN _from AND _to + ON CONFLICT ON CONSTRAINT pk_current_witnesses DO NOTHING; + + -- processes witness properties per block range + FOR __prop_op IN + SELECT + witness_id, + (hov.body::JSON)->'value' AS value, + hov.op_type_id, + hov.timestamp + FROM hafbe_app.current_witnesses cw + JOIN ( + SELECT account_id, operation_id, block_num + FROM hive.hafbe_app_account_operations_view + WHERE op_type_id = ANY('{42,30,14,11,7}'::INT[]) AND block_num BETWEEN _from AND _to + ORDER BY operation_id ASC + ) haov ON haov.account_id = cw.witness_id + JOIN ( + SELECT body, op_type_id, timestamp, id, block_num + FROM hive.hafbe_app_operations_view + ) hov ON hov.id = haov.operation_id AND hov.block_num = haov.block_num + + LOOP + -- parse witness url 42,11 + IF __prop_op.op_type_id = ANY('{42,11}'::INT[]) THEN + IF __prop_op.op_type_id = 42 THEN + SELECT hafbe_app.parse_witness_set_props(__prop_op.value, 'url') INTO __prop_value; + ELSE + SELECT __prop_op.value->>'url' INTO __prop_value; + END IF; - INSERT INTO hafbe_app.account_operation_cache (account_id, op_type_id) - SELECT account_id, op_type_id - FROM hive.hafbe_app_account_operations_view - WHERE block_num = b - ON CONFLICT ON CONSTRAINT pk_account_operation_cache DO NOTHING; + IF __prop_value IS NOT NULL THEN + UPDATE hafbe_app.current_witnesses cw SET url = __prop_value WHERE witness_id = __prop_op.witness_id; + END IF; + + -- parse witness feed_data 42,7 + ELSIF __prop_op.op_type_id = ANY('{42,7}'::INT[]) THEN + IF __prop_op.op_type_id = 42 THEN + SELECT hafbe_app.parse_witness_set_props(__prop_op.value, 'hbd_exchange_rate') INTO __prop_value; + ELSE + SELECT __prop_op.value->>'exchange_rate' INTO __prop_value; + END IF; + + IF __prop_value IS NOT NULL THEN + UPDATE hafbe_app.current_witnesses cw SET price_feed = __prop_value WHERE witness_id = __prop_op.witness_id; + -- (((__prop_value::JSON)->'quote'->>'amount')::INT - 1000)::INT + UPDATE hafbe_app.current_witnesses cw SET bias = 0::INT WHERE witness_id = __prop_op.witness_id; + UPDATE hafbe_app.current_witnesses cw SET feed_age = (NOW() - __prop_op.timestamp)::INTERVAL WHERE witness_id = __prop_op.witness_id; + END IF; + + -- parse witness block_size 42,30,14,11 + ELSIF __prop_op.op_type_id = ANY('{42,30,14,11}'::INT[]) THEN + IF __prop_op.op_type_id = 42 THEN + SELECT hafbe_app.parse_witness_set_props(__prop_op.value, 'maximum_block_size') INTO __prop_value; + ELSE + SELECT __prop_op.value->>'maximum_block_size' INTO __prop_value; + END IF; + + IF __prop_value IS NOT NULL THEN + UPDATE hafbe_app.current_witnesses cw SET block_size = __prop_value::INT WHERE witness_id = __prop_op.witness_id; + END IF; + + -- parse witness signing_key 42,11 + ELSIF __prop_op.op_type_id = ANY('{42,11}'::INT[]) THEN + IF __prop_op.op_type_id = 42 THEN + SELECT hafbe_app.parse_witness_set_props(__prop_op.value, 'new_signing_key') INTO __prop_value; + ELSE + SELECT __prop_op.value->>'block_signing_key' INTO __prop_value; + END IF; + + IF __prop_value IS NOT NULL THEN + UPDATE hafbe_app.current_witnesses cw SET signing_key = __prop_value WHERE witness_id = __prop_op.witness_id; + END IF; + + END IF; END LOOP; + INSERT INTO hafbe_app.account_operation_cache (account_id, op_type_id) + SELECT account_id, op_type_id + FROM hive.hafbe_app_account_operations_view + WHERE block_num BETWEEN _from AND _to + ON CONFLICT ON CONSTRAINT pk_account_operation_cache DO NOTHING; + -- get impacted vests balance for block range and update account_vests FOR __balance_change IN SELECT bio.account_name AS account, bio.amount AS vests -- GitLab From fbeac3cb4deee6446d96562f05dde0441b645e55 Mon Sep 17 00:00:00 2001 From: kristupas Date: Tue, 13 Sep 2022 11:06:35 +0000 Subject: [PATCH 44/89] Fixed views creation, added witness dynamic queries and pagination #22 --- api/backend.sql | 322 +++++++++++++++++++++++++++++++++++++++------- api/endpoints.sql | 16 ++- db/hafbe_app.sql | 2 - run.sh | 3 +- 4 files changed, 288 insertions(+), 55 deletions(-) diff --git a/api/backend.sql b/api/backend.sql index 3d668cd..ecd6df7 100644 --- a/api/backend.sql +++ b/api/backend.sql @@ -383,7 +383,7 @@ CREATE TYPE hafbe_backend.witness_voters AS ( timestamp TIMESTAMP ); -CREATE FUNCTION hafbe_backend.get_set_of_witness_voters(_witness_id INT, _limit INT, _order_by TEXT, _order_is TEXT) +CREATE FUNCTION hafbe_backend.get_set_of_witness_voters(_witness_id INT, _limit INT, _offset INT, _order_by TEXT, _order_is TEXT) RETURNS SETOF hafbe_backend.witness_voters AS $function$ @@ -397,7 +397,7 @@ BEGIN JOIN ( SELECT voter_id FROM hafbe_app.current_witness_votes - WHERE witness_id = 440 + WHERE witness_id = _witness_id ) cwv ON cwv.voter_id = id JOIN ( @@ -409,6 +409,7 @@ BEGIN ORDER BY (CASE WHEN %L = 'desc' THEN %I ELSE NULL END) DESC, (CASE WHEN %L = 'asc' THEN %I ELSE NULL END) ASC + OFFSET %L LIMIT %L; $query$, @@ -422,7 +423,7 @@ SET join_collapse_limit=16 SET from_collapse_limit=16 ; -CREATE FUNCTION hafbe_backend.get_witness_voters(_witness_id INT, _limit INT, _order_by TEXT, _order_is TEXT) +CREATE FUNCTION hafbe_backend.get_witness_voters(_witness_id INT, _limit INT, _offset INT, _order_by TEXT, _order_is TEXT) RETURNS JSON LANGUAGE 'plpgsql' AS @@ -430,13 +431,176 @@ $$ BEGIN RETURN CASE WHEN arr IS NOT NULL THEN to_json(arr) ELSE '[]'::JSON END FROM ( SELECT ARRAY( - SELECT hafbe_backend.get_set_of_witness_voters(_witness_id, _limit, _order_by, _order_is) + SELECT hafbe_backend.get_set_of_witness_voters(_witness_id, _limit, _offset, _order_by, _order_is) ) arr ) result; END $$ ; +CREATE TYPE hafbe_backend.witnesses_by_name AS ( + witness_id INT, + witness TEXT, + url TEXT, + price_feed TEXT, + bias INT, + feed_age INTERVAL, + block_size INT, + signing_key TEXT, + version TEXT +); + +CREATE FUNCTION hafbe_backend.get_set_of_witnesses_by_name(_limit INT, _offset INT, _order_is TEXT) +RETURNS SETOF hafbe_backend.witnesses_by_name +AS +$function$ +BEGIN + RETURN QUERY EXECUTE format( + $query$ + + SELECT + witness_id, name::TEXT AS witness, + url, price_feed, bias, feed_age, block_size, signing_key, version + FROM hive.accounts_view hav + JOIN hafbe_app.current_witnesses cw ON hav.id = cw.witness_id + ORDER BY + (CASE WHEN %L = 'desc' THEN name ELSE NULL END) DESC, + (CASE WHEN %L = 'asc' THEN name ELSE NULL END) ASC + OFFSET %L + LIMIT %L + + $query$, + _order_is, _order_is, _offset, _limit + ); +END +$function$ +LANGUAGE 'plpgsql' STABLE +SET JIT=OFF +SET join_collapse_limit=16 +SET from_collapse_limit=16 +; + +CREATE TYPE hafbe_backend.witnesses_by_votes AS ( + witness_id INT, + votes NUMERIC, + voters_num INT +); + +CREATE FUNCTION hafbe_backend.get_set_of_witnesses_by_votes(_limit INT, _offset INT, _order_by TEXT, _order_is TEXT) +RETURNS SETOF hafbe_backend.witnesses_by_votes +AS +$function$ +BEGIN + RETURN QUERY EXECUTE format( + $query$ + + SELECT witness_id, votes::NUMERIC, voters_num::INT + FROM ( + SELECT + witness_id, + SUM(account_vests + proxied_vests) AS votes, + COUNT(voter_id) AS voters_num + FROM hafbe_views.voters_stats_view + GROUP BY witness_id + ) vsv + ORDER BY + (CASE WHEN %L = 'desc' THEN %I ELSE NULL END) DESC, + (CASE WHEN %L = 'asc' THEN %I ELSE NULL END) ASC + OFFSET %L + LIMIT %L + + $query$, + _order_is, _order_by, _order_is, _order_by, _offset, _limit + ); +END +$function$ +LANGUAGE 'plpgsql' STABLE +SET JIT=OFF +SET join_collapse_limit=16 +SET from_collapse_limit=16 +; + +CREATE TYPE hafbe_backend.witnesses_by_votes_change AS ( + witness_id INT, + votes_daily_change BIGINT, + voters_num_daily_change INT +); + +CREATE FUNCTION hafbe_backend.get_set_of_witnesses_by_votes_change(_limit INT, _offset INT, _order_by TEXT, _order_is TEXT, _today DATE) +RETURNS SETOF hafbe_backend.witnesses_by_votes_change +AS +$function$ +BEGIN + RETURN QUERY EXECUTE format( + $query$ + + SELECT witness_id, votes_daily_change::BIGINT, voters_num_daily_change::INT + FROM ( + SELECT + witness_id, + SUM(CASE WHEN approve IS TRUE THEN votes ELSE -1 * votes END) AS votes_daily_change, + SUM(CASE WHEN approve IS TRUE THEN 1 ELSE -1 END) AS voters_num_daily_change + FROM hafbe_views.voters_stats_change_view + WHERE timestamp >= %L + GROUP BY witness_id + ) vscv + ORDER BY + (CASE WHEN %L = 'desc' THEN %I ELSE NULL END) DESC, + (CASE WHEN %L = 'asc' THEN %I ELSE NULL END) ASC + OFFSET %L + LIMIT %L + + $query$, + _today, _order_is, _order_by, _order_is, _order_by, _offset, _limit + ); +END +$function$ +LANGUAGE 'plpgsql' STABLE +SET JIT=OFF +SET join_collapse_limit=16 +SET from_collapse_limit=16 +; + +CREATE TYPE hafbe_backend.witnesses_by_prop AS ( + witness_id INT, + url TEXT, + price_feed TEXT, + bias INT, + feed_age INTERVAL, + block_size INT, + signing_key TEXT, + version TEXT +); + +CREATE FUNCTION hafbe_backend.get_set_of_witnesses_by_prop(_limit INT, _offset INT, _order_by TEXT, _order_is TEXT) +RETURNS SETOF hafbe_backend.witnesses_by_prop +AS +$function$ +BEGIN + RETURN QUERY EXECUTE format( + $query$ + + SELECT + witness_id, url, price_feed, bias, feed_age, block_size, signing_key, version + FROM hafbe_app.current_witnesses + WHERE %I IS NOT NULL + ORDER BY + (CASE WHEN %L = 'desc' THEN %I ELSE NULL END) DESC, + (CASE WHEN %L = 'asc' THEN %I ELSE NULL END) ASC + OFFSET %L + LIMIT %L + + $query$, + _order_by, _order_is, _order_by, _order_is, _order_by, _offset, _limit + ); +END +$function$ +LANGUAGE 'plpgsql' STABLE +SET JIT=OFF +SET join_collapse_limit=16 +SET from_collapse_limit=16 +; + CREATE TYPE hafbe_backend.witnesses AS ( witness TEXT, url TEXT, @@ -452,7 +616,7 @@ CREATE TYPE hafbe_backend.witnesses AS ( version TEXT ); -CREATE FUNCTION hafbe_backend.get_set_of_witnesses(_limit INT, _order_by TEXT, _order_is TEXT) +CREATE FUNCTION hafbe_backend.get_set_of_witnesses(_limit INT, _offset INT, _order_by TEXT, _order_is TEXT) RETURNS SETOF hafbe_backend.witnesses AS $function$ @@ -467,53 +631,115 @@ BEGIN __today = 'today'::DATE; END IF; - RETURN QUERY EXECUTE format( - $query$ - - SELECT - witness::TEXT, url, votes::NUMERIC, votes_daily_change::BIGINT, voters_num::INT, voters_num_daily_change::INT, + IF _order_by = 'witness' THEN + + RETURN QUERY SELECT + witness, url, + COALESCE(votes, 0)::NUMERIC, + COALESCE(votes_daily_change, 0)::BIGINT, + COALESCE(voters_num, 0)::INT, + COALESCE(voters_num_daily_change, 0)::INT, price_feed, bias, feed_age, block_size, signing_key, version - FROM ( + FROM hafbe_backend.get_set_of_witnesses_by_name(_limit, _offset, _order_is) ls + LEFT JOIN ( + SELECT + witness_id, + SUM(account_vests + proxied_vests) AS votes, + COUNT(voter_id) AS voters_num + FROM hafbe_views.voters_stats_view + GROUP BY witness_id + ) all_votes ON all_votes.witness_id = ls.witness_id + LEFT JOIN ( + SELECT + witness_id, + SUM(CASE WHEN approve IS TRUE THEN votes ELSE -1 * votes END) AS votes_daily_change, + SUM(CASE WHEN approve IS TRUE THEN 1 ELSE -1 END) AS voters_num_daily_change + FROM hafbe_views.voters_stats_change_view + WHERE timestamp >= __today + GROUP BY witness_id + ) todays_votes ON todays_votes.witness_id = ls.witness_id; + + ELSIF _order_by = ANY('{votes,voters_num}'::TEXT[]) THEN + + RETURN QUERY SELECT + hav.name::TEXT, url, votes, + COALESCE(votes_daily_change, 0)::BIGINT AS votes_daily_change, + voters_num, + COALESCE(voters_num_daily_change, 0)::INT AS voters_num_daily_change, + price_feed, bias, feed_age, block_size, signing_key, version + FROM hafbe_backend.get_set_of_witnesses_by_votes(_limit, _offset, _order_by, _order_is) ls + JOIN hafbe_app.current_witnesses cw ON cw.witness_id = ls.witness_id + LEFT JOIN ( SELECT - name AS witness, url, - votes, - COALESCE(votes_daily_change, 0) AS votes_daily_change, - voters_num, - COALESCE(voters_num_daily_change, 0) AS voters_num_daily_change, - price_feed, bias, feed_age, block_size, signing_key, version + witness_id, + SUM(CASE WHEN approve IS TRUE THEN votes ELSE -1 * votes END) AS votes_daily_change, + SUM(CASE WHEN approve IS TRUE THEN 1 ELSE -1 END) AS voters_num_daily_change + FROM hafbe_views.voters_stats_change_view + WHERE timestamp >= __today + GROUP BY witness_id + ) todays_votes ON todays_votes.witness_id = ls.witness_id + JOIN ( + SELECT name, id FROM hive.accounts_view + ) hav ON hav.id = ls.witness_id; - JOIN hafbe_app.current_witnesses cw ON cw.witness_id = id - - JOIN ( - SELECT - witness_id, - SUM(account_vests + proxied_vests) AS votes, - COUNT(voter_id) AS voters_num - FROM hafbe_views.voters_stats_view - GROUP BY witness_id - ) all_votes ON all_votes.witness_id = cw.witness_id - - LEFT JOIN ( - SELECT - witness_id, - SUM(CASE WHEN approve IS TRUE THEN votes ELSE -1 * votes END) AS votes_daily_change, - SUM(CASE WHEN approve IS TRUE THEN 1 ELSE -1 END) AS voters_num_daily_change - FROM hafbe_views.voters_stats_change_view - WHERE timestamp >= %L - GROUP BY witness_id - ) todays_votes ON todays_votes.witness_id = cw.witness_id - ) witnesses + ELSIF _order_by = ANY('{votes_daily_change,voters_num_daily_change}') THEN - WHERE %I IS NOT NULL - ORDER BY - (CASE WHEN %L = 'desc' THEN %I ELSE NULL END) DESC, - (CASE WHEN %L = 'asc' THEN %I ELSE NULL END) ASC - LIMIT %L; + RETURN QUERY SELECT + hav.name::TEXT, url, + COALESCE(votes, 0)::NUMERIC, + votes_daily_change, + COALESCE(voters_num, 0)::INT, + voters_num_daily_change, + price_feed, bias, feed_age, block_size, signing_key, version + FROM hafbe_backend.get_set_of_witnesses_by_votes_change(_limit, _offset, _order_by, _order_is, __today) ls + JOIN hafbe_app.current_witnesses cw ON cw.witness_id = ls.witness_id + LEFT JOIN ( + SELECT + witness_id, + SUM(account_vests + proxied_vests) AS votes, + COUNT(voter_id) AS voters_num + FROM hafbe_views.voters_stats_view + GROUP BY witness_id + ) all_votes ON all_votes.witness_id = ls.witness_id + JOIN ( + SELECT name, id + FROM hive.accounts_view + ) hav ON hav.id = ls.witness_id; - $query$, - __today, _order_by, _order_is, _order_by, _order_is, _order_by, _limit - ) res; + ELSE + + RETURN QUERY SELECT + hav.name::TEXT, url, + COALESCE(votes, 0)::NUMERIC, + COALESCE(votes_daily_change, 0)::BIGINT, + COALESCE(voters_num, 0)::INT, + COALESCE(voters_num_daily_change, 0)::INT, + price_feed, bias, feed_age, block_size, signing_key, version + FROM hafbe_backend.get_set_of_witnesses_by_prop(_limit, _offset, _order_by, _order_is) ls + LEFT JOIN ( + SELECT + witness_id, + SUM(account_vests + proxied_vests) AS votes, + COUNT(voter_id) AS voters_num + FROM hafbe_views.voters_stats_view + GROUP BY witness_id + ) all_votes ON all_votes.witness_id = ls.witness_id + LEFT JOIN ( + SELECT + witness_id, + SUM(CASE WHEN approve IS TRUE THEN votes ELSE -1 * votes END) AS votes_daily_change, + SUM(CASE WHEN approve IS TRUE THEN 1 ELSE -1 END) AS voters_num_daily_change + FROM hafbe_views.voters_stats_change_view + WHERE timestamp >= __today + GROUP BY witness_id + ) todays_votes ON todays_votes.witness_id = ls.witness_id + JOIN ( + SELECT name, id + FROM hive.accounts_view + ) hav ON hav.id = ls.witness_id; + + END IF; END $function$ LANGUAGE 'plpgsql' STABLE @@ -522,7 +748,7 @@ SET join_collapse_limit=16 SET from_collapse_limit=16 ; -CREATE FUNCTION hafbe_backend.get_witnesses(_limit INT, _order_by TEXT, _order_is TEXT) +CREATE FUNCTION hafbe_backend.get_witnesses(_limit INT, _offset INT, _order_by TEXT, _order_is TEXT) RETURNS JSON LANGUAGE 'plpgsql' AS @@ -530,7 +756,7 @@ $$ BEGIN RETURN CASE WHEN arr IS NOT NULL THEN to_json(arr) ELSE '[]'::JSON END FROM ( SELECT ARRAY( - SELECT hafbe_backend.get_set_of_witnesses(_limit, _order_by, _order_is) + SELECT hafbe_backend.get_set_of_witnesses(_limit, _offset, _order_by, _order_is) ) arr ) result; END diff --git a/api/endpoints.sql b/api/endpoints.sql index 9f9702f..4575c27 100644 --- a/api/endpoints.sql +++ b/api/endpoints.sql @@ -208,7 +208,7 @@ END $$ ; -CREATE FUNCTION hafbe_endpoints.get_witness_voters(_witness TEXT, _limit INT = 1000, _order_by TEXT = 'vests', _order_is TEXT = 'desc') +CREATE FUNCTION hafbe_endpoints.get_witness_voters(_witness TEXT, _limit INT = 1000, _offset INT = 0, _order_by TEXT = 'vests', _order_is TEXT = 'desc') RETURNS JSON LANGUAGE 'plpgsql' AS @@ -220,6 +220,10 @@ BEGIN _limit = 1000; END IF; + IF _offset IS NULL OR _offset < 0 THEN + _offset = 0; + END IF; + IF _order_by NOT SIMILAR TO '(account|vests|account_vests|proxied_vests|timestamp)' THEN RETURN hafbe_exceptions.raise_no_such_column_exception(_order_by); END IF; @@ -234,12 +238,12 @@ BEGIN _order_is = 'desc'; END IF; - RETURN hafbe_backend.get_witness_voters(__witness_id, _limit, _order_by, _order_is); + RETURN hafbe_backend.get_witness_voters(__witness_id, _limit, _offset, _order_by, _order_is); END $$ ; -CREATE FUNCTION hafbe_endpoints.get_witnesses(_limit INT = 50, _order_by TEXT = 'vests', _order_is TEXT = 'desc') +CREATE FUNCTION hafbe_endpoints.get_witnesses(_limit INT = 50, _offset INT = 0, _order_by TEXT = 'vests', _order_is TEXT = 'desc') RETURNS JSON LANGUAGE 'plpgsql' AS @@ -249,6 +253,10 @@ BEGIN _limit = 50; END IF; + IF _offset IS NULL OR _offset < 0 THEN + _offset = 0; + END IF; + IF _order_by NOT SIMILAR TO '(witness|url|votes|votes_daily_change|voters_num|voters_num_daily_change|price_feed|bias|feed_age|block_size|signing_key|version)' THEN RETURN hafbe_exceptions.raise_no_such_column_exception(_order_by); @@ -264,7 +272,7 @@ BEGIN _order_is = 'desc'; END IF; - RETURN hafbe_backend.get_witnesses(_limit, _order_by, _order_is); + RETURN hafbe_backend.get_witnesses(_limit, _offset, _order_by, _order_is); END $$ ; diff --git a/db/hafbe_app.sql b/db/hafbe_app.sql index cf10416..3da2368 100644 --- a/db/hafbe_app.sql +++ b/db/hafbe_app.sql @@ -132,8 +132,6 @@ BEGIN CREATE INDEX IF NOT EXISTS account_vests_vests ON hafbe_app.account_vests USING btree (vests); - CALL hafbe_views.create_views(); - --ALTER SCHEMA hafbe_app OWNER TO hafbe_owner; END $$ diff --git a/run.sh b/run.sh index 61d7236..20cb00c 100755 --- a/run.sh +++ b/run.sh @@ -9,7 +9,6 @@ drop_db() { } create_db() { - psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -f api/views.sql psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -f db/hafbe_app.sql process_blocks $@ } @@ -24,7 +23,9 @@ create_api() { psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -f $postgrest_dir/backend.sql psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -f $postgrest_dir/endpoints.sql psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -f $postgrest_dir/exceptions.sql + psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -f $postgrest_dir/views.sql psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -f $postgrest_dir/roles.sql + psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "CALL hafbe_views.create_views();" } create_indexes() { -- GitLab From 84b623a7fbaefaf843c3f9f14741945fa6030145 Mon Sep 17 00:00:00 2001 From: kristupas Date: Wed, 14 Sep 2022 07:46:21 +0000 Subject: [PATCH 45/89] Optimized witnesses queries #22 --- api/backend.sql | 120 +++++++++++++++++++++++++----------------------- 1 file changed, 62 insertions(+), 58 deletions(-) diff --git a/api/backend.sql b/api/backend.sql index ecd6df7..a0cefb7 100644 --- a/api/backend.sql +++ b/api/backend.sql @@ -499,10 +499,10 @@ BEGIN SELECT witness_id, SUM(account_vests + proxied_vests) AS votes, - COUNT(voter_id) AS voters_num + COUNT(1) AS voters_num FROM hafbe_views.voters_stats_view GROUP BY witness_id - ) vsv + ) all_votes ORDER BY (CASE WHEN %L = 'desc' THEN %I ELSE NULL END) DESC, (CASE WHEN %L = 'asc' THEN %I ELSE NULL END) ASC @@ -543,7 +543,7 @@ BEGIN FROM hafbe_views.voters_stats_change_view WHERE timestamp >= %L GROUP BY witness_id - ) vscv + ) todays_votes ORDER BY (CASE WHEN %L = 'desc' THEN %I ELSE NULL END) DESC, (CASE WHEN %L = 'asc' THEN %I ELSE NULL END) ASC @@ -635,48 +635,50 @@ BEGIN RETURN QUERY SELECT witness, url, - COALESCE(votes, 0)::NUMERIC, - COALESCE(votes_daily_change, 0)::BIGINT, - COALESCE(voters_num, 0)::INT, - COALESCE(voters_num_daily_change, 0)::INT, + COALESCE(all_votes.votes, 0)::NUMERIC, + COALESCE(todays_votes.votes_daily_change, 0)::BIGINT, + COALESCE(all_votes.voters_num, 0)::INT, + COALESCE(todays_votes.voters_num_daily_change, 0)::INT, price_feed, bias, feed_age, block_size, signing_key, version FROM hafbe_backend.get_set_of_witnesses_by_name(_limit, _offset, _order_is) ls - LEFT JOIN ( + LEFT JOIN LATERAL ( SELECT - witness_id, - SUM(account_vests + proxied_vests) AS votes, - COUNT(voter_id) AS voters_num - FROM hafbe_views.voters_stats_view - GROUP BY witness_id + vsv.witness_id, + SUM(vsv.account_vests + vsv.proxied_vests) AS votes, + COUNT(1) AS voters_num + FROM hafbe_views.voters_stats_view vsv + WHERE vsv.witness_id = ls.witness_id + GROUP BY vsv.witness_id ) all_votes ON all_votes.witness_id = ls.witness_id - LEFT JOIN ( + LEFT JOIN LATERAL ( SELECT - witness_id, - SUM(CASE WHEN approve IS TRUE THEN votes ELSE -1 * votes END) AS votes_daily_change, - SUM(CASE WHEN approve IS TRUE THEN 1 ELSE -1 END) AS voters_num_daily_change - FROM hafbe_views.voters_stats_change_view - WHERE timestamp >= __today - GROUP BY witness_id + vscv.witness_id, + SUM(CASE WHEN vscv.approve IS TRUE THEN vscv.votes ELSE -1 * vscv.votes END) AS votes_daily_change, + SUM(CASE WHEN vscv.approve IS TRUE THEN 1 ELSE -1 END) AS voters_num_daily_change + FROM hafbe_views.voters_stats_change_view vscv + WHERE timestamp >= __today AND vscv.witness_id = ls.witness_id + GROUP BY vscv.witness_id ) todays_votes ON todays_votes.witness_id = ls.witness_id; ELSIF _order_by = ANY('{votes,voters_num}'::TEXT[]) THEN RETURN QUERY SELECT - hav.name::TEXT, url, votes, - COALESCE(votes_daily_change, 0)::BIGINT AS votes_daily_change, - voters_num, - COALESCE(voters_num_daily_change, 0)::INT AS voters_num_daily_change, + hav.name::TEXT, url, + ls.votes, + COALESCE(todays_votes.votes_daily_change, 0)::BIGINT AS votes_daily_change, + ls.voters_num, + COALESCE(todays_votes.voters_num_daily_change, 0)::INT AS voters_num_daily_change, price_feed, bias, feed_age, block_size, signing_key, version FROM hafbe_backend.get_set_of_witnesses_by_votes(_limit, _offset, _order_by, _order_is) ls JOIN hafbe_app.current_witnesses cw ON cw.witness_id = ls.witness_id - LEFT JOIN ( + LEFT JOIN LATERAL ( SELECT - witness_id, - SUM(CASE WHEN approve IS TRUE THEN votes ELSE -1 * votes END) AS votes_daily_change, - SUM(CASE WHEN approve IS TRUE THEN 1 ELSE -1 END) AS voters_num_daily_change - FROM hafbe_views.voters_stats_change_view - WHERE timestamp >= __today - GROUP BY witness_id + vscv.witness_id, + SUM(CASE WHEN vscv.approve IS TRUE THEN vscv.votes ELSE -1 * vscv.votes END) AS votes_daily_change, + SUM(CASE WHEN vscv.approve IS TRUE THEN 1 ELSE -1 END) AS voters_num_daily_change + FROM hafbe_views.voters_stats_change_view vscv + WHERE timestamp >= __today AND vscv.witness_id = ls.witness_id + GROUP BY vscv.witness_id ) todays_votes ON todays_votes.witness_id = ls.witness_id JOIN ( SELECT name, id @@ -687,20 +689,21 @@ BEGIN RETURN QUERY SELECT hav.name::TEXT, url, - COALESCE(votes, 0)::NUMERIC, - votes_daily_change, - COALESCE(voters_num, 0)::INT, - voters_num_daily_change, + all_votes.votes::NUMERIC, + ls.votes_daily_change, + all_votes.voters_num::INT, + ls.voters_num_daily_change, price_feed, bias, feed_age, block_size, signing_key, version FROM hafbe_backend.get_set_of_witnesses_by_votes_change(_limit, _offset, _order_by, _order_is, __today) ls JOIN hafbe_app.current_witnesses cw ON cw.witness_id = ls.witness_id - LEFT JOIN ( + JOIN LATERAL ( SELECT - witness_id, - SUM(account_vests + proxied_vests) AS votes, - COUNT(voter_id) AS voters_num - FROM hafbe_views.voters_stats_view - GROUP BY witness_id + vsv.witness_id, + SUM(vsv.account_vests + vsv.proxied_vests) AS votes, + COUNT(1) AS voters_num + FROM hafbe_views.voters_stats_view vsv + WHERE vsv.witness_id = ls.witness_id + GROUP BY vsv.witness_id ) all_votes ON all_votes.witness_id = ls.witness_id JOIN ( SELECT name, id @@ -711,28 +714,29 @@ BEGIN RETURN QUERY SELECT hav.name::TEXT, url, - COALESCE(votes, 0)::NUMERIC, - COALESCE(votes_daily_change, 0)::BIGINT, - COALESCE(voters_num, 0)::INT, - COALESCE(voters_num_daily_change, 0)::INT, + COALESCE(all_votes.votes, 0)::NUMERIC, + COALESCE(todays_votes.votes_daily_change, 0)::BIGINT, + COALESCE(all_votes.voters_num, 0)::INT, + COALESCE(todays_votes.voters_num_daily_change, 0)::INT, price_feed, bias, feed_age, block_size, signing_key, version FROM hafbe_backend.get_set_of_witnesses_by_prop(_limit, _offset, _order_by, _order_is) ls - LEFT JOIN ( + LEFT JOIN LATERAL ( SELECT - witness_id, - SUM(account_vests + proxied_vests) AS votes, - COUNT(voter_id) AS voters_num - FROM hafbe_views.voters_stats_view - GROUP BY witness_id + vsv.witness_id, + SUM(vsv.account_vests + vsv.proxied_vests) AS votes, + COUNT(1) AS voters_num + FROM hafbe_views.voters_stats_view vsv + WHERE vsv.witness_id = ls.witness_id + GROUP BY vsv.witness_id ) all_votes ON all_votes.witness_id = ls.witness_id - LEFT JOIN ( + LEFT JOIN LATERAL ( SELECT - witness_id, - SUM(CASE WHEN approve IS TRUE THEN votes ELSE -1 * votes END) AS votes_daily_change, - SUM(CASE WHEN approve IS TRUE THEN 1 ELSE -1 END) AS voters_num_daily_change - FROM hafbe_views.voters_stats_change_view - WHERE timestamp >= __today - GROUP BY witness_id + vscv.witness_id, + SUM(CASE WHEN vscv.approve IS TRUE THEN vscv.votes ELSE -1 * vscv.votes END) AS votes_daily_change, + SUM(CASE WHEN vscv.approve IS TRUE THEN 1 ELSE -1 END) AS voters_num_daily_change + FROM hafbe_views.voters_stats_change_view vscv + WHERE timestamp >= __today AND vscv.witness_id = ls.witness_id + GROUP BY vscv.witness_id ) todays_votes ON todays_votes.witness_id = ls.witness_id JOIN ( SELECT name, id -- GitLab From b6fb6dad40379aa99b649837fc22b096071d4824 Mon Sep 17 00:00:00 2001 From: kristupas Date: Thu, 15 Sep 2022 10:48:26 +0000 Subject: [PATCH 46/89] Fix 'format()' bug in 'get_witness_voters()' #22 --- api/backend.sql | 4 ++-- 1 file changed, 2 insertions(+), 2 deletions(-) diff --git a/api/backend.sql b/api/backend.sql index a0cefb7..b7bb985 100644 --- a/api/backend.sql +++ b/api/backend.sql @@ -397,7 +397,7 @@ BEGIN JOIN ( SELECT voter_id FROM hafbe_app.current_witness_votes - WHERE witness_id = _witness_id + WHERE witness_id = %L ) cwv ON cwv.voter_id = id JOIN ( @@ -413,7 +413,7 @@ BEGIN LIMIT %L; $query$, - _witness_id, _order_is, _order_by, _order_is, _order_by, _limit + _witness_id, _witness_id, _order_is, _order_by, _order_is, _order_by, _offset, _limit ) res; END $function$ -- GitLab From a5b7b5a11d33373c1d437df986b3ed50fe9539d6 Mon Sep 17 00:00:00 2001 From: kristupas Date: Fri, 16 Sep 2022 12:54:43 +0000 Subject: [PATCH 47/89] Implemented usage of 'hive.extract_set_witness_properties()', joined recursively proxied account vests #22 --- api/backend.sql | 6 ++-- api/views.sql | 81 ++++++++++++++++++++++++++++++++++++++---------- db/hafbe_app.sql | 66 +++++++++------------------------------ 3 files changed, 83 insertions(+), 70 deletions(-) diff --git a/api/backend.sql b/api/backend.sql index b7bb985..50e951d 100644 --- a/api/backend.sql +++ b/api/backend.sql @@ -442,7 +442,7 @@ CREATE TYPE hafbe_backend.witnesses_by_name AS ( witness_id INT, witness TEXT, url TEXT, - price_feed TEXT, + price_feed FLOAT, bias INT, feed_age INTERVAL, block_size INT, @@ -564,7 +564,7 @@ SET from_collapse_limit=16 CREATE TYPE hafbe_backend.witnesses_by_prop AS ( witness_id INT, url TEXT, - price_feed TEXT, + price_feed FLOAT, bias INT, feed_age INTERVAL, block_size INT, @@ -608,7 +608,7 @@ CREATE TYPE hafbe_backend.witnesses AS ( votes_daily_change BIGINT, voters_num INT, voters_num_daily_change INT, - price_feed TEXT, --JSON, + price_feed FLOAT, bias INT, feed_age INTERVAL, block_size INT, diff --git a/api/views.sql b/api/views.sql index ce6db0c..8da86da 100644 --- a/api/views.sql +++ b/api/views.sql @@ -7,37 +7,86 @@ LANGUAGE 'plpgsql' AS $$ BEGIN + DROP VIEW IF EXISTS hafbe_views.recursively_proxied_vests_view; + CREATE VIEW hafbe_views.recursively_proxied_vests_view AS + SELECT + proxies.voter_id, + SUM(proxied.vests) AS proxied_vests + FROM ( + SELECT + prox1.proxy_id AS voter_id, + prox1.account_id AS voters_proxies, + prox2.account_id AS proxies_of_voters_proxies, + prox3.account_id AS proxies_of_proxies1, + prox4.account_id AS proxies_of_proxies2, + prox5.account_id AS proxies_of_proxies3 + FROM hafbe_app.current_account_proxies prox1 + + LEFT JOIN ( + SELECT account_id, proxy_id + FROM hafbe_app.current_account_proxies + WHERE proxy = true + ) prox2 ON prox2.proxy_id = prox1.account_id + + LEFT JOIN ( + SELECT account_id, proxy_id + FROM hafbe_app.current_account_proxies + WHERE proxy = true + ) prox3 ON prox3.proxy_id = prox2.account_id + + LEFT JOIN ( + SELECT account_id, proxy_id + FROM hafbe_app.current_account_proxies + WHERE proxy = true + ) prox4 ON prox4.proxy_id = prox3.account_id + + LEFT JOIN ( + SELECT account_id, proxy_id + FROM hafbe_app.current_account_proxies + WHERE proxy = true + ) prox5 ON prox5.proxy_id = prox4.account_id + + WHERE prox1.proxy = TRUE + ) proxies + + CROSS JOIN LATERAL ( + VALUES (voters_proxies), (proxies_of_voters_proxies), (proxies_of_proxies1), (proxies_of_proxies2), (proxies_of_proxies3) + ) AS unpivot(account_id) + + JOIN LATERAL ( + SELECT vests, account_id + FROM hafbe_app.account_vests + WHERE account_id = unpivot.account_id + ) proxied ON proxied.account_id = unpivot.account_id + + WHERE unpivot.account_id IS NOT NULL + GROUP BY proxies.voter_id + ; + DROP VIEW IF EXISTS hafbe_views.voters_stats_view; CREATE VIEW hafbe_views.voters_stats_view AS SELECT - witness_id, voter_id, timestamp, + cwv.witness_id, cwv.voter_id, cwv.timestamp, COALESCE(account.vests, 0)::NUMERIC AS account_vests, - SUM(COALESCE(proxied.vests, 0)) AS proxied_vests - FROM hafbe_app.current_witness_votes - - LEFT JOIN ( - SELECT account_id, proxy_id - FROM hafbe_app.current_account_proxies - WHERE proxy = TRUE - ) acc_as_proxy ON acc_as_proxy.proxy_id = voter_id + COALESCE(rpv.proxied_vests, 0) AS proxied_vests + FROM hafbe_app.current_witness_votes cwv LEFT JOIN ( - SELECT vests, account_id - FROM hafbe_app.account_vests - ) proxied ON proxied.account_id = acc_as_proxy.account_id + SELECT voter_id, proxied_vests + FROM hafbe_views.recursively_proxied_vests_view + ) rpv ON rpv.voter_id = cwv.voter_id LEFT JOIN ( SELECT account_id, proxy FROM hafbe_app.current_account_proxies - ) acc_as_proxied ON acc_as_proxied.account_id = voter_id + ) acc_as_proxied ON acc_as_proxied.account_id = cwv.voter_id LEFT JOIN ( SELECT vests, account_id FROM hafbe_app.account_vests - ) account ON account.account_id = voter_id AND COALESCE(acc_as_proxied.proxy, FALSE) IS FALSE + ) account ON account.account_id = cwv.voter_id AND COALESCE(acc_as_proxied.proxy, FALSE) IS FALSE - WHERE approve IS TRUE - GROUP BY witness_id, voter_id, account.vests; + WHERE cwv.approve IS TRUE; ------ diff --git a/db/hafbe_app.sql b/db/hafbe_app.sql index 3da2368..7f6938f 100644 --- a/db/hafbe_app.sql +++ b/db/hafbe_app.sql @@ -63,7 +63,7 @@ BEGIN CREATE TABLE IF NOT EXISTS hafbe_app.current_witnesses ( witness_id INT NOT NULL, url TEXT, - price_feed TEXT, + price_feed FLOAT, bias INT, feed_age INTERVAL, block_size INT, @@ -205,47 +205,6 @@ END $$ ; -CREATE OR REPLACE FUNCTION hafbe_app.unpack_from_vector(_vector TEXT) -RETURNS TEXT -LANGUAGE 'plpgsql' -AS -$$ -BEGIN - -- TODO: to be replaced by hive fork manager method - RETURN _vector; -END -$$ -; - -CREATE OR REPLACE FUNCTION hafbe_app.parse_witness_set_props(_op_value JSON, _attr_name TEXT) -RETURNS TEXT -LANGUAGE 'plpgsql' -AS -$$ -DECLARE - __result TEXT; -BEGIN - SELECT INTO __result - props->>1 - FROM ( - SELECT json_array_elements(_op_value->'props') AS props - ) to_arr - WHERE props->>0 = _attr_name; - - IF _attr_name = 'new_signing_key' AND __result IS NULL THEN - SELECT INTO __result - props->>1 - FROM ( - SELECT json_array_elements(_op_value->'props') AS props - ) to_arr - WHERE props->>0 = 'key'; - END IF; - - RETURN hafbe_app.unpack_from_vector(__result); -END -$$ -; - CREATE OR REPLACE FUNCTION hafbe_app.process_block_range_data_c(_from INT, _to INT, _report_step INT = 1000) RETURNS VOID LANGUAGE 'plpgsql' @@ -353,7 +312,7 @@ BEGIN -- parse witness url 42,11 IF __prop_op.op_type_id = ANY('{42,11}'::INT[]) THEN IF __prop_op.op_type_id = 42 THEN - SELECT hafbe_app.parse_witness_set_props(__prop_op.value, 'url') INTO __prop_value; + SELECT hive.extract_set_witness_properties(__prop_op.value->>'props') WHERE prop_name = 'url' INTO __prop_value; ELSE SELECT __prop_op.value->>'url' INTO __prop_value; END IF; @@ -365,22 +324,23 @@ BEGIN -- parse witness feed_data 42,7 ELSIF __prop_op.op_type_id = ANY('{42,7}'::INT[]) THEN IF __prop_op.op_type_id = 42 THEN - SELECT hafbe_app.parse_witness_set_props(__prop_op.value, 'hbd_exchange_rate') INTO __prop_value; + SELECT hive.extract_set_witness_properties(__prop_op.value->>'props') WHERE prop_name = 'hbd_exchange_rate' INTO __prop_value; ELSE - SELECT __prop_op.value->>'exchange_rate' INTO __prop_value; + SELECT __prop_op.value->'exchange_rate' INTO __prop_value; END IF; IF __prop_value IS NOT NULL THEN - UPDATE hafbe_app.current_witnesses cw SET price_feed = __prop_value WHERE witness_id = __prop_op.witness_id; - -- (((__prop_value::JSON)->'quote'->>'amount')::INT - 1000)::INT - UPDATE hafbe_app.current_witnesses cw SET bias = 0::INT WHERE witness_id = __prop_op.witness_id; - UPDATE hafbe_app.current_witnesses cw SET feed_age = (NOW() - __prop_op.timestamp)::INTERVAL WHERE witness_id = __prop_op.witness_id; + UPDATE hafbe_app.current_witnesses cw SET + price_feed = ((__prop_value::JSON)->'base'->>'amount')::INT / ((__prop_value::JSON)->'quote'->>'amount')::INT, + bias = (((__prop_value::JSON)->'quote'->>'amount')::INT - 1000)::INT, + feed_age = (NOW() - __prop_op.timestamp)::INTERVAL + WHERE witness_id = __prop_op.witness_id; END IF; -- parse witness block_size 42,30,14,11 ELSIF __prop_op.op_type_id = ANY('{42,30,14,11}'::INT[]) THEN IF __prop_op.op_type_id = 42 THEN - SELECT hafbe_app.parse_witness_set_props(__prop_op.value, 'maximum_block_size') INTO __prop_value; + SELECT hive.extract_set_witness_properties(__prop_op.value->>'props') WHERE prop_name = 'maximum_block_size' INTO __prop_value; ELSE SELECT __prop_op.value->>'maximum_block_size' INTO __prop_value; END IF; @@ -392,11 +352,15 @@ BEGIN -- parse witness signing_key 42,11 ELSIF __prop_op.op_type_id = ANY('{42,11}'::INT[]) THEN IF __prop_op.op_type_id = 42 THEN - SELECT hafbe_app.parse_witness_set_props(__prop_op.value, 'new_signing_key') INTO __prop_value; + SELECT hive.extract_set_witness_properties(__prop_op.value->>'props') WHERE prop_name = 'new_signing_key' INTO __prop_value; ELSE SELECT __prop_op.value->>'block_signing_key' INTO __prop_value; END IF; + IF __prop_op.op_type_id = 42 AND __prop_value IS NULL THEN + SELECT hive.extract_set_witness_properties(__prop_op.value->>'props') WHERE prop_name = 'key' INTO __prop_value; + END IF; + IF __prop_value IS NOT NULL THEN UPDATE hafbe_app.current_witnesses cw SET signing_key = __prop_value WHERE witness_id = __prop_op.witness_id; END IF; -- GitLab From dda1dfbe8204e73dac43d7541dc4b5d049232a7d Mon Sep 17 00:00:00 2001 From: kristupas Date: Thu, 22 Sep 2022 08:14:39 +0000 Subject: [PATCH 48/89] Moved helper functions to 'endpoints.sql', moved TYPEs to 'types.sql', updated 'get_block()' to use haf data, refined app setup #22 --- api/backend.sql | 353 ++++++++-------------------------------------- api/endpoints.sql | 77 +++++++--- api/roles.sql | 3 + api/types.sql | 79 +++++++++++ api/views.sql | 218 ++++++++++++++-------------- db/hafbe_app.sql | 40 ++---- db/indexes.sql | 43 ++++++ run.sh | 35 ++--- 8 files changed, 377 insertions(+), 471 deletions(-) create mode 100644 api/types.sql create mode 100644 db/indexes.sql diff --git a/api/backend.sql b/api/backend.sql index 50e951d..201ff9f 100644 --- a/api/backend.sql +++ b/api/backend.sql @@ -19,28 +19,6 @@ END $$ ; -CREATE FUNCTION hafbe_backend.get_block_num(_block_hash BYTEA) -RETURNS INT -LANGUAGE 'plpgsql' -AS -$$ -BEGIN - RETURN num FROM hive.blocks WHERE hash=_block_hash; -END -$$ -; - -CREATE FUNCTION hafbe_backend.find_matching_accounts(_partial_account_name TEXT) -RETURNS JSON -LANGUAGE 'plpgsql' -AS -$$ -BEGIN - RETURN btracker_app.find_matching_accounts(_partial_account_name); -END -$$ -; - CREATE FUNCTION hafbe_backend.get_account_id(_account TEXT) RETURNS INT LANGUAGE 'plpgsql' @@ -56,129 +34,62 @@ $$ operation types */ -CREATE FUNCTION hafbe_backend.format_op_types(_operation_id BIGINT, _operation_name TEXT, _is_virtual BOOLEAN) -RETURNS JSON -LANGUAGE 'plpgsql' -AS -$$ -BEGIN - RETURN ('[' || _operation_id || ', "' || split_part(_operation_name, '::', 3) || '", ' || _is_virtual || ']'); -END -$$ -; - -CREATE TYPE hafbe_backend.op_types AS ( - op_type_id INT, - operation_name TEXT, - is_virtual BOOLEAN -); - CREATE FUNCTION hafbe_backend.get_set_of_op_types() -RETURNS SETOF hafbe_backend.op_types +RETURNS SETOF hafbe_types.op_types LANGUAGE 'plpgsql' AS $$ BEGIN RETURN QUERY SELECT - id::INT, - name::TEXT, - is_virtual::BOOLEAN + id, name, is_virtual FROM hive.operation_types ORDER BY id ASC; END $$ ; -CREATE FUNCTION hafbe_backend.get_op_types() -RETURNS JSON -LANGUAGE 'plpgsql' -AS -$$ -BEGIN - RETURN CASE WHEN res.arr IS NOT NULL THEN res.arr ELSE '[]'::JSON END FROM ( - SELECT json_agg(hafbe_backend.format_op_types(op_type_id, operation_name, is_virtual)) AS arr - FROM hafbe_backend.get_set_of_op_types() - ) res; -END -$$ -; - CREATE FUNCTION hafbe_backend.get_set_of_acc_op_types(_account_id INT) -RETURNS SETOF hafbe_backend.op_types -LANGUAGE 'plpgsql' +RETURNS SETOF hafbe_types.op_types AS -$$ +$function$ BEGIN RETURN QUERY SELECT - aoc.op_type_id, - hot.name::TEXT, - hot.is_virtual::BOOLEAN - FROM ( - SELECT op_type_id - FROM hafbe_app.account_operation_cache - WHERE account_id = _account_id - ) aoc - - JOIN LATERAL ( + aoc.op_type_id, hot.name, hot.is_virtual + FROM hafbe_app.account_operation_cache aoc + JOIN ( SELECT id, name, is_virtual FROM hive.operation_types ) hot ON hot.id = aoc.op_type_id + WHERE aoc.account_id = _account_id ORDER BY aoc.op_type_id ASC; END -$$ -; - -CREATE FUNCTION hafbe_backend.get_acc_op_types(_account_id INT) -RETURNS JSON -LANGUAGE 'plpgsql' -AS -$$ -BEGIN - RETURN CASE WHEN res.arr IS NOT NULL THEN res.arr ELSE '[]'::JSON END FROM ( - SELECT json_agg(hafbe_backend.format_op_types(op_type_id, operation_name, is_virtual)) AS arr - FROM hafbe_backend.get_set_of_acc_op_types(_account_id) - ) res; -END -$$ +$function$ +LANGUAGE 'plpgsql' STABLE +SET JIT=OFF +SET join_collapse_limit=16 +SET from_collapse_limit=16 ; CREATE FUNCTION hafbe_backend.get_set_of_block_op_types(_block_num INT) -RETURNS SETOF hafbe_backend.op_types -LANGUAGE 'plpgsql' +RETURNS SETOF hafbe_types.op_types AS -$$ +$function$ BEGIN RETURN QUERY SELECT - hot.id::INT, - hot.name::TEXT, - hot.is_virtual::BOOLEAN - FROM ( - SELECT DISTINCT op_type_id - FROM hive.operations_view - WHERE block_num = _block_num - ) hov - - JOIN LATERAL ( + hov.op_type_id, hot.name, hot.is_virtual + FROM hive.operations_view hov + JOIN ( SELECT id, name, is_virtual FROM hive.operation_types ) hot ON hot.id = hov.op_type_id + WHERE hov.block_num = _block_num ORDER BY hov.op_type_id ASC; END -$$ -; - -CREATE FUNCTION hafbe_backend.get_block_op_types(_block_num INT) -RETURNS JSON -LANGUAGE 'plpgsql' -AS -$$ -BEGIN - RETURN CASE WHEN res.arr IS NOT NULL THEN res.arr ELSE '[]'::JSON END FROM ( - SELECT json_agg(hafbe_backend.format_op_types(op_type_id, operation_name, is_virtual)) AS arr - FROM hafbe_backend.get_set_of_block_op_types(_block_num) - ) res; -END -$$ +$function$ +LANGUAGE 'plpgsql' STABLE +SET JIT=OFF +SET join_collapse_limit=16 +SET from_collapse_limit=16 ; /* @@ -198,20 +109,8 @@ END $$ ; -CREATE TYPE hafbe_backend.operations AS ( - trx_id TEXT, - block INT, - trx_in_block INT, - op_in_trx INT, - virtual_op BOOLEAN, - timestamp TEXT, - operations JSON, - operation_id BIGINT, - acc_operation_id BIGINT -); - CREATE FUNCTION hafbe_backend.get_set_of_ops_by_account(_account_id INT, _top_op_id BIGINT, _limit BIGINT, _filter SMALLINT[], _date_start TIMESTAMP, _date_end TIMESTAMP) -RETURNS SETOF hafbe_backend.operations +RETURNS SETOF hafbe_types.operations AS $function$ DECLARE @@ -261,30 +160,15 @@ SET join_collapse_limit=16 SET from_collapse_limit=16 ; -CREATE FUNCTION hafbe_backend.get_ops_by_account(_account_id INT, _top_op_id BIGINT, _limit BIGINT, _filter SMALLINT[], _date_start TIMESTAMP, _date_end TIMESTAMP) -RETURNS JSON -LANGUAGE 'plpgsql' -AS -$$ -BEGIN - RETURN CASE WHEN arr IS NOT NULL THEN to_json(arr) ELSE '[]'::JSON END FROM ( - SELECT ARRAY( - SELECT to_json(hafbe_backend.get_set_of_ops_by_account(_account_id, _top_op_id, _limit, _filter, _date_start, _date_end)) - ) arr - ) result; -END -$$ -; - CREATE FUNCTION hafbe_backend.get_set_of_ops_by_block(_block_num INT, _top_op_id BIGINT, _limit BIGINT, _filter SMALLINT[]) -RETURNS SETOF hafbe_backend.operations +RETURNS SETOF hafbe_types.operations AS $function$ DECLARE __filter_ops BOOLEAN = ((SELECT array_length(_filter, 1)) IS NULL); BEGIN RETURN QUERY SELECT - hafbe_backend.get_trx_hash(_block_num, hov.trx_in_block)::TEXT, + encode(htv.trx_hash, 'hex')::TEXT, _block_num::INT, hov.trx_in_block::INT, hov.op_pos::INT, @@ -294,11 +178,17 @@ BEGIN hov.id::BIGINT, NULL::BIGINT FROM hive.operations_view hov - JOIN LATERAL ( + JOIN ( SELECT id, is_virtual FROM hive.operation_types ) hot ON hot.id = hov.op_type_id - WHERE hov.block_num = _block_num AND hov.id <= _top_op_id AND ( + JOIN ( + SELECT trx_hash, block_num, trx_in_block + FROM hive.transactions_view + ) htv ON htv.block_num = hov.block_num AND htv.trx_in_block = hov.trx_in_block + WHERE + hov.block_num = _block_num AND + hov.id <= _top_op_id AND ( __filter_ops OR hov.op_type_id=ANY(_filter) ) ORDER BY hov.id DESC @@ -311,80 +201,44 @@ SET join_collapse_limit=16 SET from_collapse_limit=16 ; -CREATE FUNCTION hafbe_backend.get_ops_by_block(_block_num INT, _top_op_id BIGINT, _limit BIGINT, _filter SMALLINT[]) -RETURNS JSON -LANGUAGE 'plpgsql' -AS -$$ -BEGIN - RETURN CASE WHEN arr IS NOT NULL THEN to_json(arr) ELSE '[]'::JSON END FROM ( - SELECT ARRAY( - SELECT to_json(hafbe_backend.get_set_of_ops_by_block(_block_num, _top_op_id, _limit, _filter)) - ) arr - ) result; -END -$$ -; - /* Block stats */ CREATE FUNCTION hafbe_backend.get_block(_block_num INT) RETURNS JSON -LANGUAGE 'plpgsql' AS -$$ -DECLARE - __block_api_data JSON = (((SELECT hafbe_backend.get_block_api_data(_block_num))->'result')->'block'); +$function$ BEGIN - RETURN json_build_object( - 'block_num', _block_num, - 'block_hash', __block_api_data->>'block_id', - 'timestamp', __block_api_data->>'timestamp', - 'witness', __block_api_data->>'witness', - 'signing_key', __block_api_data->>'signing_key' - ); + RETURN to_json(res) FROM ( + SELECT + hbv.num AS block_num, + encode(hbv.hash, 'hex')::TEXT AS block_hash, + hbv.created_at AS timestamp, + hav.name AS witness, + hbv.signing_key + FROM hive.accounts_view hav + JOIN ( + SELECT num, hash, created_at, producer_account_id, signing_key + FROM hive.blocks_view + WHERE num = _block_num + LIMIT 1 + ) hbv ON hbv.producer_account_id = hav.id + ) res; END -$$ -; - -CREATE FUNCTION hafbe_backend.get_block_api_data(_block_num INT) -RETURNS JSON -LANGUAGE 'plpython3u' -AS -$$ - import subprocess - import json - - return json.dumps( - json.loads( - subprocess.check_output([ - """ - curl -X POST https://api.hive.blog \ - -H 'Content-Type: application/json' \ - -d '{"jsonrpc": "2.0", "method": "block_api.get_block", "params": {"block_num": %d}, "id": null}' - """ % _block_num - ], shell=True).decode('utf-8') - ) - ) -$$ +$function$ +LANGUAGE 'plpgsql' STABLE +SET JIT=OFF +SET join_collapse_limit=16 +SET from_collapse_limit=16 ; /* witnesses and voters */ -CREATE TYPE hafbe_backend.witness_voters AS ( - account TEXT, - vests NUMERIC, - account_vests NUMERIC, - proxied_vests NUMERIC, - timestamp TIMESTAMP -); - CREATE FUNCTION hafbe_backend.get_set_of_witness_voters(_witness_id INT, _limit INT, _offset INT, _order_by TEXT, _order_is TEXT) -RETURNS SETOF hafbe_backend.witness_voters +RETURNS SETOF hafbe_types.witness_voters AS $function$ BEGIN @@ -393,19 +247,16 @@ BEGIN SELECT name::TEXT, vsv.vests, vsv.account_vests, vsv.proxied_vests, vsv.timestamp FROM hive.accounts_view - JOIN ( SELECT voter_id FROM hafbe_app.current_witness_votes WHERE witness_id = %L ) cwv ON cwv.voter_id = id - JOIN ( SELECT voter_id, proxied_vests + account_vests AS vests, account_vests, proxied_vests, timestamp FROM hafbe_views.voters_stats_view WHERE witness_id = %L ) vsv ON vsv.voter_id = id - ORDER BY (CASE WHEN %L = 'desc' THEN %I ELSE NULL END) DESC, (CASE WHEN %L = 'asc' THEN %I ELSE NULL END) ASC @@ -423,35 +274,8 @@ SET join_collapse_limit=16 SET from_collapse_limit=16 ; -CREATE FUNCTION hafbe_backend.get_witness_voters(_witness_id INT, _limit INT, _offset INT, _order_by TEXT, _order_is TEXT) -RETURNS JSON -LANGUAGE 'plpgsql' -AS -$$ -BEGIN - RETURN CASE WHEN arr IS NOT NULL THEN to_json(arr) ELSE '[]'::JSON END FROM ( - SELECT ARRAY( - SELECT hafbe_backend.get_set_of_witness_voters(_witness_id, _limit, _offset, _order_by, _order_is) - ) arr - ) result; -END -$$ -; - -CREATE TYPE hafbe_backend.witnesses_by_name AS ( - witness_id INT, - witness TEXT, - url TEXT, - price_feed FLOAT, - bias INT, - feed_age INTERVAL, - block_size INT, - signing_key TEXT, - version TEXT -); - CREATE FUNCTION hafbe_backend.get_set_of_witnesses_by_name(_limit INT, _offset INT, _order_is TEXT) -RETURNS SETOF hafbe_backend.witnesses_by_name +RETURNS SETOF hafbe_types.witnesses_by_name AS $function$ BEGIN @@ -480,14 +304,8 @@ SET join_collapse_limit=16 SET from_collapse_limit=16 ; -CREATE TYPE hafbe_backend.witnesses_by_votes AS ( - witness_id INT, - votes NUMERIC, - voters_num INT -); - CREATE FUNCTION hafbe_backend.get_set_of_witnesses_by_votes(_limit INT, _offset INT, _order_by TEXT, _order_is TEXT) -RETURNS SETOF hafbe_backend.witnesses_by_votes +RETURNS SETOF hafbe_types.witnesses_by_votes AS $function$ BEGIN @@ -520,14 +338,8 @@ SET join_collapse_limit=16 SET from_collapse_limit=16 ; -CREATE TYPE hafbe_backend.witnesses_by_votes_change AS ( - witness_id INT, - votes_daily_change BIGINT, - voters_num_daily_change INT -); - CREATE FUNCTION hafbe_backend.get_set_of_witnesses_by_votes_change(_limit INT, _offset INT, _order_by TEXT, _order_is TEXT, _today DATE) -RETURNS SETOF hafbe_backend.witnesses_by_votes_change +RETURNS SETOF hafbe_types.witnesses_by_votes_change AS $function$ BEGIN @@ -561,19 +373,8 @@ SET join_collapse_limit=16 SET from_collapse_limit=16 ; -CREATE TYPE hafbe_backend.witnesses_by_prop AS ( - witness_id INT, - url TEXT, - price_feed FLOAT, - bias INT, - feed_age INTERVAL, - block_size INT, - signing_key TEXT, - version TEXT -); - CREATE FUNCTION hafbe_backend.get_set_of_witnesses_by_prop(_limit INT, _offset INT, _order_by TEXT, _order_is TEXT) -RETURNS SETOF hafbe_backend.witnesses_by_prop +RETURNS SETOF hafbe_types.witnesses_by_prop AS $function$ BEGIN @@ -601,23 +402,8 @@ SET join_collapse_limit=16 SET from_collapse_limit=16 ; -CREATE TYPE hafbe_backend.witnesses AS ( - witness TEXT, - url TEXT, - votes NUMERIC, - votes_daily_change BIGINT, - voters_num INT, - voters_num_daily_change INT, - price_feed FLOAT, - bias INT, - feed_age INTERVAL, - block_size INT, - signing_key TEXT, - version TEXT -); - CREATE FUNCTION hafbe_backend.get_set_of_witnesses(_limit INT, _offset INT, _order_by TEXT, _order_is TEXT) -RETURNS SETOF hafbe_backend.witnesses +RETURNS SETOF hafbe_types.witnesses AS $function$ DECLARE @@ -752,21 +538,6 @@ SET join_collapse_limit=16 SET from_collapse_limit=16 ; -CREATE FUNCTION hafbe_backend.get_witnesses(_limit INT, _offset INT, _order_by TEXT, _order_is TEXT) -RETURNS JSON -LANGUAGE 'plpgsql' -AS -$$ -BEGIN - RETURN CASE WHEN arr IS NOT NULL THEN to_json(arr) ELSE '[]'::JSON END FROM ( - SELECT ARRAY( - SELECT hafbe_backend.get_set_of_witnesses(_limit, _offset, _order_by, _order_is) - ) arr - ) result; -END -$$ -; - /* account data */ diff --git a/api/endpoints.sql b/api/endpoints.sql index 4575c27..48e96c6 100644 --- a/api/endpoints.sql +++ b/api/endpoints.sql @@ -17,14 +17,13 @@ LANGUAGE 'plpgsql' AS $$ DECLARE - __input_type TEXT; - __input_value TEXT = _input; + __hash BYTEA; __block_num INT; __head_block_num INT; __accounts_array JSON; BEGIN -- first, name existance is checked - IF (SELECT name FROM hive.accounts WHERE name = _input LIMIT 1) IS NOT NULL THEN + IF (SELECT 1 FROM hive.accounts_view WHERE name = _input LIMIT 1) IS NOT NULL THEN RETURN json_build_object( 'input_type', 'account_name', 'input_value', _input @@ -47,35 +46,37 @@ BEGIN -- third, if input is 40 char hash, it is validated for transaction or block hash -- hash is unknown if failed to validate IF _input SIMILAR TO '([a-f0-9]{40})' THEN - IF (SELECT trx_hash FROM hive.transactions WHERE trx_hash = ('\x' || _input)::BYTEA LIMIT 1) IS NOT NULL THEN + SELECT ('\x' || _input)::BYTEA INTO __hash; + + IF (SELECT trx_hash FROM hive.transactions WHERE trx_hash = __hash LIMIT 1) IS NOT NULL THEN RETURN json_build_object( 'input_type', 'transaction_hash', 'input_value', _input ); ELSE - __block_num = hafbe_backend.get_block_num(('\x' || _input)::BYTEA); + SELECT num FROM hive.blocks_view WHERE hash = __hash LIMIT 1 INTO __block_num; END IF; - IF __input_type IS NULL AND __block_num IS NOT NULL THEN + IF __block_num IS NOT NULL THEN RETURN json_build_object( 'input_type', 'block_hash', 'input_value', __block_num ); - ELSIF __input_type IS NULL AND __block_num IS NULL THEN - RETURN hafbe_exceptions.raise_unknown_hash_exception(_input::TEXT); + ELSE + RETURN hafbe_exceptions.raise_unknown_hash_exception(_input); END IF; END IF; -- fourth, it is still possible input is partial name, max 50 names returned. -- if no matching accounts were found, 'unknown_input' is returned - SELECT hafbe_backend.find_matching_accounts(_input::TEXT) INTO __accounts_array; + SELECT btracker_app.find_matching_accounts(_input) INTO __accounts_array; IF __accounts_array IS NOT NULL THEN RETURN json_build_object( 'input_type', 'account_name_array', 'input_value', __accounts_array ); ELSE - RETURN hafbe_exceptions.raise_unknown_input_exception(_input::TEXT); + RETURN hafbe_exceptions.raise_unknown_input_exception(_input); END IF; END $$ @@ -92,13 +93,31 @@ END $$ ; +/* +operation types +*/ + +CREATE FUNCTION hafbe_endpoints.format_op_types(op_type_id INT, _operation_name TEXT, _is_virtual BOOLEAN) +RETURNS JSON +LANGUAGE 'plpgsql' +AS +$$ +BEGIN + RETURN ('[' || op_type_id || ', "' || split_part(_operation_name, '::', 3) || '", ' || _is_virtual || ']'); +END +$$ +; + CREATE FUNCTION hafbe_endpoints.get_op_types() RETURNS JSON LANGUAGE 'plpgsql' AS $$ BEGIN - RETURN hafbe_backend.get_op_types(); + RETURN CASE WHEN res.arr IS NOT NULL THEN res.arr ELSE '[]'::JSON END FROM ( + SELECT json_agg(hafbe_endpoints.format_op_types(op_type_id, operation_name, is_virtual)) AS arr + FROM hafbe_backend.get_set_of_op_types() + ) res; END $$ ; @@ -111,7 +130,10 @@ $$ DECLARE __account_id INT = hafbe_backend.get_account_id(_account); BEGIN - RETURN hafbe_backend.get_acc_op_types(__account_id); + RETURN CASE WHEN res.arr IS NOT NULL THEN res.arr ELSE '[]'::JSON END FROM ( + SELECT json_agg(hafbe_endpoints.format_op_types(op_type_id, operation_name, is_virtual)) AS arr + FROM hafbe_backend.get_set_of_acc_op_types(__account_id) + ) res; END $$ ; @@ -122,7 +144,10 @@ LANGUAGE 'plpgsql' AS $$ BEGIN - RETURN hafbe_backend.get_block_op_types(_block_num); + RETURN CASE WHEN res.arr IS NOT NULL THEN res.arr ELSE '[]'::JSON END FROM ( + SELECT json_agg(hafbe_endpoints.format_op_types(op_type_id, operation_name, is_virtual)) AS arr + FROM hafbe_backend.get_set_of_block_op_types(_block_num) + ) res; END $$ ; @@ -153,7 +178,11 @@ BEGIN SELECT hafbe_backend.get_account_id(_account) INTO __account_id; - RETURN hafbe_backend.get_ops_by_account(__account_id, _top_op_id, _limit, _filter, _date_start, _date_end); + RETURN CASE WHEN arr IS NOT NULL THEN to_json(arr) ELSE '[]'::JSON END FROM ( + SELECT ARRAY( + SELECT to_json(hafbe_backend.get_set_of_ops_by_account(__account_id, _top_op_id, _limit, _filter, _date_start, _date_end)) + ) arr + ) result; END $$ ; @@ -191,7 +220,11 @@ BEGIN _filter = ARRAY[]::SMALLINT[]; END IF; - RETURN hafbe_backend.get_ops_by_block(_block_num, _top_op_id, _limit, _filter); + RETURN CASE WHEN arr IS NOT NULL THEN to_json(arr) ELSE '[]'::JSON END FROM ( + SELECT ARRAY( + SELECT to_json(hafbe_backend.get_set_of_ops_by_block(_block_num, _top_op_id, _limit, _filter)) + ) arr + ) result; END $$ ; @@ -238,12 +271,16 @@ BEGIN _order_is = 'desc'; END IF; - RETURN hafbe_backend.get_witness_voters(__witness_id, _limit, _offset, _order_by, _order_is); + RETURN CASE WHEN arr IS NOT NULL THEN to_json(arr) ELSE '[]'::JSON END FROM ( + SELECT ARRAY( + SELECT hafbe_backend.get_set_of_witness_voters(__witness_id, _limit, _offset, _order_by, _order_is) + ) arr + ) result; END $$ ; -CREATE FUNCTION hafbe_endpoints.get_witnesses(_limit INT = 50, _offset INT = 0, _order_by TEXT = 'vests', _order_is TEXT = 'desc') +CREATE FUNCTION hafbe_endpoints.get_witnesses(_limit INT = 50, _offset INT = 0, _order_by TEXT = 'votes', _order_is TEXT = 'desc') RETURNS JSON LANGUAGE 'plpgsql' AS @@ -272,7 +309,11 @@ BEGIN _order_is = 'desc'; END IF; - RETURN hafbe_backend.get_witnesses(_limit, _offset, _order_by, _order_is); + RETURN CASE WHEN arr IS NOT NULL THEN to_json(arr) ELSE '[]'::JSON END FROM ( + SELECT ARRAY( + SELECT hafbe_backend.get_set_of_witnesses(_limit, _offset, _order_by, _order_is) + ) arr + ) result; END $$ ; diff --git a/api/roles.sql b/api/roles.sql index ab5431e..b68ec02 100755 --- a/api/roles.sql +++ b/api/roles.sql @@ -34,6 +34,9 @@ GRANT SELECT ON ALL TABLES IN SCHEMA hafbe_exceptions TO hafbe_user; GRANT USAGE ON SCHEMA hafbe_views TO hafbe_user; GRANT SELECT ON ALL TABLES IN SCHEMA hafbe_views TO hafbe_user; +GRANT USAGE ON SCHEMA hafbe_types TO hafbe_user; +GRANT SELECT ON ALL TABLES IN SCHEMA hafbe_types TO hafbe_user; + GRANT USAGE ON SCHEMA btracker_app TO hafbe_user; GRANT SELECT ON ALL TABLES IN SCHEMA btracker_app TO hafbe_user; GRANT EXECUTE ON ALL FUNCTIONS IN SCHEMA btracker_app TO hafbe_user; diff --git a/api/types.sql b/api/types.sql new file mode 100644 index 0000000..4b36446 --- /dev/null +++ b/api/types.sql @@ -0,0 +1,79 @@ +DROP SCHEMA IF EXISTS hafbe_types CASCADE; + +CREATE SCHEMA IF NOT EXISTS hafbe_types; + +CREATE TYPE hafbe_types.op_types AS ( + op_type_id SMALLINT, + operation_name TEXT, + is_virtual BOOLEAN +); + +CREATE TYPE hafbe_types.operations AS ( + trx_id TEXT, + block INT, + trx_in_block INT, + op_in_trx INT, + virtual_op BOOLEAN, + timestamp TEXT, + operations JSON, + operation_id BIGINT, + acc_operation_id BIGINT +); + +CREATE TYPE hafbe_types.witness_voters AS ( + account TEXT, + vests NUMERIC, + account_vests NUMERIC, + proxied_vests NUMERIC, + timestamp TIMESTAMP +); + +CREATE TYPE hafbe_types.witnesses_by_name AS ( + witness_id INT, + witness TEXT, + url TEXT, + price_feed FLOAT, + bias INT, + feed_age INTERVAL, + block_size INT, + signing_key TEXT, + version TEXT +); + +CREATE TYPE hafbe_types.witnesses_by_votes AS ( + witness_id INT, + votes NUMERIC, + voters_num INT +); + +CREATE TYPE hafbe_types.witnesses_by_votes_change AS ( + witness_id INT, + votes_daily_change BIGINT, + voters_num_daily_change INT +); + +CREATE TYPE hafbe_types.witnesses_by_prop AS ( + witness_id INT, + url TEXT, + price_feed FLOAT, + bias INT, + feed_age INTERVAL, + block_size INT, + signing_key TEXT, + version TEXT +); + +CREATE TYPE hafbe_types.witnesses AS ( + witness TEXT, + url TEXT, + votes NUMERIC, + votes_daily_change BIGINT, + voters_num INT, + voters_num_daily_change INT, + price_feed FLOAT, + bias INT, + feed_age INTERVAL, + block_size INT, + signing_key TEXT, + version TEXT +); \ No newline at end of file diff --git a/api/views.sql b/api/views.sql index 8da86da..5385ffa 100644 --- a/api/views.sql +++ b/api/views.sql @@ -2,126 +2,118 @@ DROP SCHEMA IF EXISTS hafbe_views CASCADE; CREATE SCHEMA hafbe_views; -CREATE PROCEDURE hafbe_views.create_views() -LANGUAGE 'plpgsql' -AS -$$ -BEGIN - DROP VIEW IF EXISTS hafbe_views.recursively_proxied_vests_view; - CREATE VIEW hafbe_views.recursively_proxied_vests_view AS +DROP VIEW IF EXISTS hafbe_views.recursively_proxied_vests_view; +CREATE VIEW hafbe_views.recursively_proxied_vests_view AS +SELECT + proxies.voter_id, + SUM(proxied.vests) AS proxied_vests +FROM ( SELECT - proxies.voter_id, - SUM(proxied.vests) AS proxied_vests - FROM ( - SELECT - prox1.proxy_id AS voter_id, - prox1.account_id AS voters_proxies, - prox2.account_id AS proxies_of_voters_proxies, - prox3.account_id AS proxies_of_proxies1, - prox4.account_id AS proxies_of_proxies2, - prox5.account_id AS proxies_of_proxies3 - FROM hafbe_app.current_account_proxies prox1 - - LEFT JOIN ( - SELECT account_id, proxy_id - FROM hafbe_app.current_account_proxies - WHERE proxy = true - ) prox2 ON prox2.proxy_id = prox1.account_id - - LEFT JOIN ( - SELECT account_id, proxy_id - FROM hafbe_app.current_account_proxies - WHERE proxy = true - ) prox3 ON prox3.proxy_id = prox2.account_id - - LEFT JOIN ( - SELECT account_id, proxy_id - FROM hafbe_app.current_account_proxies - WHERE proxy = true - ) prox4 ON prox4.proxy_id = prox3.account_id - - LEFT JOIN ( - SELECT account_id, proxy_id - FROM hafbe_app.current_account_proxies - WHERE proxy = true - ) prox5 ON prox5.proxy_id = prox4.account_id - - WHERE prox1.proxy = TRUE - ) proxies - - CROSS JOIN LATERAL ( - VALUES (voters_proxies), (proxies_of_voters_proxies), (proxies_of_proxies1), (proxies_of_proxies2), (proxies_of_proxies3) - ) AS unpivot(account_id) - - JOIN LATERAL ( - SELECT vests, account_id - FROM hafbe_app.account_vests - WHERE account_id = unpivot.account_id - ) proxied ON proxied.account_id = unpivot.account_id - - WHERE unpivot.account_id IS NOT NULL - GROUP BY proxies.voter_id - ; - - DROP VIEW IF EXISTS hafbe_views.voters_stats_view; - CREATE VIEW hafbe_views.voters_stats_view AS - SELECT - cwv.witness_id, cwv.voter_id, cwv.timestamp, - COALESCE(account.vests, 0)::NUMERIC AS account_vests, - COALESCE(rpv.proxied_vests, 0) AS proxied_vests - FROM hafbe_app.current_witness_votes cwv - - LEFT JOIN ( - SELECT voter_id, proxied_vests - FROM hafbe_views.recursively_proxied_vests_view - ) rpv ON rpv.voter_id = cwv.voter_id + prox1.proxy_id AS voter_id, + prox1.account_id AS voters_proxies, + prox2.account_id AS proxies_of_voters_proxies, + prox3.account_id AS proxies_of_proxies1, + prox4.account_id AS proxies_of_proxies2, + prox5.account_id AS proxies_of_proxies3 + FROM hafbe_app.current_account_proxies prox1 LEFT JOIN ( - SELECT account_id, proxy + SELECT account_id, proxy_id FROM hafbe_app.current_account_proxies - ) acc_as_proxied ON acc_as_proxied.account_id = cwv.voter_id - - LEFT JOIN ( - SELECT vests, account_id - FROM hafbe_app.account_vests - ) account ON account.account_id = cwv.voter_id AND COALESCE(acc_as_proxied.proxy, FALSE) IS FALSE - - WHERE cwv.approve IS TRUE; - - ------ - - DROP VIEW IF EXISTS hafbe_views.voters_stats_change_view; - CREATE VIEW hafbe_views.voters_stats_change_view AS - SELECT - witness_id, voter_id, approve, timestamp, - ( - SUM(CASE WHEN acc_as_proxy.proxy IS TRUE THEN proxied.vests ELSE -1 * proxied.vests END) - + - CASE WHEN acc_as_proxied.proxy IS FALSE THEN account.vests ELSE -1 * account.vests END - ) AS votes - FROM hafbe_app.witness_votes_history - - LEFT JOIN ( - SELECT account_id, proxy_id, proxy - FROM hafbe_app.account_proxies_history - ) acc_as_proxy ON acc_as_proxy.proxy_id = voter_id + WHERE proxy = true + ) prox2 ON prox2.proxy_id = prox1.account_id LEFT JOIN ( - SELECT vests, account_id - FROM hafbe_app.account_vests - ) proxied ON proxied.account_id = acc_as_proxy.account_id + SELECT account_id, proxy_id + FROM hafbe_app.current_account_proxies + WHERE proxy = true + ) prox3 ON prox3.proxy_id = prox2.account_id LEFT JOIN ( - SELECT account_id, proxy - FROM hafbe_app.account_proxies_history - ) acc_as_proxied ON acc_as_proxied.account_id = voter_id + SELECT account_id, proxy_id + FROM hafbe_app.current_account_proxies + WHERE proxy = true + ) prox4 ON prox4.proxy_id = prox3.account_id LEFT JOIN ( - SELECT vests, account_id - FROM hafbe_app.account_vests - ) account ON account.account_id = acc_as_proxied.account_id - - GROUP BY witness_id, voter_id, approve, timestamp, acc_as_proxied.proxy, account.vests; -END -$$ -; \ No newline at end of file + SELECT account_id, proxy_id + FROM hafbe_app.current_account_proxies + WHERE proxy = true + ) prox5 ON prox5.proxy_id = prox4.account_id + + WHERE prox1.proxy = TRUE +) proxies + +CROSS JOIN LATERAL ( + VALUES (voters_proxies), (proxies_of_voters_proxies), (proxies_of_proxies1), (proxies_of_proxies2), (proxies_of_proxies3) +) AS unpivot(account_id) + +JOIN LATERAL ( + SELECT vests, account_id + FROM hafbe_app.account_vests + WHERE account_id = unpivot.account_id +) proxied ON proxied.account_id = unpivot.account_id + +WHERE unpivot.account_id IS NOT NULL +GROUP BY proxies.voter_id +; + +DROP VIEW IF EXISTS hafbe_views.voters_stats_view; +CREATE VIEW hafbe_views.voters_stats_view AS +SELECT + cwv.witness_id, cwv.voter_id, cwv.timestamp, + COALESCE(account.vests, 0)::NUMERIC AS account_vests, + COALESCE(rpv.proxied_vests, 0) AS proxied_vests +FROM hafbe_app.current_witness_votes cwv + +LEFT JOIN ( + SELECT voter_id, proxied_vests + FROM hafbe_views.recursively_proxied_vests_view +) rpv ON rpv.voter_id = cwv.voter_id + +LEFT JOIN ( + SELECT account_id, proxy + FROM hafbe_app.current_account_proxies +) acc_as_proxied ON acc_as_proxied.account_id = cwv.voter_id + +LEFT JOIN ( + SELECT vests, account_id + FROM hafbe_app.account_vests +) account ON account.account_id = cwv.voter_id AND COALESCE(acc_as_proxied.proxy, FALSE) IS FALSE + +WHERE cwv.approve IS TRUE; + +------ + +DROP VIEW IF EXISTS hafbe_views.voters_stats_change_view; +CREATE VIEW hafbe_views.voters_stats_change_view AS +SELECT + witness_id, voter_id, approve, timestamp, + ( + SUM(CASE WHEN acc_as_proxy.proxy IS TRUE THEN proxied.vests ELSE -1 * proxied.vests END) + + + CASE WHEN acc_as_proxied.proxy IS FALSE THEN account.vests ELSE -1 * account.vests END + ) AS votes +FROM hafbe_app.witness_votes_history + +LEFT JOIN ( + SELECT account_id, proxy_id, proxy + FROM hafbe_app.account_proxies_history +) acc_as_proxy ON acc_as_proxy.proxy_id = voter_id + +LEFT JOIN ( + SELECT vests, account_id + FROM hafbe_app.account_vests +) proxied ON proxied.account_id = acc_as_proxy.account_id + +LEFT JOIN ( + SELECT account_id, proxy + FROM hafbe_app.account_proxies_history +) acc_as_proxied ON acc_as_proxied.account_id = voter_id + +LEFT JOIN ( + SELECT vests, account_id + FROM hafbe_app.account_vests +) account ON account.account_id = acc_as_proxied.account_id + +GROUP BY witness_id, voter_id, approve, timestamp, acc_as_proxied.proxy, account.vests; \ No newline at end of file diff --git a/db/hafbe_app.sql b/db/hafbe_app.sql index 7f6938f..d5684ac 100644 --- a/db/hafbe_app.sql +++ b/db/hafbe_app.sql @@ -14,11 +14,10 @@ BEGIN continue_processing BOOLEAN, last_processed_block INT, started_processing_at TIMESTAMP, - last_reported_at TIMESTAMP, - report_time BOOLEAN + last_reported_at TIMESTAMP ); - INSERT INTO hafbe_app.app_status (continue_processing, last_processed_block, started_processing_at, last_reported_at, report_time) - VALUES (True, 0, NULL, to_timestamp(0), TRUE); + INSERT INTO hafbe_app.app_status (continue_processing, last_processed_block, started_processing_at, finished_processing_at) + VALUES (True, 0, NULL, to_timestamp(0)); CREATE TABLE IF NOT EXISTS hafbe_app.hardfork_operations ( operation_id INT NOT NULL, @@ -47,8 +46,6 @@ BEGIN timestamp TIMESTAMP NOT NULL ) INHERITS (hive.hafbe_app); - CREATE INDEX IF NOT EXISTS witness_votes_history_witness_id_timestamp ON hafbe_app.witness_votes_history USING btree (witness_id, timestamp); - CREATE TABLE IF NOT EXISTS hafbe_app.current_witness_votes ( witness_id INT NOT NULL, voter_id INT NOT NULL, @@ -57,8 +54,6 @@ BEGIN CONSTRAINT pk_current_witness_votes PRIMARY KEY (witness_id, voter_id) ) INHERITS (hive.hafbe_app); - - CREATE INDEX IF NOT EXISTS current_witness_votes_witness_id_approve ON hafbe_app.current_witness_votes USING btree (witness_id, approve); CREATE TABLE IF NOT EXISTS hafbe_app.current_witnesses ( witness_id INT NOT NULL, @@ -79,12 +74,6 @@ BEGIN proxy BOOLEAN NOT NULL, timestamp TIMESTAMP NOT NULL ) INHERITS (hive.hafbe_app); - - CREATE INDEX IF NOT EXISTS account_proxies_history_timestamp ON hafbe_app.account_proxies_history USING btree (timestamp); - CREATE INDEX IF NOT EXISTS account_proxies_history_timestamp_account_id ON hafbe_app.account_proxies_history USING btree (timestamp, account_id); - CREATE INDEX IF NOT EXISTS account_proxies_history_timestamp_proxy_id ON hafbe_app.account_proxies_history USING btree (timestamp, proxy_id); - CREATE INDEX IF NOT EXISTS account_proxies_history_timestamp_proxy_id_proxy ON hafbe_app.account_proxies_history USING btree (timestamp, proxy_id, proxy); - CREATE INDEX IF NOT EXISTS account_proxies_history_account_id_proxy_id ON hafbe_app.account_proxies_history USING btree (account_id, proxy_id); CREATE TABLE IF NOT EXISTS hafbe_app.current_account_proxies ( account_id INT NOT NULL, @@ -93,10 +82,6 @@ BEGIN CONSTRAINT pk_current_account_proxies PRIMARY KEY (account_id) ) INHERITS (hive.hafbe_app); - - CREATE INDEX IF NOT EXISTS current_account_proxies_proxy_id_proxy ON hafbe_app.current_account_proxies USING btree (proxy_id, proxy); - CREATE INDEX IF NOT EXISTS current_account_proxies_account_id_proxy ON hafbe_app.current_account_proxies USING btree (account_id, proxy); - CREATE INDEX IF NOT EXISTS current_account_proxies_account_id_proxy_id ON hafbe_app.current_account_proxies USING btree (account_id, proxy_id); CREATE TABLE IF NOT EXISTS hafbe_app.hived_account_cache ( account TEXT NOT NULL, @@ -107,7 +92,7 @@ BEGIN CREATE TABLE IF NOT EXISTS hafbe_app.account_operation_cache ( account_id INT NOT NULL, - op_type_id INT NOT NULL, + op_type_id SMALLINT NOT NULL, CONSTRAINT pk_account_operation_cache PRIMARY KEY (account_id, op_type_id) ) INHERITS (hive.hafbe_app); @@ -130,8 +115,6 @@ BEGIN CONSTRAINT pk_account_vests PRIMARY KEY (account_id) ) INHERITS (hive.hafbe_app); - CREATE INDEX IF NOT EXISTS account_vests_vests ON hafbe_app.account_vests USING btree (vests); - --ALTER SCHEMA hafbe_app OWNER TO hafbe_owner; END $$ @@ -312,7 +295,7 @@ BEGIN -- parse witness url 42,11 IF __prop_op.op_type_id = ANY('{42,11}'::INT[]) THEN IF __prop_op.op_type_id = 42 THEN - SELECT hive.extract_set_witness_properties(__prop_op.value->>'props') WHERE prop_name = 'url' INTO __prop_value; + SELECT prop_value FROM hive.extract_set_witness_properties(__prop_op.value->>'props') WHERE prop_name = 'url' INTO __prop_value; ELSE SELECT __prop_op.value->>'url' INTO __prop_value; END IF; @@ -324,14 +307,14 @@ BEGIN -- parse witness feed_data 42,7 ELSIF __prop_op.op_type_id = ANY('{42,7}'::INT[]) THEN IF __prop_op.op_type_id = 42 THEN - SELECT hive.extract_set_witness_properties(__prop_op.value->>'props') WHERE prop_name = 'hbd_exchange_rate' INTO __prop_value; + SELECT prop_value FROM hive.extract_set_witness_properties(__prop_op.value->>'props') WHERE prop_name = 'hbd_exchange_rate' INTO __prop_value; ELSE SELECT __prop_op.value->'exchange_rate' INTO __prop_value; END IF; IF __prop_value IS NOT NULL THEN UPDATE hafbe_app.current_witnesses cw SET - price_feed = ((__prop_value::JSON)->'base'->>'amount')::INT / ((__prop_value::JSON)->'quote'->>'amount')::INT, + price_feed = ((__prop_value::JSON)->'base'->>'amount')::BIGINT / ((__prop_value::JSON)->'quote'->>'amount')::INT, bias = (((__prop_value::JSON)->'quote'->>'amount')::INT - 1000)::INT, feed_age = (NOW() - __prop_op.timestamp)::INTERVAL WHERE witness_id = __prop_op.witness_id; @@ -340,7 +323,7 @@ BEGIN -- parse witness block_size 42,30,14,11 ELSIF __prop_op.op_type_id = ANY('{42,30,14,11}'::INT[]) THEN IF __prop_op.op_type_id = 42 THEN - SELECT hive.extract_set_witness_properties(__prop_op.value->>'props') WHERE prop_name = 'maximum_block_size' INTO __prop_value; + SELECT prop_value FROM hive.extract_set_witness_properties(__prop_op.value->>'props') WHERE prop_name = 'maximum_block_size' INTO __prop_value; ELSE SELECT __prop_op.value->>'maximum_block_size' INTO __prop_value; END IF; @@ -352,13 +335,13 @@ BEGIN -- parse witness signing_key 42,11 ELSIF __prop_op.op_type_id = ANY('{42,11}'::INT[]) THEN IF __prop_op.op_type_id = 42 THEN - SELECT hive.extract_set_witness_properties(__prop_op.value->>'props') WHERE prop_name = 'new_signing_key' INTO __prop_value; + SELECT prop_value FROM hive.extract_set_witness_properties(__prop_op.value->>'props') WHERE prop_name = 'new_signing_key' INTO __prop_value; ELSE SELECT __prop_op.value->>'block_signing_key' INTO __prop_value; END IF; IF __prop_op.op_type_id = 42 AND __prop_value IS NULL THEN - SELECT hive.extract_set_witness_properties(__prop_op.value->>'props') WHERE prop_name = 'key' INTO __prop_value; + SELECT prop_value FROM hive.extract_set_witness_properties(__prop_op.value->>'props') WHERE prop_name = 'key' INTO __prop_value; END IF; IF __prop_value IS NOT NULL THEN @@ -435,8 +418,7 @@ BEGIN --RAISE NOTICE 'Block range: <%, %> processed successfully.', b, _last_block; - IF (SELECT report_time FROM hafbe_app.app_status) IS TRUE AND - (NOW() - (SELECT last_reported_at FROM hafbe_app.app_status))::INTERVAL >= '5 second'::INTERVAL THEN + IF (NOW() - (SELECT last_reported_at FROM hafbe_app.app_status))::INTERVAL >= '5 second'::INTERVAL THEN RAISE NOTICE 'Last processed block %', _last_block; RAISE NOTICE 'Block processing running for % minutes', diff --git a/db/indexes.sql b/db/indexes.sql new file mode 100644 index 0000000..d3f9901 --- /dev/null +++ b/db/indexes.sql @@ -0,0 +1,43 @@ +-- TODO: review if all indexes necessary + +CREATE INDEX IF NOT EXISTS witness_votes_history_witness_id_timestamp ON hafbe_app.witness_votes_history USING btree (witness_id, timestamp); + +CREATE INDEX IF NOT EXISTS current_witness_votes_witness_id_approve ON hafbe_app.current_witness_votes USING btree (witness_id, approve); + +CREATE INDEX IF NOT EXISTS account_proxies_history_timestamp ON hafbe_app.account_proxies_history USING btree (timestamp); +CREATE INDEX IF NOT EXISTS account_proxies_history_timestamp_account_id ON hafbe_app.account_proxies_history USING btree (timestamp, account_id); +CREATE INDEX IF NOT EXISTS account_proxies_history_timestamp_proxy_id ON hafbe_app.account_proxies_history USING btree (timestamp, proxy_id); +CREATE INDEX IF NOT EXISTS account_proxies_history_timestamp_proxy_id_proxy ON hafbe_app.account_proxies_history USING btree (timestamp, proxy_id, proxy); +CREATE INDEX IF NOT EXISTS account_proxies_history_account_id_proxy_id ON hafbe_app.account_proxies_history USING btree (account_id, proxy_id); + +CREATE INDEX IF NOT EXISTS current_account_proxies_proxy_id_proxy ON hafbe_app.current_account_proxies USING btree (proxy_id, proxy); +CREATE INDEX IF NOT EXISTS current_account_proxies_account_id_proxy ON hafbe_app.current_account_proxies USING btree (account_id, proxy); +CREATE INDEX IF NOT EXISTS current_account_proxies_account_id_proxy_id ON hafbe_app.current_account_proxies USING btree (account_id, proxy_id); + +CREATE INDEX IF NOT EXISTS account_vests_vests ON hafbe_app.account_vests USING btree (vests); + +-- hive table indexes + +CREATE UNIQUE INDEX IF NOT EXISTS uq_hive_blocks_reversible_hash ON hive.blocks_reversible USING btree (hash, fork_id) +CREATE UNIQUE INDEX IF NOT EXISTS uq_hive_blocks_hash ON hive.blocks USING btree (hash) + +CREATE INDEX IF NOT EXISTS hive_operations_reversible_timestamp_id ON hive.operations_reversible USING btree (timestamp, id, fork_id) +CREATE INDEX IF NOT EXISTS hive_operations_timestamp_id ON hive.operations USING btree (timestamp, id) + +CREATE INDEX IF NOT EXISTS hive_operations_reversible_block_num_op_type_id ON hive.operations_reversible USING btree (block_num, op_type_id, fork_id) +CREATE INDEX IF NOT EXISTS hive_operations_block_num_op_type_id ON hive.operations USING btree (block_num, op_type_id) + +CREATE INDEX IF NOT EXISTS hive_operations_reversible_timestamp ON hive.operations_reversible USING btree (timestamp, fork_id) +CREATE INDEX IF NOT EXISTS hive_operations_timestamp ON hive.operations USING btree (timestamp) + +CREATE UNIQUE INDEX IF NOT EXISTS hive_account_operations_reversible_uq2 ON hive.account_operations_reversible USING btree (account_id, op_type_id, operation_id, fork_id) +CREATE UNIQUE INDEX IF NOT EXISTS hive_account_operations_uq2 ON hive.account_operations USING btree (account_id, op_type_id, operation_id) + +CREATE INDEX IF NOT EXISTS hive_account_operations_reversible_block_num ON hive.account_operations_reversible USING btree (block_num, fork_id) +CREATE INDEX IF NOT EXISTS hive_account_operations_block_num ON hive.account_operations USING btree (block_num) + +CREATE INDEX IF NOT EXISTS hive_account_operations_reversible_block_num_op_type_id ON hive.account_operations_reversible USING btree (block_num, op_type_id, fork_id) +CREATE INDEX IF NOT EXISTS hive_account_operations_block_num_op_type_id ON hive.account_operations USING btree (block_num, op_type_id) + +CREATE INDEX IF NOT EXISTS hive_account_operations_reversible_operation_id_block_num ON hive.account_operations_reversible USING btree (operation_id, block_num, fork_id) +CREATE INDEX IF NOT EXISTS hive_account_operations_operation_id_block_num ON hive.account_operations USING btree (operation_id, block_num) \ No newline at end of file diff --git a/run.sh b/run.sh index 20cb00c..b59b86a 100755 --- a/run.sh +++ b/run.sh @@ -18,34 +18,28 @@ process_blocks() { psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "CALL hafbe_app.main('$hive_app_name', $n_blocks);" } +stop_processing() { + psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "SELECT hafbe_app.stopProcessing();" +} + +continue_processing() { + psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "SELECT hafbe_app.allowProcessing();" +} + create_api() { postgrest_dir=$PWD/api + psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -f $postgrest_dir/views.sql + psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -f $postgrest_dir/types.sql + psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -f $postgrest_dir/exceptions.sql psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -f $postgrest_dir/backend.sql psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -f $postgrest_dir/endpoints.sql - psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -f $postgrest_dir/exceptions.sql - psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -f $postgrest_dir/views.sql psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -f $postgrest_dir/roles.sql - psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "CALL hafbe_views.create_views();" } create_indexes() { - # creating indexes CONCURRENTLY inside sql function is not allowed, they must be created from script echo "Creating indexes, this might take a while." - psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "CREATE UNIQUE INDEX CONCURRENTLY IF NOT EXISTS uq_hive_blocks_reversible_hash ON hive.blocks_reversible USING btree (hash, fork_id)" - psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "CREATE UNIQUE INDEX CONCURRENTLY IF NOT EXISTS uq_hive_blocks_hash ON hive.blocks USING btree (hash)" - - psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "CREATE INDEX CONCURRENTLY IF NOT EXISTS hive_operations_reversible_timestamp_id ON hive.operations_reversible USING btree (timestamp, id, fork_id)" - psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "CREATE INDEX CONCURRENTLY IF NOT EXISTS hive_operations_timestamp_id ON hive.operations USING btree (timestamp, id)" - - psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "CREATE UNIQUE INDEX CONCURRENTLY IF NOT EXISTS hive_account_operations_reversible_uq2 ON hive.account_operations_reversible USING btree (account_id, op_type_id, operation_id, fork_id)" - psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "CREATE UNIQUE INDEX CONCURRENTLY IF NOT EXISTS hive_account_operations_uq2 ON hive.account_operations USING btree (account_id, op_type_id, operation_id)" - - psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "CREATE INDEX CONCURRENTLY IF NOT EXISTS hive_account_operations_reversible_block_num ON hive.account_operations_reversible USING btree (block_num, fork_id)" - psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "CREATE INDEX CONCURRENTLY IF NOT EXISTS hive_account_operations_block_num ON hive.account_operations USING btree (block_num)" - - psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "CREATE INDEX CONCURRENTLY IF NOT EXISTS hive_account_operations_reversible_operation_id_block_num ON hive.account_operations_reversible USING btree (operation_id, block_num, fork_id)" - psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "CREATE INDEX CONCURRENTLY IF NOT EXISTS hive_account_operations_operation_id_block_num ON hive.account_operations USING btree (operation_id, block_num)" + psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -f db/indexes.sql } start_webserver() { @@ -121,13 +115,14 @@ elif [ "$1" = "create-db" ]; then create_db $2 elif [ "$1" = "re-start" ]; then create_api - create_indexes echo 'SUCCESS: Users and API recreated' start_webserver $2 elif [ "$1" = "create-indexes" ]; then create_indexes +elif [ "$1" = "stop-processing" ]; then + stop_processing elif [ "$1" = "continue-processing" ]; then - create_indexes + continue_processing elif [ "$1" = "install-postgrest" ]; then install_postgrest elif [ "$1" = "install-plpython" ]; then -- GitLab From 0c3469c476c1135ed245febe73feb8a7aab36fcd Mon Sep 17 00:00:00 2001 From: kristupas Date: Fri, 23 Sep 2022 22:51:29 +0000 Subject: [PATCH 49/89] Moved config to env vars, updated index setup, fixed types bug #22 --- .gitignore | 1 - api/types.sql | 6 +-- db/hafbe_app.sql | 10 ++--- db/indexes.sql | 103 ++++++++++++++++++++++++++++------------------- postgrest.conf | 4 -- run.sh | 26 +++++++----- 6 files changed, 84 insertions(+), 66 deletions(-) delete mode 100644 postgrest.conf diff --git a/.gitignore b/.gitignore index 5e95531..27a225b 100644 --- a/.gitignore +++ b/.gitignore @@ -1,2 +1 @@ -postgrest.conf tests/performance/result \ No newline at end of file diff --git a/api/types.sql b/api/types.sql index 4b36446..c7f09b4 100644 --- a/api/types.sql +++ b/api/types.sql @@ -33,7 +33,7 @@ CREATE TYPE hafbe_types.witnesses_by_name AS ( witness TEXT, url TEXT, price_feed FLOAT, - bias INT, + bias NUMERIC, feed_age INTERVAL, block_size INT, signing_key TEXT, @@ -56,7 +56,7 @@ CREATE TYPE hafbe_types.witnesses_by_prop AS ( witness_id INT, url TEXT, price_feed FLOAT, - bias INT, + bias NUMERIC, feed_age INTERVAL, block_size INT, signing_key TEXT, @@ -71,7 +71,7 @@ CREATE TYPE hafbe_types.witnesses AS ( voters_num INT, voters_num_daily_change INT, price_feed FLOAT, - bias INT, + bias NUMERIC, feed_age INTERVAL, block_size INT, signing_key TEXT, diff --git a/db/hafbe_app.sql b/db/hafbe_app.sql index d5684ac..fae405d 100644 --- a/db/hafbe_app.sql +++ b/db/hafbe_app.sql @@ -16,8 +16,8 @@ BEGIN started_processing_at TIMESTAMP, last_reported_at TIMESTAMP ); - INSERT INTO hafbe_app.app_status (continue_processing, last_processed_block, started_processing_at, finished_processing_at) - VALUES (True, 0, NULL, to_timestamp(0)); + INSERT INTO hafbe_app.app_status (continue_processing, last_processed_block, started_processing_at, last_reported_at) + VALUES (TRUE, 0, NULL, to_timestamp(0)); CREATE TABLE IF NOT EXISTS hafbe_app.hardfork_operations ( operation_id INT NOT NULL, @@ -59,7 +59,7 @@ BEGIN witness_id INT NOT NULL, url TEXT, price_feed FLOAT, - bias INT, + bias NUMERIC, feed_age INTERVAL, block_size INT, signing_key TEXT, @@ -314,8 +314,8 @@ BEGIN IF __prop_value IS NOT NULL THEN UPDATE hafbe_app.current_witnesses cw SET - price_feed = ((__prop_value::JSON)->'base'->>'amount')::BIGINT / ((__prop_value::JSON)->'quote'->>'amount')::INT, - bias = (((__prop_value::JSON)->'quote'->>'amount')::INT - 1000)::INT, + price_feed = ((__prop_value::JSON)->'base'->>'amount')::NUMERIC / ((__prop_value::JSON)->'quote'->>'amount')::NUMERIC, + bias = (((__prop_value::JSON)->'quote'->>'amount')::NUMERIC - 1000)::NUMERIC, feed_age = (NOW() - __prop_op.timestamp)::INTERVAL WHERE witness_id = __prop_op.witness_id; END IF; diff --git a/db/indexes.sql b/db/indexes.sql index d3f9901..a52f25f 100644 --- a/db/indexes.sql +++ b/db/indexes.sql @@ -1,43 +1,62 @@ -- TODO: review if all indexes necessary - -CREATE INDEX IF NOT EXISTS witness_votes_history_witness_id_timestamp ON hafbe_app.witness_votes_history USING btree (witness_id, timestamp); - -CREATE INDEX IF NOT EXISTS current_witness_votes_witness_id_approve ON hafbe_app.current_witness_votes USING btree (witness_id, approve); - -CREATE INDEX IF NOT EXISTS account_proxies_history_timestamp ON hafbe_app.account_proxies_history USING btree (timestamp); -CREATE INDEX IF NOT EXISTS account_proxies_history_timestamp_account_id ON hafbe_app.account_proxies_history USING btree (timestamp, account_id); -CREATE INDEX IF NOT EXISTS account_proxies_history_timestamp_proxy_id ON hafbe_app.account_proxies_history USING btree (timestamp, proxy_id); -CREATE INDEX IF NOT EXISTS account_proxies_history_timestamp_proxy_id_proxy ON hafbe_app.account_proxies_history USING btree (timestamp, proxy_id, proxy); -CREATE INDEX IF NOT EXISTS account_proxies_history_account_id_proxy_id ON hafbe_app.account_proxies_history USING btree (account_id, proxy_id); - -CREATE INDEX IF NOT EXISTS current_account_proxies_proxy_id_proxy ON hafbe_app.current_account_proxies USING btree (proxy_id, proxy); -CREATE INDEX IF NOT EXISTS current_account_proxies_account_id_proxy ON hafbe_app.current_account_proxies USING btree (account_id, proxy); -CREATE INDEX IF NOT EXISTS current_account_proxies_account_id_proxy_id ON hafbe_app.current_account_proxies USING btree (account_id, proxy_id); - -CREATE INDEX IF NOT EXISTS account_vests_vests ON hafbe_app.account_vests USING btree (vests); - --- hive table indexes - -CREATE UNIQUE INDEX IF NOT EXISTS uq_hive_blocks_reversible_hash ON hive.blocks_reversible USING btree (hash, fork_id) -CREATE UNIQUE INDEX IF NOT EXISTS uq_hive_blocks_hash ON hive.blocks USING btree (hash) - -CREATE INDEX IF NOT EXISTS hive_operations_reversible_timestamp_id ON hive.operations_reversible USING btree (timestamp, id, fork_id) -CREATE INDEX IF NOT EXISTS hive_operations_timestamp_id ON hive.operations USING btree (timestamp, id) - -CREATE INDEX IF NOT EXISTS hive_operations_reversible_block_num_op_type_id ON hive.operations_reversible USING btree (block_num, op_type_id, fork_id) -CREATE INDEX IF NOT EXISTS hive_operations_block_num_op_type_id ON hive.operations USING btree (block_num, op_type_id) - -CREATE INDEX IF NOT EXISTS hive_operations_reversible_timestamp ON hive.operations_reversible USING btree (timestamp, fork_id) -CREATE INDEX IF NOT EXISTS hive_operations_timestamp ON hive.operations USING btree (timestamp) - -CREATE UNIQUE INDEX IF NOT EXISTS hive_account_operations_reversible_uq2 ON hive.account_operations_reversible USING btree (account_id, op_type_id, operation_id, fork_id) -CREATE UNIQUE INDEX IF NOT EXISTS hive_account_operations_uq2 ON hive.account_operations USING btree (account_id, op_type_id, operation_id) - -CREATE INDEX IF NOT EXISTS hive_account_operations_reversible_block_num ON hive.account_operations_reversible USING btree (block_num, fork_id) -CREATE INDEX IF NOT EXISTS hive_account_operations_block_num ON hive.account_operations USING btree (block_num) - -CREATE INDEX IF NOT EXISTS hive_account_operations_reversible_block_num_op_type_id ON hive.account_operations_reversible USING btree (block_num, op_type_id, fork_id) -CREATE INDEX IF NOT EXISTS hive_account_operations_block_num_op_type_id ON hive.account_operations USING btree (block_num, op_type_id) - -CREATE INDEX IF NOT EXISTS hive_account_operations_reversible_operation_id_block_num ON hive.account_operations_reversible USING btree (operation_id, block_num, fork_id) -CREATE INDEX IF NOT EXISTS hive_account_operations_operation_id_block_num ON hive.account_operations USING btree (operation_id, block_num) \ No newline at end of file +DROP SCHEMA IF EXISTS hafbe_indexes CASCADE; + +CREATE SCHEMA IF NOT EXISTS hafbe_indexes; + +CREATE FUNCTION hafbe_indexes.create_hafbe_indexes() +RETURNS VOID +LANGUAGE 'plpgsql' +AS +$$ +BEGIN + CREATE INDEX IF NOT EXISTS witness_votes_history_witness_id_timestamp ON hafbe_app.witness_votes_history USING btree (witness_id, timestamp); + + CREATE INDEX IF NOT EXISTS current_witness_votes_witness_id_approve ON hafbe_app.current_witness_votes USING btree (witness_id, approve); + + CREATE INDEX IF NOT EXISTS account_proxies_history_timestamp ON hafbe_app.account_proxies_history USING btree (timestamp); + CREATE INDEX IF NOT EXISTS account_proxies_history_timestamp_account_id ON hafbe_app.account_proxies_history USING btree (timestamp, account_id); + CREATE INDEX IF NOT EXISTS account_proxies_history_timestamp_proxy_id ON hafbe_app.account_proxies_history USING btree (timestamp, proxy_id); + CREATE INDEX IF NOT EXISTS account_proxies_history_timestamp_proxy_id_proxy ON hafbe_app.account_proxies_history USING btree (timestamp, proxy_id, proxy); + CREATE INDEX IF NOT EXISTS account_proxies_history_account_id_proxy_id ON hafbe_app.account_proxies_history USING btree (account_id, proxy_id); + + CREATE INDEX IF NOT EXISTS current_account_proxies_proxy_id_proxy ON hafbe_app.current_account_proxies USING btree (proxy_id, proxy); + CREATE INDEX IF NOT EXISTS current_account_proxies_account_id_proxy ON hafbe_app.current_account_proxies USING btree (account_id, proxy); + CREATE INDEX IF NOT EXISTS current_account_proxies_account_id_proxy_id ON hafbe_app.current_account_proxies USING btree (account_id, proxy_id); + + CREATE INDEX IF NOT EXISTS account_vests_vests ON hafbe_app.account_vests USING btree (vests); +END +$$ +; + +CREATE FUNCTION hafbe_indexes.create_haf_indexes() +RETURNS VOID +LANGUAGE 'plpgsql' +AS +$$ +BEGIN + CREATE UNIQUE INDEX IF NOT EXISTS uq_hive_blocks_reversible_hash ON hive.blocks_reversible USING btree (hash, fork_id); + CREATE UNIQUE INDEX IF NOT EXISTS uq_hive_blocks_hash ON hive.blocks USING btree (hash); + + CREATE INDEX IF NOT EXISTS hive_operations_reversible_timestamp_id ON hive.operations_reversible USING btree (timestamp, id, fork_id); + CREATE INDEX IF NOT EXISTS hive_operations_timestamp_id ON hive.operations USING btree (timestamp, id); + + CREATE INDEX IF NOT EXISTS hive_operations_reversible_block_num_op_type_id ON hive.operations_reversible USING btree (block_num, op_type_id, fork_id); + CREATE INDEX IF NOT EXISTS hive_operations_block_num_op_type_id ON hive.operations USING btree (block_num, op_type_id); + + CREATE INDEX IF NOT EXISTS hive_operations_reversible_timestamp ON hive.operations_reversible USING btree (timestamp, fork_id); + CREATE INDEX IF NOT EXISTS hive_operations_timestamp ON hive.operations USING btree (timestamp); + + CREATE UNIQUE INDEX IF NOT EXISTS hive_account_operations_reversible_account_id_op_type_id_operation_id ON hive.account_operations_reversible USING btree (account_id, op_type_id, operation_id, fork_id); + CREATE UNIQUE INDEX IF NOT EXISTS hive_account_operations_account_id_op_type_id_operation_id ON hive.account_operations USING btree (account_id, op_type_id, operation_id); + + CREATE INDEX IF NOT EXISTS hive_account_operations_reversible_block_num ON hive.account_operations_reversible USING btree (block_num, fork_id); + CREATE INDEX IF NOT EXISTS hive_account_operations_block_num ON hive.account_operations USING btree (block_num); + + CREATE INDEX IF NOT EXISTS hive_account_operations_reversible_block_num_op_type_id ON hive.account_operations_reversible USING btree (block_num, op_type_id, fork_id); + CREATE INDEX IF NOT EXISTS hive_account_operations_block_num_op_type_id ON hive.account_operations USING btree (block_num, op_type_id); + + CREATE INDEX IF NOT EXISTS hive_account_operations_reversible_operation_id_block_num ON hive.account_operations_reversible USING btree (operation_id, block_num, fork_id); + CREATE INDEX IF NOT EXISTS hive_account_operations_operation_id_block_num ON hive.account_operations USING btree (operation_id, block_num); +END +$$ +; \ No newline at end of file diff --git a/postgrest.conf b/postgrest.conf deleted file mode 100644 index e8c1c7d..0000000 --- a/postgrest.conf +++ /dev/null @@ -1,4 +0,0 @@ -db-uri = "postgres://haf_admin@/haf_block_log" -db-schema = "hafbe_endpoints" -db-anon-role = "hafbe_user" -server-port = "3000" \ No newline at end of file diff --git a/run.sh b/run.sh index b59b86a..6c1f293 100755 --- a/run.sh +++ b/run.sh @@ -19,11 +19,11 @@ process_blocks() { } stop_processing() { - psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "SELECT hafbe_app.stopProcessing();" + psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "SELECT hafbe_app.stopProcessing();" } continue_processing() { - psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "SELECT hafbe_app.allowProcessing();" + psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "SELECT hafbe_app.allowProcessing();" } create_api() { @@ -34,24 +34,28 @@ create_api() { psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -f $postgrest_dir/backend.sql psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -f $postgrest_dir/endpoints.sql psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -f $postgrest_dir/roles.sql -} -create_indexes() { + psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -f db/indexes.sql + echo "Creating indexes, this might take a while." + psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "SELECT hafbe_indexes.create_haf_indexes()" +} - psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -f db/indexes.sql +create_indexes() { + psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "SELECT hafbe_indexes.create_hafbe_indexes()" } start_webserver() { - default_port=3000 + export PGRST_DB_URI="postgres://haf_admin@/haf_block_log" + export PGRST_DB_SCHEMA="hafbe_endpoints" + export PGRST_DB_ANON_ROLE="hafbe_user" + + export PGRST_SERVER_PORT=3000 if [[ $1 == ?+([0-9]) ]]; then - port=$1 - else - port=$default_port + export PGRST_SERVER_PORT=$1 fi - sed -i "/server-port = /s/.*/server-port = \"$port\"/" $CONFIG_PATH - postgrest postgrest.conf + postgrest } install_postgrest() { -- GitLab From 24aed73fd7baff4c33d5248f5e55d62887fb1ed7 Mon Sep 17 00:00:00 2001 From: kristupas Date: Mon, 26 Sep 2022 06:59:30 +0000 Subject: [PATCH 50/89] Added missing ORDER BY clauses #22 --- api/backend.sql | 236 ++++++++++++++++++++++++++++-------------------- 1 file changed, 140 insertions(+), 96 deletions(-) diff --git a/api/backend.sql b/api/backend.sql index 201ff9f..1b6fb86 100644 --- a/api/backend.sql +++ b/api/backend.sql @@ -419,115 +419,159 @@ BEGIN IF _order_by = 'witness' THEN - RETURN QUERY SELECT - witness, url, - COALESCE(all_votes.votes, 0)::NUMERIC, - COALESCE(todays_votes.votes_daily_change, 0)::BIGINT, - COALESCE(all_votes.voters_num, 0)::INT, - COALESCE(todays_votes.voters_num_daily_change, 0)::INT, - price_feed, bias, feed_age, block_size, signing_key, version - FROM hafbe_backend.get_set_of_witnesses_by_name(_limit, _offset, _order_is) ls - LEFT JOIN LATERAL ( + RETURN QUERY EXECUTE format( + $query$ + SELECT - vsv.witness_id, - SUM(vsv.account_vests + vsv.proxied_vests) AS votes, - COUNT(1) AS voters_num - FROM hafbe_views.voters_stats_view vsv - WHERE vsv.witness_id = ls.witness_id - GROUP BY vsv.witness_id - ) all_votes ON all_votes.witness_id = ls.witness_id - LEFT JOIN LATERAL ( - SELECT - vscv.witness_id, - SUM(CASE WHEN vscv.approve IS TRUE THEN vscv.votes ELSE -1 * vscv.votes END) AS votes_daily_change, - SUM(CASE WHEN vscv.approve IS TRUE THEN 1 ELSE -1 END) AS voters_num_daily_change - FROM hafbe_views.voters_stats_change_view vscv - WHERE timestamp >= __today AND vscv.witness_id = ls.witness_id - GROUP BY vscv.witness_id - ) todays_votes ON todays_votes.witness_id = ls.witness_id; + witness, url, + COALESCE(all_votes.votes, 0)::NUMERIC, + COALESCE(todays_votes.votes_daily_change, 0)::BIGINT, + COALESCE(all_votes.voters_num, 0)::INT, + COALESCE(todays_votes.voters_num_daily_change, 0)::INT, + price_feed, bias, feed_age, block_size, signing_key, version + FROM hafbe_backend.get_set_of_witnesses_by_name(%L, %L, %L) ls + LEFT JOIN LATERAL ( + SELECT + vsv.witness_id, + SUM(vsv.account_vests + vsv.proxied_vests) AS votes, + COUNT(1) AS voters_num + FROM hafbe_views.voters_stats_view vsv + WHERE vsv.witness_id = ls.witness_id + GROUP BY vsv.witness_id + ) all_votes ON all_votes.witness_id = ls.witness_id + LEFT JOIN LATERAL ( + SELECT + vscv.witness_id, + SUM(CASE WHEN vscv.approve IS TRUE THEN vscv.votes ELSE -1 * vscv.votes END) AS votes_daily_change, + SUM(CASE WHEN vscv.approve IS TRUE THEN 1 ELSE -1 END) AS voters_num_daily_change + FROM hafbe_views.voters_stats_change_view vscv + WHERE timestamp >= %L AND vscv.witness_id = ls.witness_id + GROUP BY vscv.witness_id + ) todays_votes ON todays_votes.witness_id = ls.witness_id + ORDER BY + (CASE WHEN %L = 'desc' THEN %I ELSE NULL END) DESC, + (CASE WHEN %L = 'asc' THEN %I ELSE NULL END) ASC + + $query$, + _limit, _offset, _order_is, __today, + _order_is, _order_by, _order_is, _order_by + ); ELSIF _order_by = ANY('{votes,voters_num}'::TEXT[]) THEN - RETURN QUERY SELECT - hav.name::TEXT, url, - ls.votes, - COALESCE(todays_votes.votes_daily_change, 0)::BIGINT AS votes_daily_change, - ls.voters_num, - COALESCE(todays_votes.voters_num_daily_change, 0)::INT AS voters_num_daily_change, - price_feed, bias, feed_age, block_size, signing_key, version - FROM hafbe_backend.get_set_of_witnesses_by_votes(_limit, _offset, _order_by, _order_is) ls - JOIN hafbe_app.current_witnesses cw ON cw.witness_id = ls.witness_id - LEFT JOIN LATERAL ( + RETURN QUERY EXECUTE format( + $query$ + SELECT - vscv.witness_id, - SUM(CASE WHEN vscv.approve IS TRUE THEN vscv.votes ELSE -1 * vscv.votes END) AS votes_daily_change, - SUM(CASE WHEN vscv.approve IS TRUE THEN 1 ELSE -1 END) AS voters_num_daily_change - FROM hafbe_views.voters_stats_change_view vscv - WHERE timestamp >= __today AND vscv.witness_id = ls.witness_id - GROUP BY vscv.witness_id - ) todays_votes ON todays_votes.witness_id = ls.witness_id - JOIN ( - SELECT name, id - FROM hive.accounts_view - ) hav ON hav.id = ls.witness_id; + hav.name::TEXT, url, + ls.votes, + COALESCE(todays_votes.votes_daily_change, 0)::BIGINT AS votes_daily_change, + ls.voters_num, + COALESCE(todays_votes.voters_num_daily_change, 0)::INT AS voters_num_daily_change, + price_feed, bias, feed_age, block_size, signing_key, version + FROM hafbe_backend.get_set_of_witnesses_by_votes(%L, %L, %L, %L) ls + JOIN hafbe_app.current_witnesses cw ON cw.witness_id = ls.witness_id + LEFT JOIN LATERAL ( + SELECT + vscv.witness_id, + SUM(CASE WHEN vscv.approve IS TRUE THEN vscv.votes ELSE -1 * vscv.votes END) AS votes_daily_change, + SUM(CASE WHEN vscv.approve IS TRUE THEN 1 ELSE -1 END) AS voters_num_daily_change + FROM hafbe_views.voters_stats_change_view vscv + WHERE timestamp >= %L AND vscv.witness_id = ls.witness_id + GROUP BY vscv.witness_id + ) todays_votes ON todays_votes.witness_id = ls.witness_id + JOIN ( + SELECT name, id + FROM hive.accounts_view + ) hav ON hav.id = ls.witness_id + ORDER BY + (CASE WHEN %L = 'desc' THEN %I ELSE NULL END) DESC, + (CASE WHEN %L = 'asc' THEN %I ELSE NULL END) ASC + + $query$, + _limit, _offset, _order_by, _order_is, __today, + _order_is, _order_by, _order_is, _order_by + ); ELSIF _order_by = ANY('{votes_daily_change,voters_num_daily_change}') THEN - RETURN QUERY SELECT - hav.name::TEXT, url, - all_votes.votes::NUMERIC, - ls.votes_daily_change, - all_votes.voters_num::INT, - ls.voters_num_daily_change, - price_feed, bias, feed_age, block_size, signing_key, version - FROM hafbe_backend.get_set_of_witnesses_by_votes_change(_limit, _offset, _order_by, _order_is, __today) ls - JOIN hafbe_app.current_witnesses cw ON cw.witness_id = ls.witness_id - JOIN LATERAL ( + RETURN QUERY EXECUTE format( + $query$ + SELECT - vsv.witness_id, - SUM(vsv.account_vests + vsv.proxied_vests) AS votes, - COUNT(1) AS voters_num - FROM hafbe_views.voters_stats_view vsv - WHERE vsv.witness_id = ls.witness_id - GROUP BY vsv.witness_id - ) all_votes ON all_votes.witness_id = ls.witness_id - JOIN ( - SELECT name, id - FROM hive.accounts_view - ) hav ON hav.id = ls.witness_id; + hav.name::TEXT, url, + all_votes.votes::NUMERIC, + ls.votes_daily_change, + all_votes.voters_num::INT, + ls.voters_num_daily_change, + price_feed, bias, feed_age, block_size, signing_key, version + FROM hafbe_backend.get_set_of_witnesses_by_votes_change(%L, %L, %L, %L, %L) ls + JOIN hafbe_app.current_witnesses cw ON cw.witness_id = ls.witness_id + JOIN LATERAL ( + SELECT + vsv.witness_id, + SUM(vsv.account_vests + vsv.proxied_vests) AS votes, + COUNT(1) AS voters_num + FROM hafbe_views.voters_stats_view vsv + WHERE vsv.witness_id = ls.witness_id + GROUP BY vsv.witness_id + ) all_votes ON all_votes.witness_id = ls.witness_id + JOIN ( + SELECT name, id + FROM hive.accounts_view + ) hav ON hav.id = ls.witness_id + ORDER BY + (CASE WHEN %L = 'desc' THEN %I ELSE NULL END) DESC, + (CASE WHEN %L = 'asc' THEN %I ELSE NULL END) ASC + + $query$, + _limit, _offset, _order_by, _order_is, __today, + _order_is, _order_by, _order_is, _order_by + ); ELSE - RETURN QUERY SELECT - hav.name::TEXT, url, - COALESCE(all_votes.votes, 0)::NUMERIC, - COALESCE(todays_votes.votes_daily_change, 0)::BIGINT, - COALESCE(all_votes.voters_num, 0)::INT, - COALESCE(todays_votes.voters_num_daily_change, 0)::INT, - price_feed, bias, feed_age, block_size, signing_key, version - FROM hafbe_backend.get_set_of_witnesses_by_prop(_limit, _offset, _order_by, _order_is) ls - LEFT JOIN LATERAL ( + RETURN QUERY EXECUTE format( + $query$ + SELECT - vsv.witness_id, - SUM(vsv.account_vests + vsv.proxied_vests) AS votes, - COUNT(1) AS voters_num - FROM hafbe_views.voters_stats_view vsv - WHERE vsv.witness_id = ls.witness_id - GROUP BY vsv.witness_id - ) all_votes ON all_votes.witness_id = ls.witness_id - LEFT JOIN LATERAL ( - SELECT - vscv.witness_id, - SUM(CASE WHEN vscv.approve IS TRUE THEN vscv.votes ELSE -1 * vscv.votes END) AS votes_daily_change, - SUM(CASE WHEN vscv.approve IS TRUE THEN 1 ELSE -1 END) AS voters_num_daily_change - FROM hafbe_views.voters_stats_change_view vscv - WHERE timestamp >= __today AND vscv.witness_id = ls.witness_id - GROUP BY vscv.witness_id - ) todays_votes ON todays_votes.witness_id = ls.witness_id - JOIN ( - SELECT name, id - FROM hive.accounts_view - ) hav ON hav.id = ls.witness_id; + hav.name::TEXT, url, + COALESCE(all_votes.votes, 0)::NUMERIC, + COALESCE(todays_votes.votes_daily_change, 0)::BIGINT, + COALESCE(all_votes.voters_num, 0)::INT, + COALESCE(todays_votes.voters_num_daily_change, 0)::INT, + price_feed, bias, feed_age, block_size, signing_key, version + FROM hafbe_backend.get_set_of_witnesses_by_prop(%L, %L, %L, %L) ls + LEFT JOIN LATERAL ( + SELECT + vsv.witness_id, + SUM(vsv.account_vests + vsv.proxied_vests) AS votes, + COUNT(1) AS voters_num + FROM hafbe_views.voters_stats_view vsv + WHERE vsv.witness_id = ls.witness_id + GROUP BY vsv.witness_id + ) all_votes ON all_votes.witness_id = ls.witness_id + LEFT JOIN LATERAL ( + SELECT + vscv.witness_id, + SUM(CASE WHEN vscv.approve IS TRUE THEN vscv.votes ELSE -1 * vscv.votes END) AS votes_daily_change, + SUM(CASE WHEN vscv.approve IS TRUE THEN 1 ELSE -1 END) AS voters_num_daily_change + FROM hafbe_views.voters_stats_change_view vscv + WHERE timestamp >= %L AND vscv.witness_id = ls.witness_id + GROUP BY vscv.witness_id + ) todays_votes ON todays_votes.witness_id = ls.witness_id + JOIN ( + SELECT name, id + FROM hive.accounts_view + ) hav ON hav.id = ls.witness_id + ORDER BY + (CASE WHEN %L = 'desc' THEN %I ELSE NULL END) DESC, + (CASE WHEN %L = 'asc' THEN %I ELSE NULL END) ASC + + $query$, + _limit, _offset, _order_by, _order_is, __today, + _order_is, _order_by, _order_is, _order_by + ); END IF; END -- GitLab From 03e40232ede0c6e02b7df63f5d8075765c54327a Mon Sep 17 00:00:00 2001 From: kristupas Date: Thu, 29 Sep 2022 23:49:56 +0000 Subject: [PATCH 51/89] Optimized views, updated setup #22 --- api/endpoints.sql | 2 +- api/views.sql | 122 +++++++++++++++++++++++++++------------------- db/hafbe_app.sql | 22 ++++++--- run.sh | 8 +-- 4 files changed, 93 insertions(+), 61 deletions(-) diff --git a/api/endpoints.sql b/api/endpoints.sql index 48e96c6..9293176 100644 --- a/api/endpoints.sql +++ b/api/endpoints.sql @@ -257,7 +257,7 @@ BEGIN _offset = 0; END IF; - IF _order_by NOT SIMILAR TO '(account|vests|account_vests|proxied_vests|timestamp)' THEN + IF _order_by NOT SIMILAR TO '(vests|account_vests|proxied_vests|timestamp)' THEN RETURN hafbe_exceptions.raise_no_such_column_exception(_order_by); END IF; IF _order_by IS NULL THEN diff --git a/api/views.sql b/api/views.sql index 5385ffa..a7a375b 100644 --- a/api/views.sql +++ b/api/views.sql @@ -2,63 +2,84 @@ DROP SCHEMA IF EXISTS hafbe_views CASCADE; CREATE SCHEMA hafbe_views; -DROP VIEW IF EXISTS hafbe_views.recursively_proxied_vests_view; -CREATE VIEW hafbe_views.recursively_proxied_vests_view AS +DROP VIEW IF EXISTS hafbe_views.recursively_proxied_accounts_view CASCADE; +CREATE VIEW hafbe_views.recursively_proxied_accounts_view AS SELECT - proxies.voter_id, - SUM(proxied.vests) AS proxied_vests -FROM ( - SELECT - prox1.proxy_id AS voter_id, - prox1.account_id AS voters_proxies, - prox2.account_id AS proxies_of_voters_proxies, - prox3.account_id AS proxies_of_proxies1, - prox4.account_id AS proxies_of_proxies2, - prox5.account_id AS proxies_of_proxies3 - FROM hafbe_app.current_account_proxies prox1 - - LEFT JOIN ( - SELECT account_id, proxy_id - FROM hafbe_app.current_account_proxies - WHERE proxy = true - ) prox2 ON prox2.proxy_id = prox1.account_id - - LEFT JOIN ( - SELECT account_id, proxy_id - FROM hafbe_app.current_account_proxies - WHERE proxy = true - ) prox3 ON prox3.proxy_id = prox2.account_id - - LEFT JOIN ( - SELECT account_id, proxy_id - FROM hafbe_app.current_account_proxies - WHERE proxy = true - ) prox4 ON prox4.proxy_id = prox3.account_id - - LEFT JOIN ( - SELECT account_id, proxy_id - FROM hafbe_app.current_account_proxies - WHERE proxy = true - ) prox5 ON prox5.proxy_id = prox4.account_id - - WHERE prox1.proxy = TRUE -) proxies + prox1.proxy_id AS voter_id, + prox1.account_id AS voters_proxies, + prox2.account_id AS proxies_of_voters_proxies, + prox3.account_id AS proxies_of_proxies1, + prox4.account_id AS proxies_of_proxies2, + prox5.account_id AS proxies_of_proxies3 +FROM hafbe_app.current_account_proxies prox1 + +LEFT JOIN ( + SELECT proxy_id, account_id, proxy + FROM hafbe_app.current_account_proxies + WHERE proxy = TRUE +) prox2 ON prox2.proxy_id = prox1.account_id + +LEFT JOIN ( + SELECT proxy_id, account_id, proxy + FROM hafbe_app.current_account_proxies + WHERE proxy = TRUE +) prox3 ON prox3.proxy_id = prox2.account_id + +LEFT JOIN ( + SELECT proxy_id, account_id, proxy + FROM hafbe_app.current_account_proxies + WHERE proxy = TRUE +) prox4 ON prox4.proxy_id = prox3.account_id + +LEFT JOIN ( + SELECT proxy_id, account_id, proxy + FROM hafbe_app.current_account_proxies + WHERE proxy = TRUE +) prox5 ON prox5.proxy_id = prox4.account_id + +WHERE prox1.proxy = TRUE; + +------ + +DROP VIEW IF EXISTS hafbe_views.recursively_proxied_accounts_unpivoted_view CASCADE; +CREATE VIEW hafbe_views.recursively_proxied_accounts_unpivoted_view AS +SELECT + cwv.witness_id, + cwv.voter_id, + unpivot.account_id +FROM hafbe_app.current_witness_votes cwv + +JOIN LATERAL ( + SELECT * + FROM hafbe_views.recursively_proxied_accounts_view + WHERE voter_id = cwv.voter_id +) proxied_accs ON cwv.voter_id = cwv.voter_id CROSS JOIN LATERAL ( VALUES (voters_proxies), (proxies_of_voters_proxies), (proxies_of_proxies1), (proxies_of_proxies2), (proxies_of_proxies3) ) AS unpivot(account_id) +WHERE unpivot.account_id IS NOT NULL; + +------ + +DROP VIEW IF EXISTS hafbe_views.recursively_proxied_vests_view CASCADE; +CREATE VIEW hafbe_views.recursively_proxied_vests_view AS +SELECT + rpauv.witness_id, + rpauv.voter_id, + SUM(proxied.vests) AS proxied_vests +FROM hafbe_views.recursively_proxied_accounts_unpivoted_view rpauv JOIN LATERAL ( SELECT vests, account_id FROM hafbe_app.account_vests - WHERE account_id = unpivot.account_id -) proxied ON proxied.account_id = unpivot.account_id + WHERE account_id = rpauv.account_id +) proxied ON proxied.account_id = rpauv.account_id +GROUP BY rpauv.witness_id, rpauv.voter_id; -WHERE unpivot.account_id IS NOT NULL -GROUP BY proxies.voter_id -; +------ -DROP VIEW IF EXISTS hafbe_views.voters_stats_view; +DROP VIEW IF EXISTS hafbe_views.voters_stats_view CASCADE; CREATE VIEW hafbe_views.voters_stats_view AS SELECT cwv.witness_id, cwv.voter_id, cwv.timestamp, @@ -66,10 +87,11 @@ SELECT COALESCE(rpv.proxied_vests, 0) AS proxied_vests FROM hafbe_app.current_witness_votes cwv -LEFT JOIN ( - SELECT voter_id, proxied_vests +LEFT JOIN LATERAL ( + SELECT witness_id, voter_id, proxied_vests FROM hafbe_views.recursively_proxied_vests_view -) rpv ON rpv.voter_id = cwv.voter_id + WHERE witness_id = cwv.witness_id AND voter_id = cwv.voter_id +) rpv ON rpv.witness_id = cwv.witness_id AND rpv.voter_id = cwv.voter_id LEFT JOIN ( SELECT account_id, proxy @@ -85,7 +107,7 @@ WHERE cwv.approve IS TRUE; ------ -DROP VIEW IF EXISTS hafbe_views.voters_stats_change_view; +DROP VIEW IF EXISTS hafbe_views.voters_stats_change_view CASCADE; CREATE VIEW hafbe_views.voters_stats_change_view AS SELECT witness_id, voter_id, approve, timestamp, diff --git a/db/hafbe_app.sql b/db/hafbe_app.sql index fae405d..01aa74a 100644 --- a/db/hafbe_app.sql +++ b/db/hafbe_app.sql @@ -464,6 +464,21 @@ END $$ ; +CREATE OR REPLACE PROCEDURE hafbe_app.create_context_if_not_exists(_appContext VARCHAR) +LANGUAGE 'plpgsql' +AS +$$ +BEGIN + IF NOT hive.app_context_exists(_appContext) THEN + RAISE NOTICE 'Attempting to create a HAF application context...'; + PERFORM hive.app_create_context(_appContext); + PERFORM hafbe_app.define_schema(); + COMMIT; + END IF; +END +$$ +; + /** Application entry point, which: - defines its data schema, - creates HAF application context, @@ -477,13 +492,6 @@ DECLARE __last_block INT; __next_block_range hive.blocks_range; BEGIN - IF NOT hive.app_context_exists(_appContext) THEN - RAISE NOTICE 'Attempting to create a HAF application context...'; - PERFORM hive.app_create_context(_appContext); - PERFORM hafbe_app.define_schema(); - COMMIT; - END IF; - PERFORM hafbe_app.allowProcessing(); COMMIT; diff --git a/run.sh b/run.sh index 6c1f293..cad9135 100755 --- a/run.sh +++ b/run.sh @@ -9,7 +9,6 @@ drop_db() { } create_db() { - psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -f db/hafbe_app.sql process_blocks $@ } @@ -28,6 +27,11 @@ continue_processing() { create_api() { postgrest_dir=$PWD/api + + psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -f db/hafbe_app.sql + psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -f db/indexes.sql + psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "CALL hafbe_app.create_context_if_not_exists('$hive_app_name');" + psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -f $postgrest_dir/views.sql psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -f $postgrest_dir/types.sql psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -f $postgrest_dir/exceptions.sql @@ -35,8 +39,6 @@ create_api() { psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -f $postgrest_dir/endpoints.sql psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -f $postgrest_dir/roles.sql - psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -f db/indexes.sql - echo "Creating indexes, this might take a while." psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "SELECT hafbe_indexes.create_haf_indexes()" } -- GitLab From fc3fca847f1ba3bc4a1dbb258beda7c356e341c1 Mon Sep 17 00:00:00 2001 From: kristupas Date: Fri, 30 Sep 2022 05:31:10 +0000 Subject: [PATCH 52/89] Simplified witness prop processing #22 --- api/backend.sql | 4 +- api/endpoints.sql | 2 +- api/exceptions.sql | 2 +- api/roles.sql | 14 +-- api/types.sql | 2 +- api/views.sql | 2 +- db/hafbe_app.sql | 249 ++++++++++++++++----------------------------- db/indexes.sql | 2 +- run.sh | 62 +++++++++-- 9 files changed, 150 insertions(+), 189 deletions(-) diff --git a/api/backend.sql b/api/backend.sql index 1b6fb86..81a2365 100644 --- a/api/backend.sql +++ b/api/backend.sql @@ -1,8 +1,6 @@ DROP SCHEMA IF EXISTS hafbe_backend CASCADE; -CREATE SCHEMA IF NOT EXISTS hafbe_backend; - -CREATE EXTENSION IF NOT EXISTS plpython3u SCHEMA pg_catalog; +CREATE SCHEMA IF NOT EXISTS hafbe_backend AUTHORIZATION hafbe_owner; /* general diff --git a/api/endpoints.sql b/api/endpoints.sql index 9293176..1e6cd2e 100644 --- a/api/endpoints.sql +++ b/api/endpoints.sql @@ -1,6 +1,6 @@ DROP SCHEMA IF EXISTS hafbe_endpoints CASCADE; -CREATE SCHEMA IF NOT EXISTS hafbe_endpoints; +CREATE SCHEMA IF NOT EXISTS hafbe_endpoints AUTHORIZATION hafbe_owner; /* determines the input type as one of 'account_name', 'block_num', 'transaction_hash', 'block_hash' diff --git a/api/exceptions.sql b/api/exceptions.sql index 5eb789b..c4c1d49 100644 --- a/api/exceptions.sql +++ b/api/exceptions.sql @@ -1,6 +1,6 @@ DROP SCHEMA IF EXISTS hafbe_exceptions CASCADE; -CREATE SCHEMA IF NOT EXISTS hafbe_exceptions; +CREATE SCHEMA IF NOT EXISTS hafbe_exceptions AUTHORIZATION hafbe_owner; CREATE FUNCTION hafbe_exceptions.raise_exception(_status INT, _error_id INT, _error TEXT, _message TEXT, _data TEXT = NULL) RETURNS JSON diff --git a/api/roles.sql b/api/roles.sql index b68ec02..ba63556 100755 --- a/api/roles.sql +++ b/api/roles.sql @@ -1,12 +1,3 @@ --- recreate hafbe schemas owner -DROP ROLE IF EXISTS hafbe_owner; -CREATE ROLE hafbe_owner LOGIN INHERIT IN ROLE hive_applications_group; - -ALTER SCHEMA hafbe_backend OWNER TO hafbe_owner; -ALTER SCHEMA hafbe_endpoints OWNER TO hafbe_owner; -ALTER SCHEMA hafbe_exceptions OWNER TO hafbe_owner; -ALTER SCHEMA hafbe_views OWNER TO hafbe_owner; - -- drop priviliges of schemas user DO $$ BEGIN @@ -52,4 +43,7 @@ GRANT EXECUTE ON ALL FUNCTIONS IN SCHEMA hive TO hafbe_user; GRANT USAGE ON SCHEMA hafbe_app TO hafbe_user; GRANT USAGE, SELECT ON ALL SEQUENCES IN SCHEMA hafbe_app TO hafbe_user; GRANT SELECT, INSERT ON ALL TABLES IN SCHEMA hafbe_app TO hafbe_user; -GRANT EXECUTE ON ALL FUNCTIONS IN SCHEMA hafbe_app TO hafbe_user; \ No newline at end of file +GRANT EXECUTE ON ALL FUNCTIONS IN SCHEMA hafbe_app TO hafbe_user; + +-- plpython3u must be trusted language +GRANT USAGE ON LANGUAGE plpython3u TO hafbe_owner; \ No newline at end of file diff --git a/api/types.sql b/api/types.sql index c7f09b4..39f4fdc 100644 --- a/api/types.sql +++ b/api/types.sql @@ -1,6 +1,6 @@ DROP SCHEMA IF EXISTS hafbe_types CASCADE; -CREATE SCHEMA IF NOT EXISTS hafbe_types; +CREATE SCHEMA IF NOT EXISTS hafbe_types AUTHORIZATION hafbe_owner; CREATE TYPE hafbe_types.op_types AS ( op_type_id SMALLINT, diff --git a/api/views.sql b/api/views.sql index a7a375b..fceb91e 100644 --- a/api/views.sql +++ b/api/views.sql @@ -1,6 +1,6 @@ DROP SCHEMA IF EXISTS hafbe_views CASCADE; -CREATE SCHEMA hafbe_views; +CREATE SCHEMA hafbe_views AUTHORIZATION hafbe_owner; DROP VIEW IF EXISTS hafbe_views.recursively_proxied_accounts_view CASCADE; CREATE VIEW hafbe_views.recursively_proxied_accounts_view AS diff --git a/db/hafbe_app.sql b/db/hafbe_app.sql index 01aa74a..8b45956 100644 --- a/db/hafbe_app.sql +++ b/db/hafbe_app.sql @@ -1,4 +1,4 @@ -CREATE SCHEMA IF NOT EXISTS hafbe_app; +CREATE SCHEMA IF NOT EXISTS hafbe_app AUTHORIZATION hafbe_owner; CREATE OR REPLACE FUNCTION hafbe_app.define_schema() RETURNS VOID @@ -14,30 +14,11 @@ BEGIN continue_processing BOOLEAN, last_processed_block INT, started_processing_at TIMESTAMP, - last_reported_at TIMESTAMP + last_reported_at TIMESTAMP, + last_reported_block INT ); - INSERT INTO hafbe_app.app_status (continue_processing, last_processed_block, started_processing_at, last_reported_at) - VALUES (TRUE, 0, NULL, to_timestamp(0)); - - CREATE TABLE IF NOT EXISTS hafbe_app.hardfork_operations ( - operation_id INT NOT NULL, - hardfork_num INT NOT NULL, - - CONSTRAINT pk_hardfork_operations PRIMARY KEY (operation_id, hardfork_num) - ); - - INSERT INTO hafbe_app.hardfork_operations (operation_id, hardfork_num) - SELECT CASE WHEN ( - SELECT ((body::JSON)->'value'->>'hardfork_id')::INT - FROM hive.operations_view - WHERE id = __hardfork_one_op_id - ) != 1 THEN - (SELECT id FROM hive.operations_view WHERE op_type_id = 60 ORDER BY id LIMIT 1) - ELSE - __hardfork_one_op_id - END, - 1 - ; + INSERT INTO hafbe_app.app_status (continue_processing, last_processed_block, started_processing_at, last_reported_at, last_reported_block) + VALUES (TRUE, 0, NULL, to_timestamp(0), 0); CREATE TABLE IF NOT EXISTS hafbe_app.witness_votes_history ( witness_id INT NOT NULL, @@ -70,14 +51,14 @@ BEGIN CREATE TABLE IF NOT EXISTS hafbe_app.account_proxies_history ( account_id INT NOT NULL, - proxy_id INT, + proxy_id INT NOT NULL, proxy BOOLEAN NOT NULL, timestamp TIMESTAMP NOT NULL ) INHERITS (hive.hafbe_app); CREATE TABLE IF NOT EXISTS hafbe_app.current_account_proxies ( account_id INT NOT NULL, - proxy_id INT, + proxy_id INT NOT NULL, proxy BOOLEAN NOT NULL, CONSTRAINT pk_current_account_proxies PRIMARY KEY (account_id) @@ -114,8 +95,6 @@ BEGIN CONSTRAINT pk_account_vests PRIMARY KEY (account_id) ) INHERITS (hive.hafbe_app); - - --ALTER SCHEMA hafbe_app OWNER TO hafbe_owner; END $$ ; @@ -188,7 +167,7 @@ END $$ ; -CREATE OR REPLACE FUNCTION hafbe_app.process_block_range_data_c(_from INT, _to INT, _report_step INT = 1000) +CREATE OR REPLACE FUNCTION hafbe_app.process_block_range_data_c(_from INT, _to INT) RETURNS VOID LANGUAGE 'plpgsql' AS @@ -198,159 +177,97 @@ DECLARE __prop_op RECORD; __proxy_op RECORD; __vote_op RECORD; + __vote_or_proxy_ops RECORD; __balance_change RECORD; - __balance_impacting_ops INT[] = (SELECT array_agg(op_type_id) FROM hafbe_app.balance_impacting_op_ids); + -- TODO: use proper function to get this data + __balance_impacting_ops_ids INT[] = '{56,64,22,9,41,69,83,59,54,50,81,27,29,2,77,78,5,21,57,85,32,39,66,51,52,80,55,74}'::SMALLINT[]; BEGIN - -- vote and proxy op processing loop FOR b IN _from .. _to + LOOP - SELECT INTO __vote_op - hafbe_app.get_account_id((body::JSON)->'value'->>'witness') AS witness_id, - hafbe_app.get_account_id((body::JSON)->'value'->>'account') AS voter_id, - ((body::JSON)->'value'->>'approve')::BOOLEAN AS approve, - timestamp + SELECT INTO __vote_or_proxy_ops + (body::JSON)->'value' AS value, + timestamp, + op_type_id FROM hive.hafbe_app_operations_view - WHERE op_type_id = 12 AND block_num = b + WHERE op_type_id = ANY('{12,13}') AND block_num = b ORDER BY id ASC; + FOR __vote_op IN + SELECT + hafbe_app.get_account_id(__vote_or_proxy_ops.value->>'witness') AS witness_id, + hafbe_app.get_account_id(__vote_or_proxy_ops.value->>'account') AS voter_id, + (__vote_or_proxy_ops.value->>'approve')::BOOLEAN AS approve, + __vote_or_proxy_ops.timestamp AS timestamp + WHERE __vote_or_proxy_ops.op_type_id = 12 + + LOOP + INSERT INTO hafbe_app.current_witness_votes (witness_id, voter_id, approve, timestamp) + SELECT __vote_op.witness_id, __vote_op.voter_id, __vote_op.approve, __vote_op.timestamp + ON CONFLICT ON CONSTRAINT pk_current_witness_votes DO UPDATE SET + approve = EXCLUDED.approve, + timestamp = EXCLUDED.timestamp + ; + END LOOP; + IF __vote_op.witness_id IS NOT NULL THEN -- add new witness per vote op INSERT INTO hafbe_app.current_witnesses (witness_id, url, price_feed, bias, feed_age, block_size, signing_key, version) - VALUES(__vote_op.witness_id, NULL, NULL, NULL, NULL, NULL, NULL, '1.25.0') + SELECT __vote_op.witness_id, NULL, NULL, NULL, NULL, NULL, NULL, '1.25.0' ON CONFLICT ON CONSTRAINT pk_current_witnesses DO NOTHING; + -- insert historical vote op data INSERT INTO hafbe_app.witness_votes_history (witness_id, voter_id, approve, timestamp) - VALUES (__vote_op.witness_id, __vote_op.voter_id, __vote_op.approve, __vote_op.timestamp); - - INSERT INTO hafbe_app.current_witness_votes (witness_id, voter_id, approve, timestamp) - VALUES (__vote_op.witness_id, __vote_op.voter_id, __vote_op.approve, __vote_op.timestamp) - ON CONFLICT ON CONSTRAINT pk_current_witness_votes DO UPDATE SET - witness_id = EXCLUDED.witness_id, - voter_id = EXCLUDED.voter_id, - approve = EXCLUDED.approve, - timestamp = EXCLUDED.timestamp - ; + SELECT __vote_op.witness_id, __vote_op.voter_id, __vote_op.approve, __vote_op.timestamp; END IF; - SELECT INTO __proxy_op - hafbe_app.get_account_id((body::JSON)->'value'->>'account') AS account_id, - hafbe_app.get_account_id((body::JSON)->'value'->>'proxy') AS proxy_id, + FOR __proxy_op IN + SELECT + prox_op.account_id, + prev_prox_op.proxy_id, + prev_prox_op.proxy, timestamp - FROM hive.hafbe_app_operations_view - WHERE op_type_id = 13 AND block_num = b - ORDER BY id ASC; + FROM ( + SELECT + hafbe_app.get_account_id(__vote_or_proxy_ops.value->>'account') AS account_id, + hafbe_app.get_account_id(__vote_or_proxy_ops.value->>'proxy') AS proxy_id, + __vote_or_proxy_ops.timestamp AS timestamp + WHERE __vote_or_proxy_ops.op_type_id = 13 + ) prox_op + JOIN LATERAL ( + SELECT + CASE WHEN prox_op.proxy_id IS NULL THEN aph.proxy_id ELSE prox_op.proxy_id END AS proxy_id, + CASE WHEN prox_op.proxy_id IS NULL THEN FALSE ELSE TRUE END AS proxy + FROM hafbe_app.account_proxies_history aph + WHERE aph.timestamp < prox_op.timestamp AND aph.account_id = prox_op.account_id + ORDER BY aph.timestamp DESC + LIMIT 1 + ) prev_prox_op ON TRUE - IF __proxy_op.account_id IS NOT NULL THEN + LOOP INSERT INTO hafbe_app.account_proxies_history (account_id, proxy_id, proxy, timestamp) - SELECT - __proxy_op.account_id, - CASE WHEN __proxy_op.proxy_id IS NULL THEN ( - SELECT proxy_id - FROM hafbe_app.account_proxies_history aph - WHERE aph.timestamp < __proxy_op.timestamp AND aph.account_id = __proxy_op.account_id AND aph.proxy_id IS NOT NULL - ORDER BY aph.timestamp DESC - LIMIT 1 - ) ELSE __proxy_op.proxy_id END, - CASE WHEN __proxy_op.proxy_id IS NULL THEN FALSE ELSE TRUE END, - __proxy_op.timestamp - ; - - INSERT INTO hafbe_app.current_account_proxies AS cap (account_id, proxy_id, proxy) - VALUES (__proxy_op.account_id, __proxy_op.proxy_id, TRUE) - ON CONFLICT ON CONSTRAINT pk_current_account_proxies DO UPDATE SET - proxy_id = CASE WHEN __proxy_op.proxy_id IS NULL THEN cap.proxy_id ELSE EXCLUDED.proxy_id END, - proxy = CASE WHEN __proxy_op.proxy_id IS NULL THEN FALSE ELSE TRUE END - ; - END IF; + VALUES (__proxy_op.account_id, __proxy_op.proxy_id, __proxy_op.proxy, __proxy_op.timestamp); + + IF __proxy_op.account_id IS NOT NULL THEN + INSERT INTO hafbe_app.current_account_proxies AS cap (account_id, proxy_id, proxy) + VALUES (__proxy_op.account_id, __proxy_op.proxy_id, __proxy_op.proxy) + ON CONFLICT ON CONSTRAINT pk_current_account_proxies DO UPDATE SET + proxy_id = EXCLUDED.proxy_id, + proxy = EXCLUDED.proxy + ; + END IF; + END LOOP; + END LOOP; -- add new witnesses per block range INSERT INTO hafbe_app.current_witnesses (witness_id, url, price_feed, bias, feed_age, block_size, signing_key, version) SELECT DISTINCT ON (account_id) account_id, NULL, NULL, NULL, NULL, NULL, NULL, '1.25.0' - FROM hive.account_operations_view + FROM hive.hafbe_app_account_operations_view WHERE op_type_id = ANY('{42,11,7}') AND block_num BETWEEN _from AND _to ON CONFLICT ON CONSTRAINT pk_current_witnesses DO NOTHING; - -- processes witness properties per block range - FOR __prop_op IN - SELECT - witness_id, - (hov.body::JSON)->'value' AS value, - hov.op_type_id, - hov.timestamp - FROM hafbe_app.current_witnesses cw - JOIN ( - SELECT account_id, operation_id, block_num - FROM hive.hafbe_app_account_operations_view - WHERE op_type_id = ANY('{42,30,14,11,7}'::INT[]) AND block_num BETWEEN _from AND _to - ORDER BY operation_id ASC - ) haov ON haov.account_id = cw.witness_id - JOIN ( - SELECT body, op_type_id, timestamp, id, block_num - FROM hive.hafbe_app_operations_view - ) hov ON hov.id = haov.operation_id AND hov.block_num = haov.block_num - - LOOP - -- parse witness url 42,11 - IF __prop_op.op_type_id = ANY('{42,11}'::INT[]) THEN - IF __prop_op.op_type_id = 42 THEN - SELECT prop_value FROM hive.extract_set_witness_properties(__prop_op.value->>'props') WHERE prop_name = 'url' INTO __prop_value; - ELSE - SELECT __prop_op.value->>'url' INTO __prop_value; - END IF; - - IF __prop_value IS NOT NULL THEN - UPDATE hafbe_app.current_witnesses cw SET url = __prop_value WHERE witness_id = __prop_op.witness_id; - END IF; - - -- parse witness feed_data 42,7 - ELSIF __prop_op.op_type_id = ANY('{42,7}'::INT[]) THEN - IF __prop_op.op_type_id = 42 THEN - SELECT prop_value FROM hive.extract_set_witness_properties(__prop_op.value->>'props') WHERE prop_name = 'hbd_exchange_rate' INTO __prop_value; - ELSE - SELECT __prop_op.value->'exchange_rate' INTO __prop_value; - END IF; - - IF __prop_value IS NOT NULL THEN - UPDATE hafbe_app.current_witnesses cw SET - price_feed = ((__prop_value::JSON)->'base'->>'amount')::NUMERIC / ((__prop_value::JSON)->'quote'->>'amount')::NUMERIC, - bias = (((__prop_value::JSON)->'quote'->>'amount')::NUMERIC - 1000)::NUMERIC, - feed_age = (NOW() - __prop_op.timestamp)::INTERVAL - WHERE witness_id = __prop_op.witness_id; - END IF; - - -- parse witness block_size 42,30,14,11 - ELSIF __prop_op.op_type_id = ANY('{42,30,14,11}'::INT[]) THEN - IF __prop_op.op_type_id = 42 THEN - SELECT prop_value FROM hive.extract_set_witness_properties(__prop_op.value->>'props') WHERE prop_name = 'maximum_block_size' INTO __prop_value; - ELSE - SELECT __prop_op.value->>'maximum_block_size' INTO __prop_value; - END IF; - - IF __prop_value IS NOT NULL THEN - UPDATE hafbe_app.current_witnesses cw SET block_size = __prop_value::INT WHERE witness_id = __prop_op.witness_id; - END IF; - - -- parse witness signing_key 42,11 - ELSIF __prop_op.op_type_id = ANY('{42,11}'::INT[]) THEN - IF __prop_op.op_type_id = 42 THEN - SELECT prop_value FROM hive.extract_set_witness_properties(__prop_op.value->>'props') WHERE prop_name = 'new_signing_key' INTO __prop_value; - ELSE - SELECT __prop_op.value->>'block_signing_key' INTO __prop_value; - END IF; - - IF __prop_op.op_type_id = 42 AND __prop_value IS NULL THEN - SELECT prop_value FROM hive.extract_set_witness_properties(__prop_op.value->>'props') WHERE prop_name = 'key' INTO __prop_value; - END IF; - - IF __prop_value IS NOT NULL THEN - UPDATE hafbe_app.current_witnesses cw SET signing_key = __prop_value WHERE witness_id = __prop_op.witness_id; - END IF; - - END IF; - END LOOP; - INSERT INTO hafbe_app.account_operation_cache (account_id, op_type_id) SELECT account_id, op_type_id FROM hive.hafbe_app_account_operations_view @@ -364,16 +281,11 @@ BEGIN JOIN LATERAL ( SELECT account_name, amount - FROM hive.get_impacted_balances( - hov.body, - CASE WHEN hov.id > ( - SELECT operation_id FROM hafbe_app.hardfork_operations WHERE hardfork_num = 1 - ) THEN TRUE ELSE FALSE END - ) + FROM hive.get_impacted_balances(hov.body, hov.block_num > 905693) WHERE asset_symbol_nai = 37 ) bio ON TRUE - WHERE hov.op_type_id = ANY(__balance_impacting_ops) AND hov.block_num BETWEEN _from AND _to + WHERE hov.op_type_id = ANY(__balance_impacting_ops_ids) AND hov.block_num BETWEEN _from AND _to ORDER BY hov.block_num, hov.id LOOP @@ -385,6 +297,12 @@ BEGIN ON CONFLICT ON CONSTRAINT pk_account_vests DO UPDATE SET vests = hafbe_app.account_vests.vests + EXCLUDED.vests; END LOOP; + + INSERT INTO hafbe_app.account_operation_cache (account_id, op_type_id) + SELECT account_id, op_type_id + FROM hive.hafbe_app_account_operations_view + WHERE block_num BETWEEN _from AND _to + ON CONFLICT ON CONSTRAINT pk_account_operation_cache DO NOTHING; END $$ SET from_collapse_limit = 16 @@ -421,12 +339,14 @@ BEGIN IF (NOW() - (SELECT last_reported_at FROM hafbe_app.app_status))::INTERVAL >= '5 second'::INTERVAL THEN RAISE NOTICE 'Last processed block %', _last_block; - RAISE NOTICE 'Block processing running for % minutes', - ROUND((EXTRACT(epoch FROM ( + RAISE NOTICE 'Processed % blocks in 5 seconds', (SELECT _last_block - last_reported_block FROM hafbe_app.app_status); + RAISE NOTICE 'Block processing running for % minutes + ', ROUND((EXTRACT(epoch FROM ( SELECT NOW() - started_processing_at FROM hafbe_app.app_status )) / 60)::NUMERIC, 2); UPDATE hafbe_app.app_status SET last_reported_at = NOW(); + UPDATE hafbe_app.app_status SET last_reported_block = _last_block; END IF; EXIT WHEN NOT hafbe_app.continueProcessing(); @@ -513,6 +433,7 @@ BEGIN WHILE hafbe_app.continueProcessing() AND (_maxBlockLimit = 0 OR __last_block < _maxBlockLimit) LOOP __next_block_range := hive.app_next_block(_appContext); + COMMIT; IF __next_block_range IS NULL THEN RAISE WARNING 'Waiting for next block...'; diff --git a/db/indexes.sql b/db/indexes.sql index a52f25f..013626e 100644 --- a/db/indexes.sql +++ b/db/indexes.sql @@ -1,7 +1,7 @@ -- TODO: review if all indexes necessary DROP SCHEMA IF EXISTS hafbe_indexes CASCADE; -CREATE SCHEMA IF NOT EXISTS hafbe_indexes; +CREATE SCHEMA IF NOT EXISTS hafbe_indexes AUTHORIZATION hafbe_owner; CREATE FUNCTION hafbe_indexes.create_hafbe_indexes() RETURNS VOID diff --git a/run.sh b/run.sh index cad9135..9e6a7d8 100755 --- a/run.sh +++ b/run.sh @@ -25,11 +25,37 @@ continue_processing() { psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "SELECT hafbe_app.allowProcessing();" } +create_role() { + role_name=hafbe_owner + + psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -f - </dev/null; then + sudo useradd -m $role_name + sudo chsh -s /bin/bash $role_name + fi; + + psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "CREATE EXTENSION IF NOT EXISTS plpython3u SCHEMA pg_catalog;" + psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "UPDATE pg_language SET lanpltrusted = true WHERE lanname = 'plpython3u';" +} + create_api() { postgrest_dir=$PWD/api + db_dir=$PWD/db - psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -f db/hafbe_app.sql - psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -f db/indexes.sql + psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -f $db_dir/hafbe_app.sql + psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -f $db_dir/indexes.sql psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "CALL hafbe_app.create_context_if_not_exists('$hive_app_name');" psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -f $postgrest_dir/views.sql @@ -37,18 +63,23 @@ create_api() { psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -f $postgrest_dir/exceptions.sql psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -f $postgrest_dir/backend.sql psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -f $postgrest_dir/endpoints.sql +} + +grant_permissions() { psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -f $postgrest_dir/roles.sql +} +create_haf_indexes() { echo "Creating indexes, this might take a while." psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "SELECT hafbe_indexes.create_haf_indexes()" } -create_indexes() { +create_hafbe_indexes() { psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "SELECT hafbe_indexes.create_hafbe_indexes()" } start_webserver() { - export PGRST_DB_URI="postgres://haf_admin@/haf_block_log" + export PGRST_DB_URI="postgres://hafbe_owner@/haf_block_log" export PGRST_DB_SCHEMA="hafbe_endpoints" export PGRST_DB_ANON_ROLE="hafbe_user" @@ -116,28 +147,45 @@ hive_app_name="hafbe_app" if [ "$1" = "start" ]; then start_webserver $2 elif [ "$1" = "drop-db" ]; then + # run as hafbe_owner drop_db elif [ "$1" = "create-db" ]; then create_db $2 +elif [ "$1" = "create-role" ]; then + # run as admin + create_role elif [ "$1" = "re-start" ]; then + # run as hafbe_owner create_api echo 'SUCCESS: Users and API recreated' start_webserver $2 -elif [ "$1" = "create-indexes" ]; then - create_indexes +elif [ "$1" = "grant-permissions" ]; then + # run as admin + grant_permissions +elif [ "$1" = "create-haf-indexes" ]; then + # run as admin + create_haf_indexes +elif [ "$1" = "create-hafbe-indexes" ]; then + # run as hafbe_owner ? + create_hafbe_indexes elif [ "$1" = "stop-processing" ]; then + # run as hafbe_owner stop_processing elif [ "$1" = "continue-processing" ]; then + # run as hafbe_owner continue_processing elif [ "$1" = "install-postgrest" ]; then + # run as admin install_postgrest elif [ "$1" = "install-plpython" ]; then + # run as admin install_plpython elif [ "$1" = "install-jmeter" ]; then + # run as admin install_jmeter elif [ "$1" = "run-tests" ]; then run_tests $@ else echo "job not found" exit 1 -fi; +fi; \ No newline at end of file -- GitLab From 6e55cf41a6d692c60e3f5bf43e37efc3324e7ad6 Mon Sep 17 00:00:00 2001 From: kristupas Date: Thu, 6 Oct 2022 00:42:15 +0000 Subject: [PATCH 53/89] Added setup scripts, used hive table for unproxy ops instead of hafbe table #22 --- api/roles.sql | 3 +- db/hafbe_app.sql | 163 +++++++++++++++++---------------- run.sh | 166 +++++----------------------------- scripts/setup_db.sh | 88 ++++++++++++++++++ scripts/setup_dependancies.sh | 53 +++++++++++ 5 files changed, 250 insertions(+), 223 deletions(-) create mode 100755 scripts/setup_db.sh create mode 100755 scripts/setup_dependancies.sh diff --git a/api/roles.sql b/api/roles.sql index ba63556..3a1f57e 100755 --- a/api/roles.sql +++ b/api/roles.sql @@ -10,7 +10,8 @@ $$ -- recreate hafbe schemas user DROP ROLE IF EXISTS hafbe_user; -CREATE ROLE hafbe_user LOGIN INHERIT IN ROLE hive_applications_group; +CREATE ROLE hafbe_user NOLOGIN; +GRANT hafbe_user TO hafbe_owner; -- grant new priviliges GRANT USAGE ON SCHEMA hafbe_backend TO hafbe_user; diff --git a/db/hafbe_app.sql b/db/hafbe_app.sql index 8b45956..1003c25 100644 --- a/db/hafbe_app.sql +++ b/db/hafbe_app.sql @@ -51,7 +51,7 @@ BEGIN CREATE TABLE IF NOT EXISTS hafbe_app.account_proxies_history ( account_id INT NOT NULL, - proxy_id INT NOT NULL, + proxy_id INT, proxy BOOLEAN NOT NULL, timestamp TIMESTAMP NOT NULL ) INHERITS (hive.hafbe_app); @@ -79,15 +79,16 @@ BEGIN ) INHERITS (hive.hafbe_app); CREATE TABLE IF NOT EXISTS hafbe_app.balance_impacting_op_ids ( - op_type_id INT NOT NULL, - - CONSTRAINT pk_balance_impacting_op_ids PRIMARY KEY(op_type_id) + op_type_ids_arr SMALLINT[] NOT NULL ); - INSERT INTO hafbe_app.balance_impacting_op_ids (op_type_id) - SELECT hot.id + INSERT INTO hafbe_app.balance_impacting_op_ids (op_type_ids_arr) + SELECT array_agg(hot.id) FROM hive.operation_types hot - WHERE hot.name IN (SELECT * FROM hive.get_balance_impacting_operations()); + JOIN ( + SELECT hive.get_balance_impacting_operations() AS name + ) bio + ON hot.name = bio.name; CREATE TABLE IF NOT EXISTS hafbe_app.account_vests ( account_id INT NOT NULL, @@ -176,90 +177,98 @@ DECLARE __prop_value TEXT; __prop_op RECORD; __proxy_op RECORD; + __first_timestamp TIMESTAMP; __vote_op RECORD; __vote_or_proxy_ops RECORD; __balance_change RECORD; - -- TODO: use proper function to get this data - __balance_impacting_ops_ids INT[] = '{56,64,22,9,41,69,83,59,54,50,81,27,29,2,77,78,5,21,57,85,32,39,66,51,52,80,55,74}'::SMALLINT[]; + __balance_impacting_ops_ids INT[] = (SELECT op_type_ids_arr FROM hafbe_app.balance_impacting_op_ids); BEGIN - FOR b IN _from .. _to - - LOOP - SELECT INTO __vote_or_proxy_ops - (body::JSON)->'value' AS value, - timestamp, - op_type_id - FROM hive.hafbe_app_operations_view - WHERE op_type_id = ANY('{12,13}') AND block_num = b - ORDER BY id ASC; - - FOR __vote_op IN + SELECT INTO __vote_or_proxy_ops + (body::JSON)->'value' AS value, + timestamp, + op_type_id, + id + FROM hive.hafbe_app_operations_view + WHERE op_type_id = ANY('{12,13}') AND block_num BETWEEN _from AND _to; + + FOR __vote_op IN SELECT hafbe_app.get_account_id(__vote_or_proxy_ops.value->>'witness') AS witness_id, hafbe_app.get_account_id(__vote_or_proxy_ops.value->>'account') AS voter_id, (__vote_or_proxy_ops.value->>'approve')::BOOLEAN AS approve, - __vote_or_proxy_ops.timestamp AS timestamp + __vote_or_proxy_ops.timestamp WHERE __vote_or_proxy_ops.op_type_id = 12 + ORDER BY __vote_or_proxy_ops.timestamp ASC - LOOP - INSERT INTO hafbe_app.current_witness_votes (witness_id, voter_id, approve, timestamp) - SELECT __vote_op.witness_id, __vote_op.voter_id, __vote_op.approve, __vote_op.timestamp - ON CONFLICT ON CONSTRAINT pk_current_witness_votes DO UPDATE SET - approve = EXCLUDED.approve, - timestamp = EXCLUDED.timestamp - ; - END LOOP; + LOOP + INSERT INTO hafbe_app.current_witness_votes (witness_id, voter_id, approve, timestamp) + SELECT __vote_op.witness_id, __vote_op.voter_id, __vote_op.approve, __vote_op.timestamp + ON CONFLICT ON CONSTRAINT pk_current_witness_votes DO UPDATE SET + approve = EXCLUDED.approve, + timestamp = EXCLUDED.timestamp + ; + END LOOP; - IF __vote_op.witness_id IS NOT NULL THEN - -- add new witness per vote op - INSERT INTO hafbe_app.current_witnesses (witness_id, url, price_feed, bias, feed_age, block_size, signing_key, version) - SELECT __vote_op.witness_id, NULL, NULL, NULL, NULL, NULL, NULL, '1.25.0' - ON CONFLICT ON CONSTRAINT pk_current_witnesses DO NOTHING; - - -- insert historical vote op data - INSERT INTO hafbe_app.witness_votes_history (witness_id, voter_id, approve, timestamp) - SELECT __vote_op.witness_id, __vote_op.voter_id, __vote_op.approve, __vote_op.timestamp; - END IF; + IF __vote_op.witness_id IS NOT NULL THEN + -- add new witness per vote op + INSERT INTO hafbe_app.current_witnesses (witness_id, url, price_feed, bias, feed_age, block_size, signing_key, version) + SELECT __vote_op.witness_id, NULL, NULL, NULL, NULL, NULL, NULL, '1.25.0' + ON CONFLICT ON CONSTRAINT pk_current_witnesses DO NOTHING; + + -- insert historical vote op data + INSERT INTO hafbe_app.witness_votes_history (witness_id, voter_id, approve, timestamp) + SELECT __vote_op.witness_id, __vote_op.voter_id, __vote_op.approve, __vote_op.timestamp; + END IF; - FOR __proxy_op IN + SELECT INTO __proxy_op + prox_op.account_id, + prox_op.proxy_id, + CASE WHEN prox_op.proxy_id IS NULL THEN FALSE ELSE TRUE END AS proxy, + prox_op.timestamp + FROM ( SELECT - prox_op.account_id, - prev_prox_op.proxy_id, - prev_prox_op.proxy, - timestamp - FROM ( - SELECT - hafbe_app.get_account_id(__vote_or_proxy_ops.value->>'account') AS account_id, - hafbe_app.get_account_id(__vote_or_proxy_ops.value->>'proxy') AS proxy_id, - __vote_or_proxy_ops.timestamp AS timestamp - WHERE __vote_or_proxy_ops.op_type_id = 13 - ) prox_op - JOIN LATERAL ( - SELECT - CASE WHEN prox_op.proxy_id IS NULL THEN aph.proxy_id ELSE prox_op.proxy_id END AS proxy_id, - CASE WHEN prox_op.proxy_id IS NULL THEN FALSE ELSE TRUE END AS proxy - FROM hafbe_app.account_proxies_history aph - WHERE aph.timestamp < prox_op.timestamp AND aph.account_id = prox_op.account_id - ORDER BY aph.timestamp DESC - LIMIT 1 - ) prev_prox_op ON TRUE + hafbe_app.get_account_id(__vote_or_proxy_ops.value->>'account') AS account_id, + hafbe_app.get_account_id(__vote_or_proxy_ops.value->>'proxy') AS proxy_id, + __vote_or_proxy_ops.timestamp, + __vote_or_proxy_ops.id + WHERE __vote_or_proxy_ops.op_type_id = 13 + ) prox_op + ORDER BY prox_op.timestamp ASC; + + IF __proxy_op.account_id IS NOT NULL THEN + INSERT INTO hafbe_app.account_proxies_history (account_id, proxy_id, proxy, timestamp) + VALUES (__proxy_op.account_id, __proxy_op.proxy_id, __proxy_op.proxy, __proxy_op.timestamp); + END IF; - LOOP - INSERT INTO hafbe_app.account_proxies_history (account_id, proxy_id, proxy, timestamp) - VALUES (__proxy_op.account_id, __proxy_op.proxy_id, __proxy_op.proxy, __proxy_op.timestamp); - - IF __proxy_op.account_id IS NOT NULL THEN - INSERT INTO hafbe_app.current_account_proxies AS cap (account_id, proxy_id, proxy) - VALUES (__proxy_op.account_id, __proxy_op.proxy_id, __proxy_op.proxy) - ON CONFLICT ON CONSTRAINT pk_current_account_proxies DO UPDATE SET - proxy_id = EXCLUDED.proxy_id, - proxy = EXCLUDED.proxy - ; - END IF; - END LOOP; - - END LOOP; + UPDATE hafbe_app.account_proxies_history + SET proxy_id = ( + SELECT aph.proxy_id + FROM hafbe_app.account_proxies_history aph + WHERE aph.account_id = __proxy_op.account_id AND aph.proxy_id IS NOT NULL AND aph.timestamp < __proxy_op.timestamp + ORDER BY aph.timestamp DESC + LIMIT 1 + ) + WHERE proxy_id IS NULL; + + SELECT INTO __first_timestamp + __proxy_op.timestamp + ORDER BY __proxy_op.timestamp ASC + LIMIT 1; + + FOR __proxy_op IN + SELECT account_id, proxy_id, proxy, timestamp + FROM hafbe_app.account_proxies_history + WHERE timestamp >= __first_timestamp AND proxy_id IS NOT NULL + LOOP + INSERT INTO hafbe_app.current_account_proxies AS cap (account_id, proxy_id, proxy) + VALUES (__proxy_op.account_id, __proxy_op.proxy_id, __proxy_op.proxy) + ON CONFLICT ON CONSTRAINT pk_current_account_proxies DO UPDATE SET + proxy_id = EXCLUDED.proxy_id, + proxy = EXCLUDED.proxy + ; + END LOOP; + -- add new witnesses per block range INSERT INTO hafbe_app.current_witnesses (witness_id, url, price_feed, bias, feed_age, block_size, signing_key, version) SELECT DISTINCT ON (account_id) @@ -436,7 +445,7 @@ BEGIN COMMIT; IF __next_block_range IS NULL THEN - RAISE WARNING 'Waiting for next block...'; + -- RAISE WARNING 'Waiting for next block...'; ELSE IF _maxBlockLimit != 0 and __next_block_range.first_block > _maxBlockLimit THEN __next_block_range.first_block := _maxBlockLimit; diff --git a/run.sh b/run.sh index 9e6a7d8..5b75bb9 100755 --- a/run.sh +++ b/run.sh @@ -3,79 +3,26 @@ set -e set -o pipefail -drop_db() { - psql -d $DB_NAME -c "SELECT hive.app_remove_context('$hive_app_name');" - psql -d $DB_NAME -c "DROP SCHEMA IF EXISTS hafbe_app CASCADE;" -} - -create_db() { - process_blocks $@ -} - process_blocks() { n_blocks="${1:-null}" - psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "CALL hafbe_app.main('$hive_app_name', $n_blocks);" + sudo -nu $owner_role psql -d $DB_NAME -a -v "ON_ERROR_STOP=on" -c "\timing" -c "CALL hafbe_app.main('hafbe_app', $n_blocks);" } stop_processing() { - psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "SELECT hafbe_app.stopProcessing();" + sudo -nu $owner_role psql -d $DB_NAME -a -v "ON_ERROR_STOP=on" -c "SELECT hafbe_app.stopProcessing();" } continue_processing() { - psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "SELECT hafbe_app.allowProcessing();" -} - -create_role() { - role_name=hafbe_owner - - psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -f - </dev/null; then - sudo useradd -m $role_name - sudo chsh -s /bin/bash $role_name - fi; - - psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "CREATE EXTENSION IF NOT EXISTS plpython3u SCHEMA pg_catalog;" - psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "UPDATE pg_language SET lanpltrusted = true WHERE lanname = 'plpython3u';" + sudo -nu $owner_role psql -d $DB_NAME -a -v "ON_ERROR_STOP=on" -c "SELECT hafbe_app.allowProcessing();" } -create_api() { - postgrest_dir=$PWD/api - db_dir=$PWD/db - - psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -f $db_dir/hafbe_app.sql - psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -f $db_dir/indexes.sql - psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "CALL hafbe_app.create_context_if_not_exists('$hive_app_name');" - - psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -f $postgrest_dir/views.sql - psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -f $postgrest_dir/types.sql - psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -f $postgrest_dir/exceptions.sql - psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -f $postgrest_dir/backend.sql - psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -f $postgrest_dir/endpoints.sql -} - -grant_permissions() { - psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -f $postgrest_dir/roles.sql -} - -create_haf_indexes() { - echo "Creating indexes, this might take a while." - psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "SELECT hafbe_indexes.create_haf_indexes()" +drop_db() { + sudo -nu $admin_role psql -d $DB_NAME -a -v "ON_ERROR_STOP=on" -c "SELECT hive.app_remove_context('hafbe_app');" + sudo -nu $owner_role psql -d $DB_NAME -a -v "ON_ERROR_STOP=on" -c "DROP SCHEMA IF EXISTS hafbe_app CASCADE;" } create_hafbe_indexes() { - psql -a -v "ON_ERROR_STOP=1" -d $DB_NAME -c "\timing" -c "SELECT hafbe_indexes.create_hafbe_indexes()" + sudo -nu $owner_role psql -d $DB_NAME -a -v "ON_ERROR_STOP=on" -c "\timing" -c "SELECT hafbe_indexes.create_hafbe_indexes();" } start_webserver() { @@ -91,100 +38,29 @@ start_webserver() { postgrest } -install_postgrest() { - sudo apt-get update -y - sudo apt-get install wget -y - - postgrest=postgrest-v$postgrest_v-linux-static-x64.tar.xz - wget https://github.com/PostgREST/postgrest/releases/download/v$postgrest_v/$postgrest - - sudo tar xvf $postgrest -C '/usr/local/bin' - rm $postgrest -} - -install_plpython() { - sudo apt-get update -y - sudo apt-get -y install python3 postgresql-plpython3-14 -} - -install_jmeter() { - sudo apt-get update -y - sudo apt-get install openjdk-8-jdk -y - - wget "https://downloads.apache.org//jmeter/binaries/apache-jmeter-${jmeter_v}.zip" - - jmeter_src="apache-jmeter-${jmeter_v}" - sudo unzip "${jmeter_src}.zip" -d '/usr/local/src' - rm "${jmeter_src}.zip" - - jmeter="jmeter-${jmeter_v}" - touch $jmeter - echo '#!/usr/bin/env bash' >> $jmeter - echo '' >> $jmeter - echo "cd '/usr/local/src/apache-jmeter-${jmeter_v}/bin'" >> $jmeter - echo './jmeter $@' >> $jmeter - sudo chmod +x $jmeter - sudo mv $jmeter "/usr/local/bin/${jmeter}" - - sudo chmod 777 /usr/local/src/apache-jmeter-5.4.3/bin/ - sudo chmod 777 /usr/local/src/apache-jmeter-5.4.3/bin/jmeter.log -} - -run_tests() { - server_port=$(sed -rn '/^server-port/p' $CONFIG_PATH | sed "s/server-port//g" | sed "s/[\"\? =]//g") - - bash $PWD/tests/run_performance_tests.sh $server_port $@ -} - -postgrest_v=9.0.0 -jmeter_v=5.4.3 - DB_NAME=haf_block_log -CONFIG_PATH=$PWD/postgrest.conf - -hive_app_name="hafbe_app" +owner_role=hafbe_owner +admin_role=haf_admin if [ "$1" = "start" ]; then start_webserver $2 -elif [ "$1" = "drop-db" ]; then - # run as hafbe_owner - drop_db -elif [ "$1" = "create-db" ]; then - create_db $2 -elif [ "$1" = "create-role" ]; then - # run as admin - create_role -elif [ "$1" = "re-start" ]; then - # run as hafbe_owner - create_api - echo 'SUCCESS: Users and API recreated' - start_webserver $2 -elif [ "$1" = "grant-permissions" ]; then - # run as admin - grant_permissions -elif [ "$1" = "create-haf-indexes" ]; then - # run as admin - create_haf_indexes -elif [ "$1" = "create-hafbe-indexes" ]; then - # run as hafbe_owner ? - create_hafbe_indexes +elif [ "$1" = "setup-dependancies" ]; then + ./scripts/setup_dependancies.sh +elif [ "$1" = "setup-db" ]; then + ./scripts/setup_db.sh +elif [ "$1" = "process-blocks" ]; then + process_blocks $2 elif [ "$1" = "stop-processing" ]; then - # run as hafbe_owner stop_processing elif [ "$1" = "continue-processing" ]; then - # run as hafbe_owner continue_processing -elif [ "$1" = "install-postgrest" ]; then - # run as admin - install_postgrest -elif [ "$1" = "install-plpython" ]; then - # run as admin - install_plpython -elif [ "$1" = "install-jmeter" ]; then - # run as admin - install_jmeter + process_blocks $2 +elif [ "$1" = "drop-db" ]; then + drop_db +elif [ "$1" = "create-hafbe-indexes" ]; then + create_hafbe_indexes elif [ "$1" = "run-tests" ]; then - run_tests $@ + bash $PWD/tests/run_performance_tests.sh $@ else echo "job not found" exit 1 diff --git a/scripts/setup_db.sh b/scripts/setup_db.sh new file mode 100755 index 0000000..27aef8a --- /dev/null +++ b/scripts/setup_db.sh @@ -0,0 +1,88 @@ +#!/bin/bash + +set -e +set -o pipefail + +setup_owner() { + if ! id $owner_role &>/dev/null; then + sudo useradd -m $owner_role + sudo chsh -s /bin/bash $owner_role + fi; + + sudo -nu $admin_role psql -d $DB_NAME -a -v "ON_ERROR_STOP=on" -f - <> $jmeter + echo '' >> $jmeter + echo "cd '/usr/local/src/apache-jmeter-${jmeter_v}/bin'" >> $jmeter + echo './jmeter $@' >> $jmeter + sudo chmod +x $jmeter + sudo mv $jmeter "/usr/local/bin/${jmeter}" + + sudo chmod 777 /usr/local/src/apache-jmeter-5.4.3/bin/ + sudo chmod 777 /usr/local/src/apache-jmeter-5.4.3/bin/jmeter.log +} + +postgrest_v=9.0.0 +jmeter_v=5.4.3 + +if [ "$1" = "install-postgrest" ]; then + install_postgrest +elif [ "$1" = "install-plpython" ]; then + install_plpython +elif [ "$1" = "install-jmeter" ]; then + install_jmeter +else + install_postgrest + install_plpython + install_jmeter +fi; \ No newline at end of file -- GitLab From d55f87e023894fd891354981e4891eb2d3dc5bb1 Mon Sep 17 00:00:00 2001 From: kristupas Date: Sat, 8 Oct 2022 01:30:52 -0400 Subject: [PATCH 54/89] Added virtual 'proxy_cleared_operation' to processing, added shared app code setup #22 --- db/hafbe_app.sql | 130 +++++++++++++++++++++++----------- run.sh | 7 +- scripts/setup_db.sh | 77 ++++++++++++++++++-- scripts/setup_dependancies.sh | 11 +-- 4 files changed, 170 insertions(+), 55 deletions(-) diff --git a/db/hafbe_app.sql b/db/hafbe_app.sql index 1003c25..9a2dceb 100644 --- a/db/hafbe_app.sql +++ b/db/hafbe_app.sql @@ -51,7 +51,7 @@ BEGIN CREATE TABLE IF NOT EXISTS hafbe_app.account_proxies_history ( account_id INT NOT NULL, - proxy_id INT, + proxy_id INT NOT NULL, proxy BOOLEAN NOT NULL, timestamp TIMESTAMP NOT NULL ) INHERITS (hive.hafbe_app); @@ -186,10 +186,9 @@ BEGIN SELECT INTO __vote_or_proxy_ops (body::JSON)->'value' AS value, timestamp, - op_type_id, - id + op_type_id FROM hive.hafbe_app_operations_view - WHERE op_type_id = ANY('{12,13}') AND block_num BETWEEN _from AND _to; + WHERE op_type_id = ANY('{12,91}') AND block_num BETWEEN _from AND _to; FOR __vote_op IN SELECT @@ -220,45 +219,18 @@ BEGIN SELECT __vote_op.witness_id, __vote_op.voter_id, __vote_op.approve, __vote_op.timestamp; END IF; - SELECT INTO __proxy_op - prox_op.account_id, - prox_op.proxy_id, - CASE WHEN prox_op.proxy_id IS NULL THEN FALSE ELSE TRUE END AS proxy, - prox_op.timestamp - FROM ( + FOR __proxy_op IN SELECT hafbe_app.get_account_id(__vote_or_proxy_ops.value->>'account') AS account_id, hafbe_app.get_account_id(__vote_or_proxy_ops.value->>'proxy') AS proxy_id, - __vote_or_proxy_ops.timestamp, - __vote_or_proxy_ops.id - WHERE __vote_or_proxy_ops.op_type_id = 13 - ) prox_op - ORDER BY prox_op.timestamp ASC; - - IF __proxy_op.account_id IS NOT NULL THEN - INSERT INTO hafbe_app.account_proxies_history (account_id, proxy_id, proxy, timestamp) - VALUES (__proxy_op.account_id, __proxy_op.proxy_id, __proxy_op.proxy, __proxy_op.timestamp); - END IF; - - UPDATE hafbe_app.account_proxies_history - SET proxy_id = ( - SELECT aph.proxy_id - FROM hafbe_app.account_proxies_history aph - WHERE aph.account_id = __proxy_op.account_id AND aph.proxy_id IS NOT NULL AND aph.timestamp < __proxy_op.timestamp - ORDER BY aph.timestamp DESC - LIMIT 1 - ) - WHERE proxy_id IS NULL; - - SELECT INTO __first_timestamp - __proxy_op.timestamp - ORDER BY __proxy_op.timestamp ASC - LIMIT 1; - - FOR __proxy_op IN - SELECT account_id, proxy_id, proxy, timestamp - FROM hafbe_app.account_proxies_history - WHERE timestamp >= __first_timestamp AND proxy_id IS NOT NULL + CASE WHEN (__vote_or_proxy_ops.value->>'clear')::BOOLEAN IS TRUE THEN + FALSE + ELSE + TRUE + END AS proxy, + __vote_or_proxy_ops.timestamp + WHERE __vote_or_proxy_ops.op_type_id = 91 + ORDER BY __vote_or_proxy_ops.timestamp ASC LOOP INSERT INTO hafbe_app.current_account_proxies AS cap (account_id, proxy_id, proxy) @@ -268,6 +240,11 @@ BEGIN proxy = EXCLUDED.proxy ; END LOOP; + + IF __proxy_op.account_id IS NOT NULL THEN + INSERT INTO hafbe_app.account_proxies_history (account_id, proxy_id, proxy, timestamp) + VALUES (__proxy_op.account_id, __proxy_op.proxy_id, __proxy_op.proxy, __proxy_op.timestamp); + END IF; -- add new witnesses per block range INSERT INTO hafbe_app.current_witnesses (witness_id, url, price_feed, bias, feed_age, block_size, signing_key, version) @@ -277,6 +254,79 @@ BEGIN WHERE op_type_id = ANY('{42,11,7}') AND block_num BETWEEN _from AND _to ON CONFLICT ON CONSTRAINT pk_current_witnesses DO NOTHING; + -- processes witness properties per block range + FOR __prop_op IN + SELECT + witness_id, + (hov.body::JSON)->'value' AS value, + hov.op_type_id, + hov.timestamp + FROM hafbe_app.current_witnesses cw + JOIN ( + SELECT account_id, operation_id, block_num + FROM hive.hafbe_app_account_operations_view + WHERE op_type_id = ANY('{42,30,14,11,7}'::INT[]) AND block_num BETWEEN _from AND _to + ORDER BY operation_id ASC + ) haov ON haov.account_id = cw.witness_id + JOIN ( + SELECT body, op_type_id, timestamp, id, block_num + FROM hive.hafbe_app_operations_view + ) hov ON hov.id = haov.operation_id AND hov.block_num = haov.block_num + + LOOP + -- parse witness url 42,11 + SELECT __prop_op.value->>'url' INTO __prop_value; + + IF __prop_value IS NULL AND __prop_op.op_type_id = 42 THEN + SELECT prop_value FROM hive.extract_set_witness_properties(__prop_op.value->>'props') WHERE prop_name = 'url' INTO __prop_value; + END IF; + + IF __prop_value IS NOT NULL THEN + UPDATE hafbe_app.current_witnesses cw SET url = __prop_value WHERE witness_id = __prop_op.witness_id; + END IF; + + -- parse witness feed_data 42,7 + SELECT __prop_op.value->'exchange_rate' INTO __prop_value; + + IF __prop_value IS NULL AND __prop_op.op_type_id = 42 THEN + SELECT prop_value FROM hive.extract_set_witness_properties(__prop_op.value->>'props') WHERE prop_name = 'hbd_exchange_rate' INTO __prop_value; + END IF; + + IF __prop_value IS NOT NULL THEN + UPDATE hafbe_app.current_witnesses cw SET + price_feed = ((__prop_value::JSON)->'base'->>'amount')::NUMERIC / ((__prop_value::JSON)->'quote'->>'amount')::NUMERIC, + bias = (((__prop_value::JSON)->'quote'->>'amount')::NUMERIC - 1000)::NUMERIC, + feed_age = (NOW() - __prop_op.timestamp)::INTERVAL + WHERE witness_id = __prop_op.witness_id; + END IF; + + -- parse witness block_size 42,30,14,11 + SELECT __prop_op.value->'props'->>'maximum_block_size' INTO __prop_value; + + IF __prop_value IS NULL AND __prop_op.op_type_id = 42 THEN + SELECT prop_value FROM hive.extract_set_witness_properties(__prop_op.value->>'props') WHERE prop_name = 'maximum_block_size' INTO __prop_value; + END IF; + + IF __prop_value IS NOT NULL THEN + UPDATE hafbe_app.current_witnesses cw SET block_size = __prop_value::INT WHERE witness_id = __prop_op.witness_id; + END IF; + + -- parse witness signing_key 42,11 + SELECT __prop_op.value->>'block_signing_key' INTO __prop_value; + + IF __prop_value IS NULL AND __prop_op.op_type_id = 42 THEN + SELECT prop_value FROM hive.extract_set_witness_properties(__prop_op.value->>'props') WHERE prop_name = 'new_signing_key' INTO __prop_value; + END IF; + + IF __prop_value IS NULL AND __prop_op.op_type_id = 42 THEN + SELECT prop_value FROM hive.extract_set_witness_properties(__prop_op.value->>'props') WHERE prop_name = 'key' INTO __prop_value; + END IF; + + IF __prop_value IS NOT NULL THEN + UPDATE hafbe_app.current_witnesses cw SET signing_key = __prop_value WHERE witness_id = __prop_op.witness_id; + END IF; + END LOOP; + INSERT INTO hafbe_app.account_operation_cache (account_id, op_type_id) SELECT account_id, op_type_id FROM hive.hafbe_app_account_operations_view diff --git a/run.sh b/run.sh index 5b75bb9..a64340c 100755 --- a/run.sh +++ b/run.sh @@ -44,10 +44,9 @@ admin_role=haf_admin if [ "$1" = "start" ]; then start_webserver $2 -elif [ "$1" = "setup-dependancies" ]; then - ./scripts/setup_dependancies.sh -elif [ "$1" = "setup-db" ]; then - ./scripts/setup_db.sh +elif [ "$1" = "setup" ]; then + ./scripts/setup_dependancies.sh all + ./scripts/setup_db.sh all elif [ "$1" = "process-blocks" ]; then process_blocks $2 elif [ "$1" = "stop-processing" ]; then diff --git a/scripts/setup_db.sh b/scripts/setup_db.sh index 27aef8a..f2bc96b 100755 --- a/scripts/setup_db.sh +++ b/scripts/setup_db.sh @@ -36,6 +36,65 @@ END EOF } +find_function() { + schema=$1 + function=$2 + + result=$(sudo -nu $admin_role psql -d $DB_NAME -a -v "ON_ERROR_STOP=on" -f - <&1) + notice="$schema.$function() does not exist" + + if [[ $result = *"$notice"* ]]; then + cd $build_dir + git clone git@gitlab.syncad.com:hive/HAfAH.git + cd $build_dir/HAfAH + git checkout develop + + sudo -nu $admin_role psql -d $DB_NAME -a -v "ON_ERROR_STOP=on" -f "queries/ah_schema_functions.pgsql" + fi + + # btracker + schema="btracker_app" + function="find_matching_accounts" + + result=$(find_function $schema $function 2>&1) + notice="$schema.$function() does not exist" + + if [[ $result = *"$notice"* ]]; then + cd $build_dir + git clone git@gitlab.syncad.com:hive/balance_tracker.git + cd $build_dir/balance_tracker + git checkout master + + sudo -nu $admin_role psql -d $DB_NAME -a -v "ON_ERROR_STOP=on" -c "CREATE SCHEMA IF NOT EXISTS btracker_app;" + sudo -nu $admin_role psql -d $DB_NAME -a -v "ON_ERROR_STOP=on" -f "api/btracker_api.sql" + fi +} + setup_extensions() { sudo -nu $admin_role psql -d $DB_NAME -a -v "ON_ERROR_STOP=on" -c "CREATE EXTENSION IF NOT EXISTS plpython3u SCHEMA pg_catalog;" sudo -nu $admin_role psql -d $DB_NAME -a -v "ON_ERROR_STOP=on" -c "UPDATE pg_language SET lanpltrusted = true WHERE lanname = 'plpython3u';" @@ -70,19 +129,23 @@ owner_role=hafbe_owner postgrest_dir=$PWD/api db_dir=$PWD/db -if [ "$1" = "setup-role" ]; then +if [ "$1" = "all" ]; then setup_owner -elif [ "$1" = "setup-extensions" ]; then + setup_apps setup_extensions -elif [ "$1" = "setup-api" ]; then setup_api -elif [ "$1" = "setup-permissions" ]; then - setup_permissions -elif [ "$1" = "create-haf-indexes" ]; then create_haf_indexes -else +elif [ "$1" = "owner" ]; then setup_owner +elif [ "$1" = "apps" ]; then + setup_apps +elif [ "$1" = "extensions" ]; then setup_extensions +elif [ "$1" = "api" ]; then setup_api +elif [ "$1" = "haf-indexes" ]; then create_haf_indexes +else + echo "job not found" + exit 1 fi; \ No newline at end of file diff --git a/scripts/setup_dependancies.sh b/scripts/setup_dependancies.sh index 624b583..cd3666e 100755 --- a/scripts/setup_dependancies.sh +++ b/scripts/setup_dependancies.sh @@ -40,14 +40,17 @@ install_jmeter() { postgrest_v=9.0.0 jmeter_v=5.4.3 -if [ "$1" = "install-postgrest" ]; then +if [ "$1" = "all" ]; then install_postgrest -elif [ "$1" = "install-plpython" ]; then install_plpython -elif [ "$1" = "install-jmeter" ]; then install_jmeter -else +elif [ "$1" = "postgrest" ]; then install_postgrest +elif [ "$1" = "plpython" ]; then install_plpython +elif [ "$1" = "jmeter" ]; then install_jmeter +else + echo "job not found" + exit 1 fi; \ No newline at end of file -- GitLab From 9738a5e1b8272a29d387b5dded26c5f2c6d779f7 Mon Sep 17 00:00:00 2001 From: kristupas Date: Mon, 10 Oct 2022 15:16:13 -0400 Subject: [PATCH 55/89] Added option to order witness voters by name #22 --- api/backend.sql | 116 ++++++++++++++++++++++++++++++++++++++++------ api/endpoints.sql | 2 +- api/types.sql | 13 ++++++ db/hafbe_app.sql | 7 +-- 4 files changed, 119 insertions(+), 19 deletions(-) diff --git a/api/backend.sql b/api/backend.sql index 81a2365..ca8c0c7 100644 --- a/api/backend.sql +++ b/api/backend.sql @@ -232,38 +232,62 @@ SET from_collapse_limit=16 ; /* -witnesses and voters +witness voters */ -CREATE FUNCTION hafbe_backend.get_set_of_witness_voters(_witness_id INT, _limit INT, _offset INT, _order_by TEXT, _order_is TEXT) -RETURNS SETOF hafbe_types.witness_voters +CREATE FUNCTION hafbe_backend.get_set_of_witness_voters_by_name(_witness_id INT, _limit INT, _offset INT, _order_is TEXT) +RETURNS SETOF hafbe_types.witness_voters_by_name AS $function$ BEGIN RETURN QUERY EXECUTE format( $query$ - SELECT name::TEXT, vsv.vests, vsv.account_vests, vsv.proxied_vests, vsv.timestamp - FROM hive.accounts_view - JOIN ( - SELECT voter_id - FROM hafbe_app.current_witness_votes - WHERE witness_id = %L - ) cwv ON cwv.voter_id = id - JOIN ( + SELECT + voter_id, hav.name::TEXT AS voter + FROM hive.accounts_view hav + JOIN hafbe_app.current_witness_votes cwv ON hav.id = cwv.voter_id + WHERE cwv.witness_id = %L + ORDER BY + (CASE WHEN %L = 'desc' THEN hav.name ELSE NULL END) DESC, + (CASE WHEN %L = 'asc' THEN hav.name ELSE NULL END) ASC + OFFSET %L + LIMIT %L + + $query$, + _witness_id, _order_is, _order_is, _offset, _limit + ); +END +$function$ +LANGUAGE 'plpgsql' STABLE +SET JIT=OFF +SET join_collapse_limit=16 +SET from_collapse_limit=16 +; + +CREATE FUNCTION hafbe_backend.get_set_of_witness_voters_by_vests(_witness_id INT, _limit INT, _offset INT, _order_by TEXT, _order_is TEXT) +RETURNS SETOF hafbe_types.witness_voters_by_vests +AS +$function$ +BEGIN + RETURN QUERY EXECUTE format( + $query$ + + SELECT voter_id, vests, account_vests, proxied_vests, timestamp + FROM ( SELECT voter_id, proxied_vests + account_vests AS vests, account_vests, proxied_vests, timestamp FROM hafbe_views.voters_stats_view WHERE witness_id = %L - ) vsv ON vsv.voter_id = id + ) vests_sum ORDER BY (CASE WHEN %L = 'desc' THEN %I ELSE NULL END) DESC, (CASE WHEN %L = 'asc' THEN %I ELSE NULL END) ASC OFFSET %L - LIMIT %L; + LIMIT %L $query$, - _witness_id, _witness_id, _order_is, _order_by, _order_is, _order_by, _offset, _limit - ) res; + _witness_id, _order_is, _order_by, _order_is, _order_by, _offset, _limit + ); END $function$ LANGUAGE 'plpgsql' STABLE @@ -272,6 +296,68 @@ SET join_collapse_limit=16 SET from_collapse_limit=16 ; +/* +witnesses +*/ + +CREATE FUNCTION hafbe_backend.get_set_of_witness_voters(_witness_id INT, _limit INT, _offset INT, _order_by TEXT, _order_is TEXT) +RETURNS SETOF hafbe_types.witness_voters +AS +$function$ +BEGIN + IF _order_by = 'voter' THEN + + RETURN QUERY EXECUTE format( + $query$ + + SELECT voter, vsv.vests, vsv.account_vests, vsv.proxied_vests, vsv.timestamp + FROM hafbe_backend.get_set_of_witness_voters_by_name(%L, %L, %L, %L) ls + JOIN ( + SELECT voter_id, proxied_vests + account_vests AS vests, account_vests, proxied_vests, timestamp + FROM hafbe_views.voters_stats_view + WHERE witness_id = %L + ) vsv ON vsv.voter_id = ls.voter_id + ORDER BY + (CASE WHEN %L = 'desc' THEN %I ELSE NULL END) DESC, + (CASE WHEN %L = 'asc' THEN %I ELSE NULL END) ASC + ; + + $query$, + _witness_id, _limit, _offset, _order_is, + _witness_id, _order_is, _order_by, _order_is, _order_by + ) res; + + ELSIF _order_by = ANY('{vests,account_vests,proxied_vests,timestamp}'::TEXT[]) THEN + + RETURN QUERY EXECUTE format( + $query$ + + SELECT hav.name::TEXT, ls.vests, ls.account_vests, ls.proxied_vests, ls.timestamp + FROM hafbe_backend.get_set_of_witness_voters_by_vests(%L, %L, %L, %L, %L) ls + JOIN ( + SELECT id, name + FROM hive.accounts_view + ) hav ON hav.id = ls.voter_id + ORDER BY + (CASE WHEN %L = 'desc' THEN %I ELSE NULL END) DESC, + (CASE WHEN %L = 'asc' THEN %I ELSE NULL END) ASC + ; + + $query$, + _witness_id, _limit, _offset, _order_by, _order_is, + _order_is, _order_by, _order_is, _order_by + ) res; + + END IF; +END +$function$ +LANGUAGE 'plpgsql' STABLE +SET JIT=OFF +SET join_collapse_limit=16 +SET from_collapse_limit=16 +; + + CREATE FUNCTION hafbe_backend.get_set_of_witnesses_by_name(_limit INT, _offset INT, _order_is TEXT) RETURNS SETOF hafbe_types.witnesses_by_name AS diff --git a/api/endpoints.sql b/api/endpoints.sql index 1e6cd2e..a51c083 100644 --- a/api/endpoints.sql +++ b/api/endpoints.sql @@ -257,7 +257,7 @@ BEGIN _offset = 0; END IF; - IF _order_by NOT SIMILAR TO '(vests|account_vests|proxied_vests|timestamp)' THEN + IF _order_by NOT SIMILAR TO '(voter|vests|account_vests|proxied_vests|timestamp)' THEN RETURN hafbe_exceptions.raise_no_such_column_exception(_order_by); END IF; IF _order_by IS NULL THEN diff --git a/api/types.sql b/api/types.sql index 39f4fdc..5e2c547 100644 --- a/api/types.sql +++ b/api/types.sql @@ -20,6 +20,19 @@ CREATE TYPE hafbe_types.operations AS ( acc_operation_id BIGINT ); +CREATE TYPE hafbe_types.witness_voters_by_name AS ( + voter_id INT, + voter TEXT +); + +CREATE TYPE hafbe_types.witness_voters_by_vests AS ( + voter_id INT, + vests NUMERIC, + account_vests NUMERIC, + proxied_vests NUMERIC, + timestamp TIMESTAMP +); + CREATE TYPE hafbe_types.witness_voters AS ( account TEXT, vests NUMERIC, diff --git a/db/hafbe_app.sql b/db/hafbe_app.sql index 9a2dceb..9aa620a 100644 --- a/db/hafbe_app.sql +++ b/db/hafbe_app.sql @@ -186,7 +186,8 @@ BEGIN SELECT INTO __vote_or_proxy_ops (body::JSON)->'value' AS value, timestamp, - op_type_id + op_type_id, + id AS operation_id FROM hive.hafbe_app_operations_view WHERE op_type_id = ANY('{12,91}') AND block_num BETWEEN _from AND _to; @@ -197,7 +198,7 @@ BEGIN (__vote_or_proxy_ops.value->>'approve')::BOOLEAN AS approve, __vote_or_proxy_ops.timestamp WHERE __vote_or_proxy_ops.op_type_id = 12 - ORDER BY __vote_or_proxy_ops.timestamp ASC + ORDER BY __vote_or_proxy_ops.operation_id ASC LOOP INSERT INTO hafbe_app.current_witness_votes (witness_id, voter_id, approve, timestamp) @@ -230,7 +231,7 @@ BEGIN END AS proxy, __vote_or_proxy_ops.timestamp WHERE __vote_or_proxy_ops.op_type_id = 91 - ORDER BY __vote_or_proxy_ops.timestamp ASC + ORDER BY __vote_or_proxy_ops.operation_id ASC LOOP INSERT INTO hafbe_app.current_account_proxies AS cap (account_id, proxy_id, proxy) -- GitLab From 62666f132cf260ebaba39b261e7d1bfa6c01b688 Mon Sep 17 00:00:00 2001 From: kristupas Date: Tue, 18 Oct 2022 00:01:06 -0400 Subject: [PATCH 56/89] Added data modifying statements in WITH for block processing #22 --- .gitignore | 3 +- db/hafbe_app.sql | 156 ++++++++++++++++++++++++++--------------------- db/indexes.sql | 1 + 3 files changed, 91 insertions(+), 69 deletions(-) diff --git a/.gitignore b/.gitignore index 27a225b..c4d2d66 100644 --- a/.gitignore +++ b/.gitignore @@ -1 +1,2 @@ -tests/performance/result \ No newline at end of file +tests/performance/result +build/ \ No newline at end of file diff --git a/db/hafbe_app.sql b/db/hafbe_app.sql index 9aa620a..194ec40 100644 --- a/db/hafbe_app.sql +++ b/db/hafbe_app.sql @@ -60,6 +60,7 @@ BEGIN account_id INT NOT NULL, proxy_id INT NOT NULL, proxy BOOLEAN NOT NULL, + operation_id BIGINT NOT NULL, CONSTRAINT pk_current_account_proxies PRIMARY KEY (account_id) ) INHERITS (hive.hafbe_app); @@ -157,16 +158,6 @@ END $$ ; -CREATE OR REPLACE FUNCTION hafbe_app.get_account_id(_account TEXT) -RETURNS INT -LANGUAGE 'plpgsql' -AS -$$ -BEGIN - RETURN id FROM hive.hafbe_app_accounts_view WHERE name = _account; -END -$$ -; CREATE OR REPLACE FUNCTION hafbe_app.process_block_range_data_c(_from INT, _to INT) RETURNS VOID @@ -174,78 +165,107 @@ LANGUAGE 'plpgsql' AS $$ DECLARE - __prop_value TEXT; __prop_op RECORD; - __proxy_op RECORD; - __first_timestamp TIMESTAMP; - __vote_op RECORD; - __vote_or_proxy_ops RECORD; + __prop_value TEXT; __balance_change RECORD; __balance_impacting_ops_ids INT[] = (SELECT op_type_ids_arr FROM hafbe_app.balance_impacting_op_ids); BEGIN - SELECT INTO __vote_or_proxy_ops - (body::JSON)->'value' AS value, - timestamp, - op_type_id, - id AS operation_id - FROM hive.hafbe_app_operations_view - WHERE op_type_id = ANY('{12,91}') AND block_num BETWEEN _from AND _to; - - FOR __vote_op IN + WITH vote_or_proxy_op AS ( SELECT - hafbe_app.get_account_id(__vote_or_proxy_ops.value->>'witness') AS witness_id, - hafbe_app.get_account_id(__vote_or_proxy_ops.value->>'account') AS voter_id, - (__vote_or_proxy_ops.value->>'approve')::BOOLEAN AS approve, - __vote_or_proxy_ops.timestamp - WHERE __vote_or_proxy_ops.op_type_id = 12 - ORDER BY __vote_or_proxy_ops.operation_id ASC - - LOOP + (body::JSON)->'value' AS value, + timestamp, op_type_id, id + FROM hive.hafbe_app_operations_view + WHERE op_type_id = ANY('{12,91}') AND block_num BETWEEN _from AND _to + ), + + insert_votes_history AS ( + INSERT INTO hafbe_app.witness_votes_history (witness_id, voter_id, approve, timestamp) + SELECT + hav_w.witness_id, + hav_v.voter_id, + approve, timestamp + FROM ( + SELECT + value->>'witness' AS witness, + value->>'account' AS voter, + (value->>'approve')::BOOLEAN AS approve, + timestamp, id + FROM vote_or_proxy_op + WHERE op_type_id = 12 + ) vote_op + JOIN LATERAL ( + SELECT id AS witness_id + FROM hive.hafbe_app_accounts_view + WHERE name = vote_op.witness + ) hav_w ON TRUE + JOIN LATERAL ( + SELECT id AS voter_id + FROM hive.hafbe_app_accounts_view + WHERE name = vote_op.voter + ) hav_v ON TRUE + ORDER BY id DESC + RETURNING witness_id, voter_id, approve, timestamp + ), + + insert_current_votes AS ( INSERT INTO hafbe_app.current_witness_votes (witness_id, voter_id, approve, timestamp) - SELECT __vote_op.witness_id, __vote_op.voter_id, __vote_op.approve, __vote_op.timestamp + SELECT DISTINCT ON (witness_id, voter_id) + witness_id, voter_id, approve, timestamp + FROM insert_votes_history ON CONFLICT ON CONSTRAINT pk_current_witness_votes DO UPDATE SET approve = EXCLUDED.approve, timestamp = EXCLUDED.timestamp - ; - END LOOP; + ), - IF __vote_op.witness_id IS NOT NULL THEN - -- add new witness per vote op + insert_witnesses_from_votes AS ( INSERT INTO hafbe_app.current_witnesses (witness_id, url, price_feed, bias, feed_age, block_size, signing_key, version) - SELECT __vote_op.witness_id, NULL, NULL, NULL, NULL, NULL, NULL, '1.25.0' - ON CONFLICT ON CONSTRAINT pk_current_witnesses DO NOTHING; - - -- insert historical vote op data - INSERT INTO hafbe_app.witness_votes_history (witness_id, voter_id, approve, timestamp) - SELECT __vote_op.witness_id, __vote_op.voter_id, __vote_op.approve, __vote_op.timestamp; - END IF; + SELECT witness_id, NULL, NULL, NULL, NULL, NULL, NULL, '1.25.0' + FROM insert_votes_history + ON CONFLICT ON CONSTRAINT pk_current_witnesses DO NOTHING + ), - FOR __proxy_op IN + select_proxy_ops AS ( SELECT - hafbe_app.get_account_id(__vote_or_proxy_ops.value->>'account') AS account_id, - hafbe_app.get_account_id(__vote_or_proxy_ops.value->>'proxy') AS proxy_id, - CASE WHEN (__vote_or_proxy_ops.value->>'clear')::BOOLEAN IS TRUE THEN - FALSE - ELSE - TRUE - END AS proxy, - __vote_or_proxy_ops.timestamp - WHERE __vote_or_proxy_ops.op_type_id = 91 - ORDER BY __vote_or_proxy_ops.operation_id ASC - - LOOP - INSERT INTO hafbe_app.current_account_proxies AS cap (account_id, proxy_id, proxy) - VALUES (__proxy_op.account_id, __proxy_op.proxy_id, __proxy_op.proxy) - ON CONFLICT ON CONSTRAINT pk_current_account_proxies DO UPDATE SET - proxy_id = EXCLUDED.proxy_id, - proxy = EXCLUDED.proxy - ; - END LOOP; - - IF __proxy_op.account_id IS NOT NULL THEN + hav_a.account_id, + hav_p.proxy_id, + proxy, timestamp, + id AS operation_id + FROM ( + SELECT + value->>'account' AS account, + value->>'proxy' AS proxy_account, + CASE WHEN (value->>'clear')::BOOLEAN IS TRUE THEN FALSE ELSE TRUE END AS proxy, + timestamp, id + FROM vote_or_proxy_op + WHERE op_type_id = 91 + ) proxy_op + JOIN LATERAL ( + SELECT id AS account_id + FROM hive.hafbe_app_accounts_view + WHERE name = proxy_op.account + ) hav_a ON TRUE + JOIN LATERAL ( + SELECT id AS proxy_id + FROM hive.hafbe_app_accounts_view + WHERE name = proxy_op.proxy_account + ) hav_p ON TRUE + ORDER BY proxy_op.id DESC + ), + + insert_proxy_history AS ( INSERT INTO hafbe_app.account_proxies_history (account_id, proxy_id, proxy, timestamp) - VALUES (__proxy_op.account_id, __proxy_op.proxy_id, __proxy_op.proxy, __proxy_op.timestamp); - END IF; + SELECT account_id, proxy_id, proxy, timestamp + FROM select_proxy_ops + ) + + INSERT INTO hafbe_app.current_account_proxies AS cap (account_id, proxy_id, proxy, operation_id) + SELECT DISTINCT ON (account_id) + account_id, proxy_id, proxy, operation_id + FROM select_proxy_ops + ON CONFLICT ON CONSTRAINT pk_current_account_proxies DO UPDATE SET + proxy_id = EXCLUDED.proxy_id, + proxy = EXCLUDED.proxy + ; -- add new witnesses per block range INSERT INTO hafbe_app.current_witnesses (witness_id, url, price_feed, bias, feed_age, block_size, signing_key, version) diff --git a/db/indexes.sql b/db/indexes.sql index 013626e..c4bfad4 100644 --- a/db/indexes.sql +++ b/db/indexes.sql @@ -22,6 +22,7 @@ BEGIN CREATE INDEX IF NOT EXISTS current_account_proxies_proxy_id_proxy ON hafbe_app.current_account_proxies USING btree (proxy_id, proxy); CREATE INDEX IF NOT EXISTS current_account_proxies_account_id_proxy ON hafbe_app.current_account_proxies USING btree (account_id, proxy); CREATE INDEX IF NOT EXISTS current_account_proxies_account_id_proxy_id ON hafbe_app.current_account_proxies USING btree (account_id, proxy_id); + CREATE INDEX IF NOT EXISTS current_account_proxies_proxy_id_operation_id ON hafbe_app.current_account_proxies USING btree (proxy_id, operation_id); CREATE INDEX IF NOT EXISTS account_vests_vests ON hafbe_app.account_vests USING btree (vests); END -- GitLab From 43f7729ca8d93877b4879708616f48ec82bdda10 Mon Sep 17 00:00:00 2001 From: kristupas Date: Tue, 18 Oct 2022 00:01:46 -0400 Subject: [PATCH 57/89] Added quick queries for witnesses votes #22 --- api/backend.sql | 27 ++++++++++++------ api/views.sql | 75 +++++++++++++++++++++++++++++++++++++++---------- 2 files changed, 79 insertions(+), 23 deletions(-) diff --git a/api/backend.sql b/api/backend.sql index ca8c0c7..650228f 100644 --- a/api/backend.sql +++ b/api/backend.sql @@ -395,16 +395,27 @@ $function$ BEGIN RETURN QUERY EXECUTE format( $query$ - - SELECT witness_id, votes::NUMERIC, voters_num::INT + SELECT witness_id, votes, voters_num FROM ( SELECT - witness_id, - SUM(account_vests + proxied_vests) AS votes, - COUNT(1) AS voters_num - FROM hafbe_views.voters_stats_view - GROUP BY witness_id - ) all_votes + vavv.witness_id, + vavv.account_vests + vpvv.proxied_vests AS votes, + cwv.voters_num + FROM hafbe_views.voters_account_vests_view vavv + JOIN ( + SELECT + witness_id, + proxied_vests + FROM hafbe_views.voters_proxied_vests_view + ) vpvv ON vpvv.witness_id = vavv.witness_id + JOIN ( + SELECT + witness_id, + COUNT(voter_id)::INT AS voters_num + FROM hafbe_app.current_witness_votes + GROUP BY witness_id + ) cwv ON cwv.witness_id = vavv.witness_id + ) votes_sum ORDER BY (CASE WHEN %L = 'desc' THEN %I ELSE NULL END) DESC, (CASE WHEN %L = 'asc' THEN %I ELSE NULL END) ASC diff --git a/api/views.sql b/api/views.sql index fceb91e..84e4591 100644 --- a/api/views.sql +++ b/api/views.sql @@ -13,28 +13,28 @@ SELECT prox5.account_id AS proxies_of_proxies3 FROM hafbe_app.current_account_proxies prox1 -LEFT JOIN ( - SELECT proxy_id, account_id, proxy +LEFT JOIN LATERAL ( + SELECT proxy_id, account_id, proxy, operation_id FROM hafbe_app.current_account_proxies - WHERE proxy = TRUE + WHERE proxy = TRUE AND operation_id < prox1.operation_id ) prox2 ON prox2.proxy_id = prox1.account_id -LEFT JOIN ( - SELECT proxy_id, account_id, proxy +LEFT JOIN LATERAL ( + SELECT proxy_id, account_id, proxy, operation_id FROM hafbe_app.current_account_proxies - WHERE proxy = TRUE + WHERE proxy = TRUE AND operation_id < prox2.operation_id ) prox3 ON prox3.proxy_id = prox2.account_id -LEFT JOIN ( - SELECT proxy_id, account_id, proxy +LEFT JOIN LATERAL ( + SELECT proxy_id, account_id, proxy, operation_id FROM hafbe_app.current_account_proxies - WHERE proxy = TRUE + WHERE proxy = TRUE AND operation_id < prox3.operation_id ) prox4 ON prox4.proxy_id = prox3.account_id -LEFT JOIN ( - SELECT proxy_id, account_id, proxy +LEFT JOIN LATERAL ( + SELECT proxy_id, account_id, proxy, operation_id FROM hafbe_app.current_account_proxies - WHERE proxy = TRUE + WHERE proxy = TRUE AND operation_id < prox4.operation_id ) prox5 ON prox5.proxy_id = prox4.account_id WHERE prox1.proxy = TRUE; @@ -50,10 +50,10 @@ SELECT FROM hafbe_app.current_witness_votes cwv JOIN LATERAL ( - SELECT * + SELECT voter_id, voters_proxies, proxies_of_voters_proxies, proxies_of_proxies1, proxies_of_proxies2, proxies_of_proxies3 FROM hafbe_views.recursively_proxied_accounts_view WHERE voter_id = cwv.voter_id -) proxied_accs ON cwv.voter_id = cwv.voter_id +) proxied_accs ON proxied_accs.voter_id = cwv.voter_id CROSS JOIN LATERAL ( VALUES (voters_proxies), (proxies_of_voters_proxies), (proxies_of_proxies1), (proxies_of_proxies2), (proxies_of_proxies3) @@ -138,4 +138,49 @@ LEFT JOIN ( FROM hafbe_app.account_vests ) account ON account.account_id = acc_as_proxied.account_id -GROUP BY witness_id, voter_id, approve, timestamp, acc_as_proxied.proxy, account.vests; \ No newline at end of file +GROUP BY witness_id, voter_id, approve, timestamp, acc_as_proxied.proxy, account.vests; + +------ + +DROP VIEW IF EXISTS hafbe_views.voters_account_vests_view CASCADE; +CREATE VIEW hafbe_views.voters_account_vests_view AS +SELECT + cwv.witness_id, + SUM(account.vests) AS account_vests +FROM hafbe_app.current_witness_votes cwv + +JOIN ( + SELECT account_id + FROM hafbe_app.current_account_proxies + WHERE proxy = FALSE +) acc_as_proxied ON acc_as_proxied.account_id = cwv.voter_id + +JOIN ( + SELECT vests, account_id + FROM hafbe_app.account_vests +) account ON account.account_id = cwv.voter_id + +WHERE cwv.approve IS TRUE +GROUP BY cwv.witness_id; + +------ + +DROP VIEW IF EXISTS hafbe_views.voters_proxied_vests_view CASCADE; +CREATE VIEW hafbe_views.voters_proxied_vests_view AS +SELECT + cwv.witness_id, + SUM(proxied.vests) AS proxied_vests +FROM hafbe_app.current_witness_votes cwv + +JOIN ( + SELECT witness_id, voter_id, account_id + FROM hafbe_views.recursively_proxied_accounts_unpivoted_view +) rpauv ON rpauv.witness_id = cwv.witness_id AND rpauv.voter_id = cwv.voter_id + +JOIN ( + SELECT vests, account_id + FROM hafbe_app.account_vests +) proxied ON proxied.account_id = rpauv.account_id + +WHERE cwv.approve IS TRUE +GROUP BY cwv.witness_id; \ No newline at end of file -- GitLab From d58c0261291523b6e013d333b1b94dac41b7f7f0 Mon Sep 17 00:00:00 2001 From: kristupas Date: Thu, 20 Oct 2022 15:23:28 -0400 Subject: [PATCH 58/89] Created 'recursive_account_proxies' table #22 --- db/hafbe_app.sql | 197 ++++++++++++++++++++++++++++++++++++++++------- 1 file changed, 168 insertions(+), 29 deletions(-) diff --git a/db/hafbe_app.sql b/db/hafbe_app.sql index 194ec40..3c1cc83 100644 --- a/db/hafbe_app.sql +++ b/db/hafbe_app.sql @@ -30,7 +30,6 @@ BEGIN CREATE TABLE IF NOT EXISTS hafbe_app.current_witness_votes ( witness_id INT NOT NULL, voter_id INT NOT NULL, - approve BOOLEAN NOT NULL, timestamp TIMESTAMP NOT NULL, CONSTRAINT pk_current_witness_votes PRIMARY KEY (witness_id, voter_id) @@ -59,12 +58,20 @@ BEGIN CREATE TABLE IF NOT EXISTS hafbe_app.current_account_proxies ( account_id INT NOT NULL, proxy_id INT NOT NULL, - proxy BOOLEAN NOT NULL, operation_id BIGINT NOT NULL, CONSTRAINT pk_current_account_proxies PRIMARY KEY (account_id) ) INHERITS (hive.hafbe_app); + CREATE INDEX IF NOT EXISTS current_account_proxies_proxy_id_operation_id ON hafbe_app.current_account_proxies USING btree (proxy_id, operation_id); + + CREATE TABLE IF NOT EXISTS hafbe_app.recursive_account_proxies ( + proxy_id INT NOT NULL, + account_id INT NOT NULL, + + CONSTRAINT pk_recursive_account_proxies PRIMARY KEY (proxy_id, account_id) + ) INHERITS (hive.hafbe_app); + CREATE TABLE IF NOT EXISTS hafbe_app.hived_account_cache ( account TEXT NOT NULL, data JSON NOT NULL, @@ -177,13 +184,9 @@ BEGIN FROM hive.hafbe_app_operations_view WHERE op_type_id = ANY('{12,91}') AND block_num BETWEEN _from AND _to ), - - insert_votes_history AS ( - INSERT INTO hafbe_app.witness_votes_history (witness_id, voter_id, approve, timestamp) - SELECT - hav_w.witness_id, - hav_v.voter_id, - approve, timestamp + + select_votes_ops AS ( + SELECT hav_w.witness_id, hav_v.voter_id, approve, timestamp FROM ( SELECT value->>'witness' AS witness, @@ -204,32 +207,38 @@ BEGIN WHERE name = vote_op.voter ) hav_v ON TRUE ORDER BY id DESC - RETURNING witness_id, voter_id, approve, timestamp + ), + + insert_votes_history AS ( + INSERT INTO hafbe_app.witness_votes_history (witness_id, voter_id, approve, timestamp) + SELECT witness_id, voter_id, approve, timestamp + FROM select_votes_ops ), insert_current_votes AS ( - INSERT INTO hafbe_app.current_witness_votes (witness_id, voter_id, approve, timestamp) + INSERT INTO hafbe_app.current_witness_votes (witness_id, voter_id, timestamp) SELECT DISTINCT ON (witness_id, voter_id) - witness_id, voter_id, approve, timestamp - FROM insert_votes_history + witness_id, voter_id, timestamp + FROM select_votes_ops + WHERE approve IS TRUE ON CONFLICT ON CONSTRAINT pk_current_witness_votes DO UPDATE SET - approve = EXCLUDED.approve, timestamp = EXCLUDED.timestamp ), + delete_current_votes AS ( + DELETE FROM hafbe_app.current_witness_votes cwv USING select_votes_ops svo + WHERE svo.approve IS FALSE AND cwv.witness_id = svo.witness_id AND cwv.voter_id = svo.voter_id + ), + insert_witnesses_from_votes AS ( INSERT INTO hafbe_app.current_witnesses (witness_id, url, price_feed, bias, feed_age, block_size, signing_key, version) SELECT witness_id, NULL, NULL, NULL, NULL, NULL, NULL, '1.25.0' - FROM insert_votes_history + FROM select_votes_ops ON CONFLICT ON CONSTRAINT pk_current_witnesses DO NOTHING ), select_proxy_ops AS ( - SELECT - hav_a.account_id, - hav_p.proxy_id, - proxy, timestamp, - id AS operation_id + SELECT hav_a.account_id, hav_p.proxy_id, proxy, timestamp, id AS operation_id FROM ( SELECT value->>'account' AS account, @@ -256,17 +265,147 @@ BEGIN INSERT INTO hafbe_app.account_proxies_history (account_id, proxy_id, proxy, timestamp) SELECT account_id, proxy_id, proxy, timestamp FROM select_proxy_ops + ), + + insert_current_proxies AS ( + INSERT INTO hafbe_app.current_account_proxies AS cap (account_id, proxy_id, operation_id) + SELECT DISTINCT ON (account_id) + account_id, proxy_id, operation_id + FROM select_proxy_ops + ON CONFLICT ON CONSTRAINT pk_current_account_proxies DO UPDATE SET + proxy_id = EXCLUDED.proxy_id + RETURNING cap.account_id, cap.proxy_id, cap.operation_id + ), + + delete_current_proxies AS ( + DELETE FROM hafbe_app.current_account_proxies cap USING select_proxy_ops spo + WHERE spo.proxy IS FALSE AND cap.account_id = spo.account_id + RETURNING cap.account_id, cap.proxy_id, cap.operation_id + ), + + proxies1 AS ( + SELECT + prox1.proxy_id AS top_proxy_id, + prox1.account_id, prox1.operation_id + FROM insert_current_proxies prox1 + ), + + proxies2 AS ( + SELECT prox1.top_proxy_id, prox2.account_id, prox2.operation_id + FROM proxies1 prox1 + JOIN LATERAL ( + SELECT proxy_id, account_id, operation_id + FROM hafbe_app.current_account_proxies + WHERE operation_id < prox1.operation_id AND proxy_id = prox1.account_id + ) prox2 ON TRUE + ), + + proxies3 AS ( + SELECT prox2.top_proxy_id, prox3.account_id, prox3.operation_id + FROM proxies2 prox2 + JOIN LATERAL ( + SELECT proxy_id, account_id, operation_id + FROM hafbe_app.current_account_proxies + WHERE operation_id < prox2.operation_id AND proxy_id = prox2.account_id + ) prox3 ON TRUE + ), + + proxies4 AS ( + SELECT prox3.top_proxy_id, prox4.account_id, prox4.operation_id + FROM proxies3 prox3 + JOIN LATERAL ( + SELECT proxy_id, account_id, operation_id + FROM hafbe_app.current_account_proxies + WHERE operation_id < prox3.operation_id AND proxy_id = prox3.account_id + ) prox4 ON TRUE + ), + + proxies5 AS ( + SELECT prox4.top_proxy_id, prox5.account_id + FROM proxies4 prox4 + JOIN LATERAL ( + SELECT proxy_id, account_id, operation_id + FROM hafbe_app.current_account_proxies + WHERE operation_id < prox4.operation_id AND proxy_id = prox4.account_id + ) prox5 ON TRUE + ), + + insert_recursive_account_proxies AS ( + INSERT INTO hafbe_app.recursive_account_proxies (proxy_id, account_id) + SELECT top_proxy_id, account_id FROM proxies1 + UNION + SELECT top_proxy_id, account_id FROM proxies2 + UNION + SELECT top_proxy_id, account_id FROM proxies3 + UNION + SELECT top_proxy_id, account_id FROM proxies4 + UNION + SELECT top_proxy_id, account_id FROM proxies5 + ON CONFLICT ON CONSTRAINT pk_recursive_account_proxies DO NOTHING + ), + + unproxies1 AS ( + SELECT + prox1.proxy_id AS top_proxy_id, + prox1.account_id, prox1.operation_id + FROM delete_current_proxies prox1 + ), + + unproxies2 AS ( + SELECT prox1.top_proxy_id, prox2.account_id, prox2.operation_id + FROM unproxies1 prox1 + JOIN LATERAL ( + SELECT proxy_id, account_id, operation_id + FROM hafbe_app.current_account_proxies + WHERE operation_id < prox1.operation_id AND proxy_id = prox1.account_id + ) prox2 ON TRUE + ), + + unproxies3 AS ( + SELECT prox2.top_proxy_id, prox3.account_id, prox3.operation_id + FROM unproxies2 prox2 + JOIN LATERAL ( + SELECT proxy_id, account_id, operation_id + FROM hafbe_app.current_account_proxies + WHERE operation_id < prox2.operation_id AND proxy_id = prox2.account_id + ) prox3 ON TRUE + ), + + unproxies4 AS ( + SELECT prox3.top_proxy_id, prox4.account_id, prox4.operation_id + FROM unproxies3 prox3 + JOIN LATERAL ( + SELECT proxy_id, account_id, operation_id + FROM hafbe_app.current_account_proxies + WHERE operation_id < prox3.operation_id AND proxy_id = prox3.account_id + ) prox4 ON TRUE + ), + + unproxies5 AS ( + SELECT prox4.top_proxy_id, prox5.account_id + FROM unproxies4 prox4 + JOIN LATERAL ( + SELECT proxy_id, account_id, operation_id + FROM hafbe_app.current_account_proxies + WHERE operation_id < prox4.operation_id AND proxy_id = prox4.account_id + ) prox5 ON TRUE + ), + + select_recursive_account_unproxies AS ( + SELECT top_proxy_id, account_id FROM unproxies1 + UNION + SELECT top_proxy_id, account_id FROM unproxies2 + UNION + SELECT top_proxy_id, account_id FROM unproxies3 + UNION + SELECT top_proxy_id, account_id FROM unproxies4 + UNION + SELECT top_proxy_id, account_id FROM unproxies5 ) - INSERT INTO hafbe_app.current_account_proxies AS cap (account_id, proxy_id, proxy, operation_id) - SELECT DISTINCT ON (account_id) - account_id, proxy_id, proxy, operation_id - FROM select_proxy_ops - ON CONFLICT ON CONSTRAINT pk_current_account_proxies DO UPDATE SET - proxy_id = EXCLUDED.proxy_id, - proxy = EXCLUDED.proxy - ; - + DELETE FROM hafbe_app.recursive_account_proxies rap USING select_recursive_account_unproxies raup + WHERE rap.proxy_id = raup.top_proxy_id AND rap.account_id = raup.account_id; + -- add new witnesses per block range INSERT INTO hafbe_app.current_witnesses (witness_id, url, price_feed, bias, feed_age, block_size, signing_key, version) SELECT DISTINCT ON (account_id) -- GitLab From cfae20e9cc95d832bcfefedd7137590de3eeae4b Mon Sep 17 00:00:00 2001 From: kristupas Date: Thu, 20 Oct 2022 21:05:46 -0400 Subject: [PATCH 59/89] Added 'recursive_account_proxies' to witness methods #22 --- api/backend.sql | 76 +++++----------- api/endpoints.sql | 2 +- api/views.sql | 220 +++++++++++++++++----------------------------- 3 files changed, 105 insertions(+), 193 deletions(-) diff --git a/api/backend.sql b/api/backend.sql index 650228f..576e78b 100644 --- a/api/backend.sql +++ b/api/backend.sql @@ -273,12 +273,9 @@ BEGIN RETURN QUERY EXECUTE format( $query$ - SELECT voter_id, vests, account_vests, proxied_vests, timestamp - FROM ( - SELECT voter_id, proxied_vests + account_vests AS vests, account_vests, proxied_vests, timestamp - FROM hafbe_views.voters_stats_view - WHERE witness_id = %L - ) vests_sum + SELECT voter_id, vests, account_vests::NUMERIC, proxied_vests, timestamp + FROM hafbe_views.voters_stats_view + WHERE witness_id = %L ORDER BY (CASE WHEN %L = 'desc' THEN %I ELSE NULL END) DESC, (CASE WHEN %L = 'asc' THEN %I ELSE NULL END) ASC @@ -310,10 +307,10 @@ BEGIN RETURN QUERY EXECUTE format( $query$ - SELECT voter, vsv.vests, vsv.account_vests, vsv.proxied_vests, vsv.timestamp + SELECT voter, vsv.vests, vsv.account_vests::NUMERIC, vsv.proxied_vests, vsv.timestamp FROM hafbe_backend.get_set_of_witness_voters_by_name(%L, %L, %L, %L) ls JOIN ( - SELECT voter_id, proxied_vests + account_vests AS vests, account_vests, proxied_vests, timestamp + SELECT voter_id, vests, account_vests, proxied_vests, timestamp FROM hafbe_views.voters_stats_view WHERE witness_id = %L ) vsv ON vsv.voter_id = ls.voter_id @@ -398,23 +395,11 @@ BEGIN SELECT witness_id, votes, voters_num FROM ( SELECT - vavv.witness_id, - vavv.account_vests + vpvv.proxied_vests AS votes, - cwv.voters_num - FROM hafbe_views.voters_account_vests_view vavv - JOIN ( - SELECT - witness_id, - proxied_vests - FROM hafbe_views.voters_proxied_vests_view - ) vpvv ON vpvv.witness_id = vavv.witness_id - JOIN ( - SELECT - witness_id, - COUNT(voter_id)::INT AS voters_num - FROM hafbe_app.current_witness_votes - GROUP BY witness_id - ) cwv ON cwv.witness_id = vavv.witness_id + vsv.witness_id, + SUM(vsv.vests) AS votes, + COUNT(1)::INT AS voters_num + FROM hafbe_views.voters_stats_view vsv + GROUP BY vsv.witness_id ) votes_sum ORDER BY (CASE WHEN %L = 'desc' THEN %I ELSE NULL END) DESC, @@ -442,15 +427,8 @@ BEGIN $query$ SELECT witness_id, votes_daily_change::BIGINT, voters_num_daily_change::INT - FROM ( - SELECT - witness_id, - SUM(CASE WHEN approve IS TRUE THEN votes ELSE -1 * votes END) AS votes_daily_change, - SUM(CASE WHEN approve IS TRUE THEN 1 ELSE -1 END) AS voters_num_daily_change - FROM hafbe_views.voters_stats_change_view - WHERE timestamp >= %L - GROUP BY witness_id - ) todays_votes + FROM hafbe_views.voters_stats_change_view + WHERE timestamp >= %L ORDER BY (CASE WHEN %L = 'desc' THEN %I ELSE NULL END) DESC, (CASE WHEN %L = 'asc' THEN %I ELSE NULL END) ASC @@ -528,21 +506,17 @@ BEGIN LEFT JOIN LATERAL ( SELECT vsv.witness_id, - SUM(vsv.account_vests + vsv.proxied_vests) AS votes, + SUM(vsv.vests) AS votes, COUNT(1) AS voters_num FROM hafbe_views.voters_stats_view vsv WHERE vsv.witness_id = ls.witness_id GROUP BY vsv.witness_id ) all_votes ON all_votes.witness_id = ls.witness_id LEFT JOIN LATERAL ( - SELECT - vscv.witness_id, - SUM(CASE WHEN vscv.approve IS TRUE THEN vscv.votes ELSE -1 * vscv.votes END) AS votes_daily_change, - SUM(CASE WHEN vscv.approve IS TRUE THEN 1 ELSE -1 END) AS voters_num_daily_change + SELECT vscv.witness_id, votes_daily_change, voters_num_daily_change FROM hafbe_views.voters_stats_change_view vscv WHERE timestamp >= %L AND vscv.witness_id = ls.witness_id - GROUP BY vscv.witness_id - ) todays_votes ON todays_votes.witness_id = ls.witness_id + ) todays_votes ON TRUE ORDER BY (CASE WHEN %L = 'desc' THEN %I ELSE NULL END) DESC, (CASE WHEN %L = 'asc' THEN %I ELSE NULL END) ASC @@ -567,14 +541,10 @@ BEGIN FROM hafbe_backend.get_set_of_witnesses_by_votes(%L, %L, %L, %L) ls JOIN hafbe_app.current_witnesses cw ON cw.witness_id = ls.witness_id LEFT JOIN LATERAL ( - SELECT - vscv.witness_id, - SUM(CASE WHEN vscv.approve IS TRUE THEN vscv.votes ELSE -1 * vscv.votes END) AS votes_daily_change, - SUM(CASE WHEN vscv.approve IS TRUE THEN 1 ELSE -1 END) AS voters_num_daily_change + SELECT vscv.witness_id, votes_daily_change, voters_num_daily_change FROM hafbe_views.voters_stats_change_view vscv WHERE timestamp >= %L AND vscv.witness_id = ls.witness_id - GROUP BY vscv.witness_id - ) todays_votes ON todays_votes.witness_id = ls.witness_id + ) todays_votes ON TRUE JOIN ( SELECT name, id FROM hive.accounts_view @@ -605,7 +575,7 @@ BEGIN JOIN LATERAL ( SELECT vsv.witness_id, - SUM(vsv.account_vests + vsv.proxied_vests) AS votes, + SUM(vsv.vests) AS votes, COUNT(1) AS voters_num FROM hafbe_views.voters_stats_view vsv WHERE vsv.witness_id = ls.witness_id @@ -640,21 +610,17 @@ BEGIN LEFT JOIN LATERAL ( SELECT vsv.witness_id, - SUM(vsv.account_vests + vsv.proxied_vests) AS votes, + SUM(vsv.vests) AS votes, COUNT(1) AS voters_num FROM hafbe_views.voters_stats_view vsv WHERE vsv.witness_id = ls.witness_id GROUP BY vsv.witness_id ) all_votes ON all_votes.witness_id = ls.witness_id LEFT JOIN LATERAL ( - SELECT - vscv.witness_id, - SUM(CASE WHEN vscv.approve IS TRUE THEN vscv.votes ELSE -1 * vscv.votes END) AS votes_daily_change, - SUM(CASE WHEN vscv.approve IS TRUE THEN 1 ELSE -1 END) AS voters_num_daily_change + SELECT vscv.witness_id, votes_daily_change, voters_num_daily_change FROM hafbe_views.voters_stats_change_view vscv WHERE timestamp >= %L AND vscv.witness_id = ls.witness_id - GROUP BY vscv.witness_id - ) todays_votes ON todays_votes.witness_id = ls.witness_id + ) todays_votes ON TRUE JOIN ( SELECT name, id FROM hive.accounts_view diff --git a/api/endpoints.sql b/api/endpoints.sql index a51c083..567883a 100644 --- a/api/endpoints.sql +++ b/api/endpoints.sql @@ -299,7 +299,7 @@ BEGIN RETURN hafbe_exceptions.raise_no_such_column_exception(_order_by); END IF; IF _order_by IS NULL THEN - _order_by = 'vests'; + _order_by = 'votes'; END IF; IF _order_is NOT SIMILAR TO '(asc|desc)' THEN diff --git a/api/views.sql b/api/views.sql index 84e4591..b251036 100644 --- a/api/views.sql +++ b/api/views.sql @@ -2,185 +2,131 @@ DROP SCHEMA IF EXISTS hafbe_views CASCADE; CREATE SCHEMA hafbe_views AUTHORIZATION hafbe_owner; -DROP VIEW IF EXISTS hafbe_views.recursively_proxied_accounts_view CASCADE; -CREATE VIEW hafbe_views.recursively_proxied_accounts_view AS +DROP VIEW IF EXISTS hafbe_views.voters_account_vests_view CASCADE; +CREATE VIEW hafbe_views.voters_account_vests_view AS SELECT - prox1.proxy_id AS voter_id, - prox1.account_id AS voters_proxies, - prox2.account_id AS proxies_of_voters_proxies, - prox3.account_id AS proxies_of_proxies1, - prox4.account_id AS proxies_of_proxies2, - prox5.account_id AS proxies_of_proxies3 -FROM hafbe_app.current_account_proxies prox1 - -LEFT JOIN LATERAL ( - SELECT proxy_id, account_id, proxy, operation_id - FROM hafbe_app.current_account_proxies - WHERE proxy = TRUE AND operation_id < prox1.operation_id -) prox2 ON prox2.proxy_id = prox1.account_id - -LEFT JOIN LATERAL ( - SELECT proxy_id, account_id, proxy, operation_id - FROM hafbe_app.current_account_proxies - WHERE proxy = TRUE AND operation_id < prox2.operation_id -) prox3 ON prox3.proxy_id = prox2.account_id + av.account_id AS voter_id, + CASE WHEN cap.account_id IS NULL THEN av.vests ELSE 0 END AS account_vests +FROM hafbe_app.account_vests av LEFT JOIN LATERAL ( - SELECT proxy_id, account_id, proxy, operation_id - FROM hafbe_app.current_account_proxies - WHERE proxy = TRUE AND operation_id < prox3.operation_id -) prox4 ON prox4.proxy_id = prox3.account_id - -LEFT JOIN LATERAL ( - SELECT proxy_id, account_id, proxy, operation_id + SELECT account_id FROM hafbe_app.current_account_proxies - WHERE proxy = TRUE AND operation_id < prox4.operation_id -) prox5 ON prox5.proxy_id = prox4.account_id - -WHERE prox1.proxy = TRUE; + WHERE account_id = av.account_id +) cap ON TRUE; ------ -DROP VIEW IF EXISTS hafbe_views.recursively_proxied_accounts_unpivoted_view CASCADE; -CREATE VIEW hafbe_views.recursively_proxied_accounts_unpivoted_view AS +DROP VIEW IF EXISTS hafbe_views.voters_proxied_vests_view CASCADE; +CREATE VIEW hafbe_views.voters_proxied_vests_view AS SELECT - cwv.witness_id, - cwv.voter_id, - unpivot.account_id -FROM hafbe_app.current_witness_votes cwv + rap.proxy_id, + SUM(av.vests) AS proxied_vests +FROM hafbe_app.recursive_account_proxies rap -JOIN LATERAL ( - SELECT voter_id, voters_proxies, proxies_of_voters_proxies, proxies_of_proxies1, proxies_of_proxies2, proxies_of_proxies3 - FROM hafbe_views.recursively_proxied_accounts_view - WHERE voter_id = cwv.voter_id -) proxied_accs ON proxied_accs.voter_id = cwv.voter_id - -CROSS JOIN LATERAL ( - VALUES (voters_proxies), (proxies_of_voters_proxies), (proxies_of_proxies1), (proxies_of_proxies2), (proxies_of_proxies3) -) AS unpivot(account_id) - -WHERE unpivot.account_id IS NOT NULL; - ------- - -DROP VIEW IF EXISTS hafbe_views.recursively_proxied_vests_view CASCADE; -CREATE VIEW hafbe_views.recursively_proxied_vests_view AS -SELECT - rpauv.witness_id, - rpauv.voter_id, - SUM(proxied.vests) AS proxied_vests -FROM hafbe_views.recursively_proxied_accounts_unpivoted_view rpauv -JOIN LATERAL ( - SELECT vests, account_id +JOIN ( + SELECT account_id, vests FROM hafbe_app.account_vests - WHERE account_id = rpauv.account_id -) proxied ON proxied.account_id = rpauv.account_id -GROUP BY rpauv.witness_id, rpauv.voter_id; +) av ON av.account_id = rap.account_id +GROUP BY rap.proxy_id; ------ DROP VIEW IF EXISTS hafbe_views.voters_stats_view CASCADE; CREATE VIEW hafbe_views.voters_stats_view AS SELECT - cwv.witness_id, cwv.voter_id, cwv.timestamp, - COALESCE(account.vests, 0)::NUMERIC AS account_vests, - COALESCE(rpv.proxied_vests, 0) AS proxied_vests + cwv.witness_id, cwv.voter_id, + COALESCE(vavv.account_vests, 0) + COALESCE(vpvv.proxied_vests, 0) AS vests, + COALESCE(vavv.account_vests, 0) AS account_vests, + COALESCE(vpvv.proxied_vests, 0) AS proxied_vests, + cwv.timestamp FROM hafbe_app.current_witness_votes cwv LEFT JOIN LATERAL ( - SELECT witness_id, voter_id, proxied_vests - FROM hafbe_views.recursively_proxied_vests_view - WHERE witness_id = cwv.witness_id AND voter_id = cwv.voter_id -) rpv ON rpv.witness_id = cwv.witness_id AND rpv.voter_id = cwv.voter_id - -LEFT JOIN ( - SELECT account_id, proxy - FROM hafbe_app.current_account_proxies -) acc_as_proxied ON acc_as_proxied.account_id = cwv.voter_id - -LEFT JOIN ( - SELECT vests, account_id - FROM hafbe_app.account_vests -) account ON account.account_id = cwv.voter_id AND COALESCE(acc_as_proxied.proxy, FALSE) IS FALSE + SELECT voter_id, account_vests + FROM hafbe_views.voters_account_vests_view + WHERE voter_id = cwv.voter_id +) vavv ON TRUE -WHERE cwv.approve IS TRUE; +LEFT JOIN LATERAL ( + SELECT proxy_id, proxied_vests + FROM hafbe_views.voters_proxied_vests_view + WHERE proxy_id = cwv.voter_id +) vpvv ON TRUE; ------ -DROP VIEW IF EXISTS hafbe_views.voters_stats_change_view CASCADE; -CREATE VIEW hafbe_views.voters_stats_change_view AS -SELECT - witness_id, voter_id, approve, timestamp, - ( - SUM(CASE WHEN acc_as_proxy.proxy IS TRUE THEN proxied.vests ELSE -1 * proxied.vests END) - + - CASE WHEN acc_as_proxied.proxy IS FALSE THEN account.vests ELSE -1 * account.vests END - ) AS votes -FROM hafbe_app.witness_votes_history +DROP VIEW IF EXISTS hafbe_views.voters_history_account_vests_view CASCADE; +CREATE VIEW hafbe_views.voters_history_account_vests_view AS +SELECT wvh.witness_id, wvh.voter_id, wvh.approve, wvh.timestamp, av.vests +FROM hafbe_app.witness_votes_history wvh -LEFT JOIN ( - SELECT account_id, proxy_id, proxy - FROM hafbe_app.account_proxies_history -) acc_as_proxy ON acc_as_proxy.proxy_id = voter_id - -LEFT JOIN ( +JOIN ( SELECT vests, account_id FROM hafbe_app.account_vests -) proxied ON proxied.account_id = acc_as_proxy.account_id +) av ON av.account_id = wvh.voter_id; + +------ -LEFT JOIN ( - SELECT account_id, proxy - FROM hafbe_app.account_proxies_history -) acc_as_proxied ON acc_as_proxied.account_id = voter_id +DROP VIEW IF EXISTS hafbe_views.voters_approve_vests_change_view CASCADE; +CREATE VIEW hafbe_views.voters_approve_vests_change_view AS +SELECT + wvh.witness_id, wvh.voter_id, wvh.approve, wvh.timestamp, + CASE WHEN wvh.approve THEN av.vests ELSE -1 * av.vests END AS approve_votes_change, + CASE WHEN wvh.approve THEN COALESCE(rpav.proxied_vests, 0) ELSE -1 * COALESCE(rpav.proxied_vests, 0) END AS proxy_votes_change +FROM hafbe_app.witness_votes_history wvh -LEFT JOIN ( +JOIN ( SELECT vests, account_id FROM hafbe_app.account_vests -) account ON account.account_id = acc_as_proxied.account_id +) av ON av.account_id = wvh.voter_id -GROUP BY witness_id, voter_id, approve, timestamp, acc_as_proxied.proxy, account.vests; +LEFT JOIN LATERAL ( + SELECT proxy_id, proxied_vests + FROM hafbe_views.voters_proxied_vests_view + WHERE proxy_id = wvh.voter_id +) rpav ON TRUE; ------ -DROP VIEW IF EXISTS hafbe_views.voters_account_vests_view CASCADE; -CREATE VIEW hafbe_views.voters_account_vests_view AS +DROP VIEW IF EXISTS hafbe_views.voters_proxy_vests_change_view CASCADE; +CREATE VIEW hafbe_views.voters_proxy_vests_change_view AS SELECT - cwv.witness_id, - SUM(account.vests) AS account_vests -FROM hafbe_app.current_witness_votes cwv - -JOIN ( - SELECT account_id - FROM hafbe_app.current_account_proxies - WHERE proxy = FALSE -) acc_as_proxied ON acc_as_proxied.account_id = cwv.voter_id + aph.account_id AS voter_id, + SUM(CASE WHEN aph.proxy THEN -1 * av.vests ELSE av.vests END) AS account_vests, + SUM(CASE WHEN aph.proxy THEN -1 * COALESCE(rpav.proxied_vests, 0) ELSE COALESCE(rpav.proxied_vests, 0) END) AS proxied_vests +FROM hafbe_app.account_proxies_history aph JOIN ( SELECT vests, account_id FROM hafbe_app.account_vests -) account ON account.account_id = cwv.voter_id +) av ON av.account_id = aph.account_id -WHERE cwv.approve IS TRUE -GROUP BY cwv.witness_id; +LEFT JOIN LATERAL ( + SELECT proxy_id, proxied_vests + FROM hafbe_views.voters_proxied_vests_view + WHERE proxy_id = aph.account_id +) rpav ON TRUE +GROUP BY aph.account_id; ------ -DROP VIEW IF EXISTS hafbe_views.voters_proxied_vests_view CASCADE; -CREATE VIEW hafbe_views.voters_proxied_vests_view AS +DROP VIEW IF EXISTS hafbe_views.voters_stats_change_view CASCADE; +CREATE VIEW hafbe_views.voters_stats_change_view AS SELECT - cwv.witness_id, - SUM(proxied.vests) AS proxied_vests -FROM hafbe_app.current_witness_votes cwv - -JOIN ( - SELECT witness_id, voter_id, account_id - FROM hafbe_views.recursively_proxied_accounts_unpivoted_view -) rpauv ON rpauv.witness_id = cwv.witness_id AND rpauv.voter_id = cwv.voter_id - -JOIN ( - SELECT vests, account_id - FROM hafbe_app.account_vests -) proxied ON proxied.account_id = rpauv.account_id + vavcv.witness_id, + SUM( + vavcv.approve_votes_change + vavcv.proxy_votes_change + + + COALESCE(vpvcv.account_vests, 0) + COALESCE(vpvcv.proxied_vests, 0) + ) AS votes_daily_change, + SUM(CASE WHEN vavcv.approve THEN 1 ELSE -1 END) AS voters_num_daily_change, + MAX(vavcv.timestamp) AS timestamp +FROM hafbe_views.voters_approve_vests_change_view vavcv -WHERE cwv.approve IS TRUE -GROUP BY cwv.witness_id; \ No newline at end of file +LEFT JOIN LATERAL ( + SELECT voter_id, account_vests, proxied_vests + FROM hafbe_views.voters_proxy_vests_change_view + WHERE voter_id = vavcv.voter_id +) vpvcv ON TRUE +GROUP BY vavcv.witness_id; \ No newline at end of file -- GitLab From 6baf356213a7fdfe36e76e74e137afe1602f5a1f Mon Sep 17 00:00:00 2001 From: kristupas Date: Fri, 21 Oct 2022 16:02:54 -0400 Subject: [PATCH 60/89] Added 'get_witness_voters_daily_change' method, updated voter history queries #22 --- .gitignore | 3 +- api/backend.sql | 207 ++++++++++++++++++++++++++++++++++++++++------ api/endpoints.sql | 39 +++++++++ api/types.sql | 25 ++++++ api/views.sql | 32 ++----- db/indexes.sql | 21 ++--- run.sh | 3 +- 7 files changed, 265 insertions(+), 65 deletions(-) diff --git a/.gitignore b/.gitignore index c4d2d66..d235270 100644 --- a/.gitignore +++ b/.gitignore @@ -1,2 +1,3 @@ tests/performance/result -build/ \ No newline at end of file +build/ +block_processing.log \ No newline at end of file diff --git a/api/backend.sql b/api/backend.sql index 576e78b..c659786 100644 --- a/api/backend.sql +++ b/api/backend.sql @@ -243,10 +243,13 @@ BEGIN RETURN QUERY EXECUTE format( $query$ - SELECT - voter_id, hav.name::TEXT AS voter - FROM hive.accounts_view hav - JOIN hafbe_app.current_witness_votes cwv ON hav.id = cwv.voter_id + SELECT cwv.voter_id, hav.name::TEXT AS voter + FROM hafbe_app.current_witness_votes cwv + JOIN LATERAL ( + SELECT name + FROM hive.accounts_view + WHERE id = cwv.voter_id + ) hav ON TRUE WHERE cwv.witness_id = %L ORDER BY (CASE WHEN %L = 'desc' THEN hav.name ELSE NULL END) DESC, @@ -293,10 +296,6 @@ SET join_collapse_limit=16 SET from_collapse_limit=16 ; -/* -witnesses -*/ - CREATE FUNCTION hafbe_backend.get_set_of_witness_voters(_witness_id INT, _limit INT, _offset INT, _order_by TEXT, _order_is TEXT) RETURNS SETOF hafbe_types.witness_voters AS @@ -354,6 +353,158 @@ SET join_collapse_limit=16 SET from_collapse_limit=16 ; +/* +witness voters change +*/ + +CREATE FUNCTION hafbe_backend.get_todays_date() +RETURNS DATE +LANGUAGE 'plpgsql' +AS +$$ +DECLARE + __today DATE; +BEGIN + IF ( + SELECT timestamp::DATE FROM hafbe_app.witness_votes_history ORDER BY timestamp DESC LIMIT 1 + ) != 'today'::DATE THEN + __today = NULL; + ELSE + __today = 'today'::DATE; + END IF; + RETURN __today; +END +$$ +; + +CREATE FUNCTION hafbe_backend.get_set_of_witness_voters_daily_change_by_name(_witness_id INT, _limit INT, _offset INT, _order_is TEXT, _today DATE) +RETURNS SETOF hafbe_types.witness_voters_daily_change_by_name +AS +$function$ +BEGIN + RETURN QUERY EXECUTE format( + $query$ + + SELECT wvh.witness_id, wvh.voter_id, hav.name::TEXT, wvh.approve + FROM hafbe_app.witness_votes_history wvh + JOIN LATERAL ( + SELECT name + FROM hive.accounts_view + WHERE id = wvh.voter_id + ) hav ON TRUE + WHERE wvh.witness_id = %L AND wvh.timestamp >= %L + ORDER BY + (CASE WHEN %L = 'desc' THEN hav.name ELSE NULL END) DESC, + (CASE WHEN %L = 'asc' THEN hav.name ELSE NULL END) ASC + OFFSET %L + LIMIT %L + + $query$, + _witness_id, _today, + _order_is, _order_is, _offset, _limit + ); +END +$function$ +LANGUAGE 'plpgsql' STABLE +SET JIT=OFF +SET join_collapse_limit=16 +SET from_collapse_limit=16 +; + +CREATE FUNCTION hafbe_backend.get_set_of_witness_voters_daily_change_by_vests(_witness_id INT, _limit INT, _offset INT, _order_by TEXT, _order_is TEXT, _today DATE) +RETURNS SETOF hafbe_types.witness_voters_daily_change_by_vests +AS +$function$ +BEGIN + RETURN QUERY EXECUTE format( + $query$ + + SELECT voter_id, vests::BIGINT, account_vests::BIGINT, proxied_vests::BIGINT, timestamp, approve + FROM hafbe_views.voters_stats_change_view + WHERE witness_id = %L AND timestamp >= %L + ORDER BY + (CASE WHEN %L = 'desc' THEN %I ELSE NULL END) DESC, + (CASE WHEN %L = 'asc' THEN %I ELSE NULL END) ASC + OFFSET %L + LIMIT %L + + $query$, + _witness_id, _today, + _order_is, _order_by, _order_is, _order_by, _offset, _limit + ); +END +$function$ +LANGUAGE 'plpgsql' STABLE +SET JIT=OFF +SET join_collapse_limit=16 +SET from_collapse_limit=16 +; + +CREATE FUNCTION hafbe_backend.get_set_of_witness_voters_daily_change(_witness_id INT, _limit INT, _offset INT, _order_by TEXT, _order_is TEXT) +RETURNS SETOF hafbe_types.witness_voters_daily_change +AS +$function$ +DECLARE + __today DATE; +BEGIN + SELECT hafbe_backend.get_todays_date() INTO __today; + + IF _order_by = 'voter' THEN + + RETURN QUERY EXECUTE format( + $query$ + + SELECT ls.voter, ls.approve, vscv.vests::BIGINT, vscv.account_vests::BIGINT, vscv.proxied_vests::BIGINT, vscv.timestamp + FROM hafbe_backend.get_set_of_witness_voters_daily_change_by_name(%L, %L, %L, %L, %L) ls + JOIN ( + SELECT voter_id, vests, account_vests, proxied_vests, timestamp + FROM hafbe_views.voters_stats_change_view vscv + WHERE witness_id = %L AND timestamp >= %L + ) vscv ON vscv.voter_id = ls.voter_id + ORDER BY + (CASE WHEN %L = 'desc' THEN %I ELSE NULL END) DESC, + (CASE WHEN %L = 'asc' THEN %I ELSE NULL END) ASC + ; + + $query$, + _witness_id, _limit, _offset, _order_is, __today, + _witness_id, __today, + _order_is, _order_by, _order_is, _order_by + ) res; + + ELSIF _order_by = ANY('{vests,account_vests,proxied_vests,timestamp}'::TEXT[]) THEN + + RETURN QUERY EXECUTE format( + $query$ + + SELECT hav.name::TEXT, ls.approve, ls.vests, ls.account_vests, ls.proxied_vests, ls.timestamp + FROM hafbe_backend.get_set_of_witness_voters_daily_change_by_vests(%L, %L, %L, %L, %L, %L) ls + JOIN ( + SELECT id, name + FROM hive.accounts_view + ) hav ON hav.id = ls.voter_id + ORDER BY + (CASE WHEN %L = 'desc' THEN %I ELSE NULL END) DESC, + (CASE WHEN %L = 'asc' THEN %I ELSE NULL END) ASC + ; + + $query$, + _witness_id, _limit, _offset, _order_by, _order_is, __today, + _order_is, _order_by, _order_is, _order_by + ) res; + + END IF; +END +$function$ +LANGUAGE 'plpgsql' STABLE +SET JIT=OFF +SET join_collapse_limit=16 +SET from_collapse_limit=16 +; + +/* +witnesses +*/ CREATE FUNCTION hafbe_backend.get_set_of_witnesses_by_name(_limit INT, _offset INT, _order_is TEXT) RETURNS SETOF hafbe_types.witnesses_by_name @@ -426,9 +577,13 @@ BEGIN RETURN QUERY EXECUTE format( $query$ - SELECT witness_id, votes_daily_change::BIGINT, voters_num_daily_change::INT - FROM hafbe_views.voters_stats_change_view + SELECT + witness_id, + SUM(vests)::BIGINT AS votes_daily_change, + COUNT(1)::INT AS voters_num_daily_change + FROM hafbe_views.voters_stats_change_view vscv WHERE timestamp >= %L + GROUP BY witness_id ORDER BY (CASE WHEN %L = 'desc' THEN %I ELSE NULL END) DESC, (CASE WHEN %L = 'asc' THEN %I ELSE NULL END) ASC @@ -482,13 +637,7 @@ $function$ DECLARE __today DATE; BEGIN - IF ( - SELECT timestamp::DATE FROM hafbe_app.witness_votes_history ORDER BY timestamp DESC LIMIT 1 - ) != 'today'::DATE THEN - __today = NULL; - ELSE - __today = 'today'::DATE; - END IF; + SELECT hafbe_backend.get_todays_date() INTO __today; IF _order_by = 'witness' THEN @@ -513,9 +662,13 @@ BEGIN GROUP BY vsv.witness_id ) all_votes ON all_votes.witness_id = ls.witness_id LEFT JOIN LATERAL ( - SELECT vscv.witness_id, votes_daily_change, voters_num_daily_change + SELECT + vscv.witness_id, + SUM(vscv.vests) AS votes_daily_change, + COUNT(1) AS voters_num_daily_change FROM hafbe_views.voters_stats_change_view vscv - WHERE timestamp >= %L AND vscv.witness_id = ls.witness_id + WHERE vscv.timestamp >= %L AND vscv.witness_id = ls.witness_id + GROUP BY vscv.witness_id ) todays_votes ON TRUE ORDER BY (CASE WHEN %L = 'desc' THEN %I ELSE NULL END) DESC, @@ -541,9 +694,13 @@ BEGIN FROM hafbe_backend.get_set_of_witnesses_by_votes(%L, %L, %L, %L) ls JOIN hafbe_app.current_witnesses cw ON cw.witness_id = ls.witness_id LEFT JOIN LATERAL ( - SELECT vscv.witness_id, votes_daily_change, voters_num_daily_change + SELECT + vscv.witness_id, + SUM(vscv.vests) AS votes_daily_change, + COUNT(1) AS voters_num_daily_change FROM hafbe_views.voters_stats_change_view vscv - WHERE timestamp >= %L AND vscv.witness_id = ls.witness_id + WHERE vscv.timestamp >= %L AND vscv.witness_id = ls.witness_id + GROUP BY vscv.witness_id ) todays_votes ON TRUE JOIN ( SELECT name, id @@ -617,9 +774,13 @@ BEGIN GROUP BY vsv.witness_id ) all_votes ON all_votes.witness_id = ls.witness_id LEFT JOIN LATERAL ( - SELECT vscv.witness_id, votes_daily_change, voters_num_daily_change + SELECT + vscv.witness_id, + SUM(vscv.vests) AS votes_daily_change, + COUNT(1) AS voters_num_daily_change FROM hafbe_views.voters_stats_change_view vscv - WHERE timestamp >= %L AND vscv.witness_id = ls.witness_id + WHERE vscv.timestamp >= %L AND vscv.witness_id = ls.witness_id + GROUP BY vscv.witness_id ) todays_votes ON TRUE JOIN ( SELECT name, id diff --git a/api/endpoints.sql b/api/endpoints.sql index 567883a..cfdddb3 100644 --- a/api/endpoints.sql +++ b/api/endpoints.sql @@ -280,6 +280,45 @@ END $$ ; +CREATE FUNCTION hafbe_endpoints.get_witness_voters_daily_change(_witness TEXT, _limit INT = 1000, _offset INT = 0, _order_by TEXT = 'vests', _order_is TEXT = 'desc') +RETURNS JSON +LANGUAGE 'plpgsql' +AS +$$ +DECLARE + __witness_id INT = hafbe_backend.get_account_id(_witness); +BEGIN + IF _limit IS NULL OR _limit <= 0 THEN + _limit = 1000; + END IF; + + IF _offset IS NULL OR _offset < 0 THEN + _offset = 0; + END IF; + + IF _order_by NOT SIMILAR TO '(voter|vests|account_vests|proxied_vests|timestamp)' THEN + RETURN hafbe_exceptions.raise_no_such_column_exception(_order_by); + END IF; + IF _order_by IS NULL THEN + _order_by = 'vests'; + END IF; + + IF _order_is NOT SIMILAR TO '(asc|desc)' THEN + RETURN hafbe_exceptions.raise_no_such_order_exception(_order_is); + END IF; + IF _order_is IS NULL THEN + _order_is = 'desc'; + END IF; + + RETURN CASE WHEN arr IS NOT NULL THEN to_json(arr) ELSE '[]'::JSON END FROM ( + SELECT ARRAY( + SELECT hafbe_backend.get_set_of_witness_voters_daily_change(__witness_id, _limit, _offset, _order_by, _order_is) + ) arr + ) result; +END +$$ +; + CREATE FUNCTION hafbe_endpoints.get_witnesses(_limit INT = 50, _offset INT = 0, _order_by TEXT = 'votes', _order_is TEXT = 'desc') RETURNS JSON LANGUAGE 'plpgsql' diff --git a/api/types.sql b/api/types.sql index 5e2c547..a345864 100644 --- a/api/types.sql +++ b/api/types.sql @@ -41,6 +41,31 @@ CREATE TYPE hafbe_types.witness_voters AS ( timestamp TIMESTAMP ); +CREATE TYPE hafbe_types.witness_voters_daily_change_by_name AS ( + witness_id INT, + voter_id INT, + voter TEXT, + approve BOOLEAN +); + +CREATE TYPE hafbe_types.witness_voters_daily_change_by_vests AS ( + voter_id INT, + vests BIGINT, + account_vests BIGINT, + proxied_vests BIGINT, + timestamp TIMESTAMP, + approve BOOLEAN +); + +CREATE TYPE hafbe_types.witness_voters_daily_change AS ( + account TEXT, + approve BOOLEAN, + vests BIGINT, + account_vests BIGINT, + proxied_vests BIGINT, + timestamp TIMESTAMP +); + CREATE TYPE hafbe_types.witnesses_by_name AS ( witness_id INT, witness TEXT, diff --git a/api/views.sql b/api/views.sql index b251036..cdfacab 100644 --- a/api/views.sql +++ b/api/views.sql @@ -56,24 +56,12 @@ LEFT JOIN LATERAL ( ------ -DROP VIEW IF EXISTS hafbe_views.voters_history_account_vests_view CASCADE; -CREATE VIEW hafbe_views.voters_history_account_vests_view AS -SELECT wvh.witness_id, wvh.voter_id, wvh.approve, wvh.timestamp, av.vests -FROM hafbe_app.witness_votes_history wvh - -JOIN ( - SELECT vests, account_id - FROM hafbe_app.account_vests -) av ON av.account_id = wvh.voter_id; - ------- - DROP VIEW IF EXISTS hafbe_views.voters_approve_vests_change_view CASCADE; CREATE VIEW hafbe_views.voters_approve_vests_change_view AS SELECT wvh.witness_id, wvh.voter_id, wvh.approve, wvh.timestamp, - CASE WHEN wvh.approve THEN av.vests ELSE -1 * av.vests END AS approve_votes_change, - CASE WHEN wvh.approve THEN COALESCE(rpav.proxied_vests, 0) ELSE -1 * COALESCE(rpav.proxied_vests, 0) END AS proxy_votes_change + CASE WHEN wvh.approve THEN av.vests ELSE -1 * av.vests END AS account_vests, + CASE WHEN wvh.approve THEN COALESCE(rpav.proxied_vests, 0) ELSE -1 * COALESCE(rpav.proxied_vests, 0) END AS proxied_vests FROM hafbe_app.witness_votes_history wvh JOIN ( @@ -114,19 +102,15 @@ GROUP BY aph.account_id; DROP VIEW IF EXISTS hafbe_views.voters_stats_change_view CASCADE; CREATE VIEW hafbe_views.voters_stats_change_view AS SELECT - vavcv.witness_id, - SUM( - vavcv.approve_votes_change + vavcv.proxy_votes_change - + - COALESCE(vpvcv.account_vests, 0) + COALESCE(vpvcv.proxied_vests, 0) - ) AS votes_daily_change, - SUM(CASE WHEN vavcv.approve THEN 1 ELSE -1 END) AS voters_num_daily_change, - MAX(vavcv.timestamp) AS timestamp + vavcv.witness_id, vavcv.voter_id, + vavcv.account_vests + vavcv.proxied_vests + COALESCE(vpvcv.account_vests, 0) + COALESCE(vpvcv.proxied_vests, 0) AS vests, + vavcv.account_vests + vavcv.proxied_vests AS account_vests, + COALESCE(vpvcv.account_vests, 0) + COALESCE(vpvcv.proxied_vests, 0) AS proxied_vests, + vavcv.approve, vavcv.timestamp FROM hafbe_views.voters_approve_vests_change_view vavcv LEFT JOIN LATERAL ( SELECT voter_id, account_vests, proxied_vests FROM hafbe_views.voters_proxy_vests_change_view WHERE voter_id = vavcv.voter_id -) vpvcv ON TRUE -GROUP BY vavcv.witness_id; \ No newline at end of file +) vpvcv ON TRUE; \ No newline at end of file diff --git a/db/indexes.sql b/db/indexes.sql index c4bfad4..cf36d80 100644 --- a/db/indexes.sql +++ b/db/indexes.sql @@ -9,22 +9,11 @@ LANGUAGE 'plpgsql' AS $$ BEGIN - CREATE INDEX IF NOT EXISTS witness_votes_history_witness_id_timestamp ON hafbe_app.witness_votes_history USING btree (witness_id, timestamp); - - CREATE INDEX IF NOT EXISTS current_witness_votes_witness_id_approve ON hafbe_app.current_witness_votes USING btree (witness_id, approve); - - CREATE INDEX IF NOT EXISTS account_proxies_history_timestamp ON hafbe_app.account_proxies_history USING btree (timestamp); - CREATE INDEX IF NOT EXISTS account_proxies_history_timestamp_account_id ON hafbe_app.account_proxies_history USING btree (timestamp, account_id); - CREATE INDEX IF NOT EXISTS account_proxies_history_timestamp_proxy_id ON hafbe_app.account_proxies_history USING btree (timestamp, proxy_id); - CREATE INDEX IF NOT EXISTS account_proxies_history_timestamp_proxy_id_proxy ON hafbe_app.account_proxies_history USING btree (timestamp, proxy_id, proxy); - CREATE INDEX IF NOT EXISTS account_proxies_history_account_id_proxy_id ON hafbe_app.account_proxies_history USING btree (account_id, proxy_id); - - CREATE INDEX IF NOT EXISTS current_account_proxies_proxy_id_proxy ON hafbe_app.current_account_proxies USING btree (proxy_id, proxy); - CREATE INDEX IF NOT EXISTS current_account_proxies_account_id_proxy ON hafbe_app.current_account_proxies USING btree (account_id, proxy); - CREATE INDEX IF NOT EXISTS current_account_proxies_account_id_proxy_id ON hafbe_app.current_account_proxies USING btree (account_id, proxy_id); - CREATE INDEX IF NOT EXISTS current_account_proxies_proxy_id_operation_id ON hafbe_app.current_account_proxies USING btree (proxy_id, operation_id); - - CREATE INDEX IF NOT EXISTS account_vests_vests ON hafbe_app.account_vests USING btree (vests); + CREATE INDEX IF NOT EXISTS current_witness_votes_voter_id ON hafbe_app.current_witness_votes USING btree (voter_id); + CREATE INDEX IF NOT EXISTS witness_votes_history_timestamp ON hafbe_app.witness_votes_history USING btree (timestamp); + CREATE INDEX IF NOT EXISTS account_proxies_history_timestamp ON hafbe_app.account_proxies_history USING btree (timestamp); + CREATE INDEX IF NOT EXISTS account_proxies_history_account_id ON hafbe_app.account_proxies_history USING btree (account_id); + CREATE INDEX IF NOT EXISTS account_vests_account_id ON hafbe_app.account_vests USING btree (account_id); END $$ ; diff --git a/run.sh b/run.sh index a64340c..d5579b2 100755 --- a/run.sh +++ b/run.sh @@ -5,7 +5,8 @@ set -o pipefail process_blocks() { n_blocks="${1:-null}" - sudo -nu $owner_role psql -d $DB_NAME -a -v "ON_ERROR_STOP=on" -c "\timing" -c "CALL hafbe_app.main('hafbe_app', $n_blocks);" + log_file="block_processing.log" + sudo -nu $owner_role psql -d $DB_NAME -a -v "ON_ERROR_STOP=on" -c "\timing" -c "CALL hafbe_app.main('hafbe_app', $n_blocks);" 2>&1 | tee $log_file } stop_processing() { -- GitLab From ae8ecd194210d92218c6c6880e6b9ee42784cb55 Mon Sep 17 00:00:00 2001 From: kristupas Date: Sat, 22 Oct 2022 22:54:39 -0400 Subject: [PATCH 61/89] Removed 'operation_id' from 'current_account_proxies' table #22 --- db/hafbe_app.sql | 237 +++++++++++++++++++++++------------------------ 1 file changed, 117 insertions(+), 120 deletions(-) diff --git a/db/hafbe_app.sql b/db/hafbe_app.sql index 3c1cc83..767e9c3 100644 --- a/db/hafbe_app.sql +++ b/db/hafbe_app.sql @@ -58,13 +58,10 @@ BEGIN CREATE TABLE IF NOT EXISTS hafbe_app.current_account_proxies ( account_id INT NOT NULL, proxy_id INT NOT NULL, - operation_id BIGINT NOT NULL, CONSTRAINT pk_current_account_proxies PRIMARY KEY (account_id) ) INHERITS (hive.hafbe_app); - CREATE INDEX IF NOT EXISTS current_account_proxies_proxy_id_operation_id ON hafbe_app.current_account_proxies USING btree (proxy_id, operation_id); - CREATE TABLE IF NOT EXISTS hafbe_app.recursive_account_proxies ( proxy_id INT NOT NULL, account_id INT NOT NULL, @@ -180,33 +177,33 @@ BEGIN WITH vote_or_proxy_op AS ( SELECT (body::JSON)->'value' AS value, - timestamp, op_type_id, id - FROM hive.hafbe_app_operations_view + timestamp, op_type_id, id AS operation_id + FROM hive.operations_view WHERE op_type_id = ANY('{12,91}') AND block_num BETWEEN _from AND _to ), select_votes_ops AS ( - SELECT hav_w.witness_id, hav_v.voter_id, approve, timestamp + SELECT hav_w.witness_id, hav_v.voter_id, approve, timestamp, operation_id FROM ( SELECT value->>'witness' AS witness, value->>'account' AS voter, (value->>'approve')::BOOLEAN AS approve, - timestamp, id + timestamp, operation_id FROM vote_or_proxy_op WHERE op_type_id = 12 ) vote_op JOIN LATERAL ( SELECT id AS witness_id - FROM hive.hafbe_app_accounts_view + FROM hive.accounts_view WHERE name = vote_op.witness ) hav_w ON TRUE JOIN LATERAL ( SELECT id AS voter_id - FROM hive.hafbe_app_accounts_view + FROM hive.accounts_view WHERE name = vote_op.voter ) hav_v ON TRUE - ORDER BY id DESC + ORDER BY operation_id DESC ), insert_votes_history AS ( @@ -215,19 +212,33 @@ BEGIN FROM select_votes_ops ), + select_latest_vote_ops AS ( + SELECT witness_id, voter_id, approve, timestamp + FROM ( + SELECT + ROW_NUMBER() OVER (PARTITION BY witness_id, voter_id ORDER BY operation_id DESC) AS row_n, + witness_id, voter_id, approve, timestamp + FROM select_votes_ops + ) row_count + WHERE row_n = 1 + ), + insert_current_votes AS ( INSERT INTO hafbe_app.current_witness_votes (witness_id, voter_id, timestamp) - SELECT DISTINCT ON (witness_id, voter_id) - witness_id, voter_id, timestamp - FROM select_votes_ops + SELECT witness_id, voter_id, timestamp + FROM select_latest_vote_ops WHERE approve IS TRUE ON CONFLICT ON CONSTRAINT pk_current_witness_votes DO UPDATE SET timestamp = EXCLUDED.timestamp ), delete_current_votes AS ( - DELETE FROM hafbe_app.current_witness_votes cwv USING select_votes_ops svo - WHERE svo.approve IS FALSE AND cwv.witness_id = svo.witness_id AND cwv.voter_id = svo.voter_id + DELETE FROM hafbe_app.current_witness_votes cwv USING ( + SELECT witness_id, voter_id + FROM select_latest_vote_ops + WHERE approve IS FALSE + ) svo + WHERE cwv.witness_id = svo.witness_id AND cwv.voter_id = svo.voter_id ), insert_witnesses_from_votes AS ( @@ -238,27 +249,27 @@ BEGIN ), select_proxy_ops AS ( - SELECT hav_a.account_id, hav_p.proxy_id, proxy, timestamp, id AS operation_id + SELECT hav_a.account_id, hav_p.proxy_id, proxy, timestamp, operation_id FROM ( SELECT value->>'account' AS account, value->>'proxy' AS proxy_account, CASE WHEN (value->>'clear')::BOOLEAN IS TRUE THEN FALSE ELSE TRUE END AS proxy, - timestamp, id + timestamp, operation_id FROM vote_or_proxy_op WHERE op_type_id = 91 ) proxy_op JOIN LATERAL ( SELECT id AS account_id - FROM hive.hafbe_app_accounts_view + FROM hive.accounts_view WHERE name = proxy_op.account ) hav_a ON TRUE JOIN LATERAL ( SELECT id AS proxy_id - FROM hive.hafbe_app_accounts_view + FROM hive.accounts_view WHERE name = proxy_op.proxy_account ) hav_p ON TRUE - ORDER BY proxy_op.id DESC + ORDER BY operation_id DESC ), insert_proxy_history AS ( @@ -267,150 +278,136 @@ BEGIN FROM select_proxy_ops ), + select_latest_proxy_ops AS ( + SELECT account_id, proxy_id, proxy, timestamp + FROM ( + SELECT + ROW_NUMBER() OVER (PARTITION BY account_id, proxy_id ORDER BY operation_id DESC) AS row_n, + account_id, proxy_id, proxy, timestamp + FROM select_proxy_ops + ) row_count + WHERE row_n = 1 + ), + insert_current_proxies AS ( - INSERT INTO hafbe_app.current_account_proxies AS cap (account_id, proxy_id, operation_id) - SELECT DISTINCT ON (account_id) - account_id, proxy_id, operation_id - FROM select_proxy_ops + INSERT INTO hafbe_app.current_account_proxies AS cap (account_id, proxy_id) + SELECT account_id, proxy_id + FROM select_latest_proxy_ops + WHERE proxy IS TRUE + ON CONFLICT ON CONSTRAINT pk_current_account_proxies DO UPDATE SET proxy_id = EXCLUDED.proxy_id - RETURNING cap.account_id, cap.proxy_id, cap.operation_id + RETURNING cap.account_id, cap.proxy_id ), delete_current_proxies AS ( - DELETE FROM hafbe_app.current_account_proxies cap USING select_proxy_ops spo - WHERE spo.proxy IS FALSE AND cap.account_id = spo.account_id - RETURNING cap.account_id, cap.proxy_id, cap.operation_id + DELETE FROM hafbe_app.current_account_proxies cap USING ( + SELECT account_id + FROM select_latest_proxy_ops + WHERE proxy IS FALSE + ) spo + WHERE cap.account_id = spo.account_id + RETURNING cap.account_id, cap.proxy_id ), - proxies1 AS ( + unproxies1 AS ( SELECT prox1.proxy_id AS top_proxy_id, - prox1.account_id, prox1.operation_id - FROM insert_current_proxies prox1 + prox1.account_id + FROM delete_current_proxies prox1 ), - proxies2 AS ( - SELECT prox1.top_proxy_id, prox2.account_id, prox2.operation_id - FROM proxies1 prox1 - JOIN LATERAL ( - SELECT proxy_id, account_id, operation_id - FROM hafbe_app.current_account_proxies - WHERE operation_id < prox1.operation_id AND proxy_id = prox1.account_id - ) prox2 ON TRUE + unproxies2 AS ( + SELECT prox1.top_proxy_id, prox2.account_id + FROM unproxies1 prox1 + JOIN hafbe_app.current_account_proxies prox2 ON prox2.proxy_id = prox1.account_id ), - proxies3 AS ( - SELECT prox2.top_proxy_id, prox3.account_id, prox3.operation_id - FROM proxies2 prox2 - JOIN LATERAL ( - SELECT proxy_id, account_id, operation_id - FROM hafbe_app.current_account_proxies - WHERE operation_id < prox2.operation_id AND proxy_id = prox2.account_id - ) prox3 ON TRUE + unproxies3 AS ( + SELECT prox2.top_proxy_id, prox3.account_id + FROM unproxies2 prox2 + JOIN hafbe_app.current_account_proxies prox3 ON prox3.proxy_id = prox2.account_id ), - proxies4 AS ( - SELECT prox3.top_proxy_id, prox4.account_id, prox4.operation_id - FROM proxies3 prox3 - JOIN LATERAL ( - SELECT proxy_id, account_id, operation_id - FROM hafbe_app.current_account_proxies - WHERE operation_id < prox3.operation_id AND proxy_id = prox3.account_id - ) prox4 ON TRUE + unproxies4 AS ( + SELECT prox3.top_proxy_id, prox4.account_id + FROM unproxies3 prox3 + JOIN hafbe_app.current_account_proxies prox4 ON prox4.proxy_id = prox3.account_id ), - proxies5 AS ( + unproxies5 AS ( SELECT prox4.top_proxy_id, prox5.account_id - FROM proxies4 prox4 - JOIN LATERAL ( - SELECT proxy_id, account_id, operation_id - FROM hafbe_app.current_account_proxies - WHERE operation_id < prox4.operation_id AND proxy_id = prox4.account_id - ) prox5 ON TRUE + FROM unproxies4 prox4 + JOIN hafbe_app.current_account_proxies prox5 ON prox5.proxy_id = prox4.account_id ), - insert_recursive_account_proxies AS ( - INSERT INTO hafbe_app.recursive_account_proxies (proxy_id, account_id) - SELECT top_proxy_id, account_id FROM proxies1 - UNION - SELECT top_proxy_id, account_id FROM proxies2 - UNION - SELECT top_proxy_id, account_id FROM proxies3 - UNION - SELECT top_proxy_id, account_id FROM proxies4 - UNION - SELECT top_proxy_id, account_id FROM proxies5 - ON CONFLICT ON CONSTRAINT pk_recursive_account_proxies DO NOTHING + delete_recursive_account_unproxies AS ( + DELETE FROM hafbe_app.recursive_account_proxies rap USING ( + SELECT top_proxy_id, account_id FROM unproxies1 + UNION + SELECT top_proxy_id, account_id FROM unproxies2 + UNION + SELECT top_proxy_id, account_id FROM unproxies3 + UNION + SELECT top_proxy_id, account_id FROM unproxies4 + UNION + SELECT top_proxy_id, account_id FROM unproxies5 + ) raup + WHERE rap.proxy_id = raup.top_proxy_id AND rap.account_id = raup.account_id ), - unproxies1 AS ( + proxies1 AS ( SELECT prox1.proxy_id AS top_proxy_id, - prox1.account_id, prox1.operation_id - FROM delete_current_proxies prox1 + prox1.account_id + FROM insert_current_proxies prox1 ), - unproxies2 AS ( - SELECT prox1.top_proxy_id, prox2.account_id, prox2.operation_id - FROM unproxies1 prox1 - JOIN LATERAL ( - SELECT proxy_id, account_id, operation_id - FROM hafbe_app.current_account_proxies - WHERE operation_id < prox1.operation_id AND proxy_id = prox1.account_id - ) prox2 ON TRUE + proxies2 AS ( + SELECT prox1.top_proxy_id, prox2.account_id + FROM proxies1 prox1 + JOIN hafbe_app.current_account_proxies prox2 ON prox2.proxy_id = prox1.account_id ), - unproxies3 AS ( - SELECT prox2.top_proxy_id, prox3.account_id, prox3.operation_id - FROM unproxies2 prox2 - JOIN LATERAL ( - SELECT proxy_id, account_id, operation_id - FROM hafbe_app.current_account_proxies - WHERE operation_id < prox2.operation_id AND proxy_id = prox2.account_id - ) prox3 ON TRUE + proxies3 AS ( + SELECT prox2.top_proxy_id, prox3.account_id + FROM proxies2 prox2 + JOIN hafbe_app.current_account_proxies prox3 ON prox3.proxy_id = prox2.account_id ), - unproxies4 AS ( - SELECT prox3.top_proxy_id, prox4.account_id, prox4.operation_id - FROM unproxies3 prox3 - JOIN LATERAL ( - SELECT proxy_id, account_id, operation_id - FROM hafbe_app.current_account_proxies - WHERE operation_id < prox3.operation_id AND proxy_id = prox3.account_id - ) prox4 ON TRUE + proxies4 AS ( + SELECT prox3.top_proxy_id, prox4.account_id + FROM proxies3 prox3 + JOIN hafbe_app.current_account_proxies prox4 ON prox4.proxy_id = prox3.account_id ), - unproxies5 AS ( + proxies5 AS ( SELECT prox4.top_proxy_id, prox5.account_id - FROM unproxies4 prox4 - JOIN LATERAL ( - SELECT proxy_id, account_id, operation_id - FROM hafbe_app.current_account_proxies - WHERE operation_id < prox4.operation_id AND proxy_id = prox4.account_id - ) prox5 ON TRUE - ), + FROM proxies4 prox4 + JOIN hafbe_app.current_account_proxies prox5 ON prox5.proxy_id = prox4.account_id + ) - select_recursive_account_unproxies AS ( - SELECT top_proxy_id, account_id FROM unproxies1 + INSERT INTO hafbe_app.recursive_account_proxies (proxy_id, account_id) + SELECT top_proxy_id, account_id + FROM ( + SELECT top_proxy_id, account_id FROM proxies1 UNION - SELECT top_proxy_id, account_id FROM unproxies2 + SELECT top_proxy_id, account_id FROM proxies2 UNION - SELECT top_proxy_id, account_id FROM unproxies3 + SELECT top_proxy_id, account_id FROM proxies3 UNION - SELECT top_proxy_id, account_id FROM unproxies4 + SELECT top_proxy_id, account_id FROM proxies4 UNION - SELECT top_proxy_id, account_id FROM unproxies5 - ) - - DELETE FROM hafbe_app.recursive_account_proxies rap USING select_recursive_account_unproxies raup - WHERE rap.proxy_id = raup.top_proxy_id AND rap.account_id = raup.account_id; + SELECT top_proxy_id, account_id FROM proxies5 + ) rap + WHERE top_proxy_id != account_id + ON CONFLICT ON CONSTRAINT pk_recursive_account_proxies DO NOTHING; -- add new witnesses per block range INSERT INTO hafbe_app.current_witnesses (witness_id, url, price_feed, bias, feed_age, block_size, signing_key, version) SELECT DISTINCT ON (account_id) account_id, NULL, NULL, NULL, NULL, NULL, NULL, '1.25.0' - FROM hive.hafbe_app_account_operations_view + FROM hive.account_operations_view WHERE op_type_id = ANY('{42,11,7}') AND block_num BETWEEN _from AND _to ON CONFLICT ON CONSTRAINT pk_current_witnesses DO NOTHING; -- GitLab From 167da69e978fefd3d2d0a5aab4b0e2927ea7d82f Mon Sep 17 00:00:00 2001 From: kristupas Date: Mon, 24 Oct 2022 22:16:24 -0400 Subject: [PATCH 62/89] Replaced LOOP with window function in witness props processing #22 --- db/hafbe_app.sql | 221 ++++++++++++++++++++++++++++++----------------- 1 file changed, 143 insertions(+), 78 deletions(-) diff --git a/db/hafbe_app.sql b/db/hafbe_app.sql index 767e9c3..70160c6 100644 --- a/db/hafbe_app.sql +++ b/db/hafbe_app.sql @@ -178,7 +178,7 @@ BEGIN SELECT (body::JSON)->'value' AS value, timestamp, op_type_id, id AS operation_id - FROM hive.operations_view + FROM hive.hafbe_app_operations_view WHERE op_type_id = ANY('{12,91}') AND block_num BETWEEN _from AND _to ), @@ -195,12 +195,12 @@ BEGIN ) vote_op JOIN LATERAL ( SELECT id AS witness_id - FROM hive.accounts_view + FROM hive.hafbe_app_accounts_view WHERE name = vote_op.witness ) hav_w ON TRUE JOIN LATERAL ( SELECT id AS voter_id - FROM hive.accounts_view + FROM hive.hafbe_app_accounts_view WHERE name = vote_op.voter ) hav_v ON TRUE ORDER BY operation_id DESC @@ -261,12 +261,12 @@ BEGIN ) proxy_op JOIN LATERAL ( SELECT id AS account_id - FROM hive.accounts_view + FROM hive.hafbe_app_accounts_view WHERE name = proxy_op.account ) hav_a ON TRUE JOIN LATERAL ( SELECT id AS proxy_id - FROM hive.accounts_view + FROM hive.hafbe_app_accounts_view WHERE name = proxy_op.proxy_account ) hav_p ON TRUE ORDER BY operation_id DESC @@ -407,82 +407,147 @@ BEGIN INSERT INTO hafbe_app.current_witnesses (witness_id, url, price_feed, bias, feed_age, block_size, signing_key, version) SELECT DISTINCT ON (account_id) account_id, NULL, NULL, NULL, NULL, NULL, NULL, '1.25.0' - FROM hive.account_operations_view + FROM hive.hafbe_app_account_operations_view WHERE op_type_id = ANY('{42,11,7}') AND block_num BETWEEN _from AND _to ON CONFLICT ON CONSTRAINT pk_current_witnesses DO NOTHING; - -- processes witness properties per block range - FOR __prop_op IN - SELECT - witness_id, - (hov.body::JSON)->'value' AS value, - hov.op_type_id, - hov.timestamp - FROM hafbe_app.current_witnesses cw - JOIN ( - SELECT account_id, operation_id, block_num - FROM hive.hafbe_app_account_operations_view - WHERE op_type_id = ANY('{42,30,14,11,7}'::INT[]) AND block_num BETWEEN _from AND _to - ORDER BY operation_id ASC - ) haov ON haov.account_id = cw.witness_id - JOIN ( - SELECT body, op_type_id, timestamp, id, block_num - FROM hive.hafbe_app_operations_view - ) hov ON hov.id = haov.operation_id AND hov.block_num = haov.block_num - - LOOP - -- parse witness url 42,11 - SELECT __prop_op.value->>'url' INTO __prop_value; - - IF __prop_value IS NULL AND __prop_op.op_type_id = 42 THEN - SELECT prop_value FROM hive.extract_set_witness_properties(__prop_op.value->>'props') WHERE prop_name = 'url' INTO __prop_value; - END IF; - - IF __prop_value IS NOT NULL THEN - UPDATE hafbe_app.current_witnesses cw SET url = __prop_value WHERE witness_id = __prop_op.witness_id; - END IF; - - -- parse witness feed_data 42,7 - SELECT __prop_op.value->'exchange_rate' INTO __prop_value; - - IF __prop_value IS NULL AND __prop_op.op_type_id = 42 THEN - SELECT prop_value FROM hive.extract_set_witness_properties(__prop_op.value->>'props') WHERE prop_name = 'hbd_exchange_rate' INTO __prop_value; - END IF; - - IF __prop_value IS NOT NULL THEN - UPDATE hafbe_app.current_witnesses cw SET - price_feed = ((__prop_value::JSON)->'base'->>'amount')::NUMERIC / ((__prop_value::JSON)->'quote'->>'amount')::NUMERIC, - bias = (((__prop_value::JSON)->'quote'->>'amount')::NUMERIC - 1000)::NUMERIC, - feed_age = (NOW() - __prop_op.timestamp)::INTERVAL - WHERE witness_id = __prop_op.witness_id; - END IF; - - -- parse witness block_size 42,30,14,11 - SELECT __prop_op.value->'props'->>'maximum_block_size' INTO __prop_value; - - IF __prop_value IS NULL AND __prop_op.op_type_id = 42 THEN - SELECT prop_value FROM hive.extract_set_witness_properties(__prop_op.value->>'props') WHERE prop_name = 'maximum_block_size' INTO __prop_value; - END IF; - - IF __prop_value IS NOT NULL THEN - UPDATE hafbe_app.current_witnesses cw SET block_size = __prop_value::INT WHERE witness_id = __prop_op.witness_id; - END IF; - - -- parse witness signing_key 42,11 - SELECT __prop_op.value->>'block_signing_key' INTO __prop_value; - - IF __prop_value IS NULL AND __prop_op.op_type_id = 42 THEN - SELECT prop_value FROM hive.extract_set_witness_properties(__prop_op.value->>'props') WHERE prop_name = 'new_signing_key' INTO __prop_value; - END IF; - - IF __prop_value IS NULL AND __prop_op.op_type_id = 42 THEN - SELECT prop_value FROM hive.extract_set_witness_properties(__prop_op.value->>'props') WHERE prop_name = 'key' INTO __prop_value; - END IF; - - IF __prop_value IS NOT NULL THEN - UPDATE hafbe_app.current_witnesses cw SET signing_key = __prop_value WHERE witness_id = __prop_op.witness_id; - END IF; - END LOOP; + SELECT INTO __prop_op + cw.witness_id, + (hov.body::JSON)->'value' AS value, + hov.op_type_id, hov.timestamp, haov.operation_id + FROM hafbe_app.current_witnesses cw + JOIN ( + SELECT account_id, operation_id, block_num + FROM hive.hafbe_app_account_operations_view + WHERE op_type_id = ANY('{42,30,14,11,7}') AND block_num BETWEEN _from AND _to + ) haov ON haov.account_id = cw.witness_id + JOIN ( + SELECT body, op_type_id, timestamp, id, block_num + FROM hive.hafbe_app_operations_view + ) hov ON hov.id = haov.operation_id AND hov.block_num = haov.block_num; + + UPDATE hafbe_app.current_witnesses cw SET url = res.prop_value FROM ( + SELECT prop_value, witness_id + FROM ( + SELECT + prop_value, witness_id, operation_id, + ROW_NUMBER() OVER (PARTITION BY witness_id ORDER BY operation_id DESC) AS row_n + FROM ( + SELECT + __prop_op.value->>'url' AS prop_value, + __prop_op.operation_id, __prop_op.witness_id + WHERE __prop_op.op_type_id = 11 + + UNION + + SELECT + trim(both '"' FROM prop_value::TEXT), + __prop_op.operation_id, __prop_op.witness_id + FROM hive.extract_set_witness_properties(__prop_op.value->>'props') + WHERE prop_name = 'url' AND __prop_op.op_type_id = 42 + ) parsed + WHERE prop_value IS NOT NULL + ) row_count + WHERE row_n = 1 + ) res + WHERE cw.witness_id = res.witness_id; + + UPDATE hafbe_app.current_witnesses cw SET + price_feed = (res.prop_value->'base'->>'amount')::NUMERIC / (res.prop_value->'quote'->>'amount')::NUMERIC, + bias = ((res.prop_value->'quote'->>'amount')::NUMERIC - 1000)::NUMERIC, + feed_age = (NOW() - res.timestamp)::INTERVAL + FROM ( + SELECT prop_value::JSON, witness_id, timestamp + FROM ( + SELECT + prop_value, witness_id, operation_id, timestamp, + ROW_NUMBER() OVER (PARTITION BY witness_id ORDER BY operation_id DESC) AS row_n + FROM ( + SELECT + __prop_op.value->>'exchange_rate' AS prop_value, + __prop_op.operation_id, __prop_op.witness_id, __prop_op.timestamp + WHERE __prop_op.op_type_id = 7 + + UNION + + SELECT + prop_value::TEXT, + __prop_op.operation_id, __prop_op.witness_id, __prop_op.timestamp + FROM hive.extract_set_witness_properties(__prop_op.value->>'props') + WHERE prop_name = 'hbd_exchange_rate' AND __prop_op.op_type_id = 42 + ) parsed + WHERE prop_value IS NOT NULL + ) row_count + WHERE row_n = 1 + ) res + WHERE cw.witness_id = res.witness_id; + + UPDATE hafbe_app.current_witnesses cw SET block_size = res.prop_value FROM ( + SELECT prop_value::INT, witness_id + FROM ( + SELECT + prop_value, witness_id, operation_id, + ROW_NUMBER() OVER (PARTITION BY witness_id ORDER BY operation_id DESC) AS row_n + FROM ( + SELECT + __prop_op.value->'props'->>'maximum_block_size' AS prop_value, + __prop_op.operation_id, __prop_op.witness_id + WHERE __prop_op.op_type_id = ANY('{30,14,11}') + + UNION + + SELECT + prop_value::TEXT, + __prop_op.operation_id, __prop_op.witness_id + FROM hive.extract_set_witness_properties(__prop_op.value->>'props') + WHERE prop_name = 'maximum_block_size' AND __prop_op.op_type_id = 42 + ) parsed + WHERE prop_value IS NOT NULL + ) row_count + WHERE row_n = 1 + ) res + WHERE cw.witness_id = res.witness_id; + + UPDATE hafbe_app.current_witnesses cw SET signing_key = res.prop_value FROM ( + SELECT prop_value, witness_id + FROM ( + SELECT + prop_value, witness_id, operation_id, + ROW_NUMBER() OVER (PARTITION BY witness_id ORDER BY operation_id DESC) AS row_n + FROM ( + SELECT + __prop_op.value->>'block_signing_key' AS prop_value, + __prop_op.operation_id, __prop_op.witness_id + WHERE __prop_op.op_type_id = 11 + + UNION + + SELECT + -- witness_set_properties_operation may contain old and new signing keys + trim(both '"' FROM + (CASE WHEN ex_res1.prop_value IS NULL THEN ex_res2.prop_value ELSE ex_res1.prop_value END)::TEXT + ), + operation_id, witness_id + FROM ( + SELECT __prop_op.value, __prop_op.operation_id, __prop_op.witness_id + ) encoded_op + LEFT JOIN LATERAL ( + SELECT prop_value + FROM hive.extract_set_witness_properties(value->>'props') + WHERE prop_name = 'new_signing_key' + ) ex_res1 ON TRUE + JOIN LATERAL ( + SELECT prop_value + FROM hive.extract_set_witness_properties(value->>'props') + WHERE prop_name = 'key' + ) ex_res2 ON ex_res1.prop_value IS NULL + WHERE __prop_op.op_type_id = 42 + ) parsed + WHERE prop_value IS NOT NULL + ) row_count + WHERE row_n = 1 + ) res + WHERE cw.witness_id = res.witness_id; INSERT INTO hafbe_app.account_operation_cache (account_id, op_type_id) SELECT account_id, op_type_id -- GitLab From 69526d98dbd13cbe2aa47fc99d41cf40cbff0f20 Mon Sep 17 00:00:00 2001 From: kristupas Date: Thu, 27 Oct 2022 00:39:48 +0000 Subject: [PATCH 63/89] Updated block processing queries to avoid creating new indexes in 'hive' schema #22 --- db/hafbe_app.sql | 53 ++++++++++++++++++++++++--------------------- db/indexes.sql | 23 ++------------------ run.sh | 2 ++ scripts/setup_db.sh | 2 ++ 4 files changed, 34 insertions(+), 46 deletions(-) diff --git a/db/hafbe_app.sql b/db/hafbe_app.sql index 70160c6..350cecb 100644 --- a/db/hafbe_app.sql +++ b/db/hafbe_app.sql @@ -91,9 +91,9 @@ BEGIN SELECT array_agg(hot.id) FROM hive.operation_types hot JOIN ( - SELECT hive.get_balance_impacting_operations() AS name - ) bio - ON hot.name = bio.name; + SELECT get_balance_impacting_operations AS name + FROM hive.get_balance_impacting_operations() + ) bio ON bio.name = hot.name::TEXT; CREATE TABLE IF NOT EXISTS hafbe_app.account_vests ( account_id INT NOT NULL, @@ -179,7 +179,7 @@ BEGIN (body::JSON)->'value' AS value, timestamp, op_type_id, id AS operation_id FROM hive.hafbe_app_operations_view - WHERE op_type_id = ANY('{12,91}') AND block_num BETWEEN _from AND _to + WHERE op_type_id = ANY('{12,91}') AND block_num BETWEEN _from AND _to ), select_votes_ops AS ( @@ -405,26 +405,30 @@ BEGIN -- add new witnesses per block range INSERT INTO hafbe_app.current_witnesses (witness_id, url, price_feed, bias, feed_age, block_size, signing_key, version) - SELECT DISTINCT ON (account_id) - account_id, NULL, NULL, NULL, NULL, NULL, NULL, '1.25.0' - FROM hive.hafbe_app_account_operations_view - WHERE op_type_id = ANY('{42,11,7}') AND block_num BETWEEN _from AND _to + SELECT DISTINCT ON (haov.account_id) + haov.account_id, NULL, NULL, NULL, NULL, NULL, NULL, '1.25.0' + FROM hive.hafbe_app_account_operations_view haov + JOIN ( + SELECT id + FROM hive.hafbe_app_operations_view + WHERE op_type_id = ANY('{42,11,7}') AND block_num BETWEEN _from AND _to + ) hov ON hov.id = haov.operation_id ON CONFLICT ON CONSTRAINT pk_current_witnesses DO NOTHING; SELECT INTO __prop_op cw.witness_id, (hov.body::JSON)->'value' AS value, hov.op_type_id, hov.timestamp, haov.operation_id - FROM hafbe_app.current_witnesses cw - JOIN ( - SELECT account_id, operation_id, block_num - FROM hive.hafbe_app_account_operations_view - WHERE op_type_id = ANY('{42,30,14,11,7}') AND block_num BETWEEN _from AND _to - ) haov ON haov.account_id = cw.witness_id + FROM hive.hafbe_app_account_operations_view haov JOIN ( SELECT body, op_type_id, timestamp, id, block_num FROM hive.hafbe_app_operations_view - ) hov ON hov.id = haov.operation_id AND hov.block_num = haov.block_num; + WHERE op_type_id = ANY('{42,30,14,11,7}') AND block_num BETWEEN _from AND _to + ) hov ON hov.id = haov.operation_id AND hov.block_num = haov.block_num + JOIN ( + SELECT witness_id + FROM hafbe_app.current_witnesses + ) cw ON cw.witness_id = haov.account_id; UPDATE hafbe_app.current_witnesses cw SET url = res.prop_value FROM ( SELECT prop_value, witness_id @@ -536,7 +540,7 @@ BEGIN FROM hive.extract_set_witness_properties(value->>'props') WHERE prop_name = 'new_signing_key' ) ex_res1 ON TRUE - JOIN LATERAL ( + LEFT JOIN LATERAL ( SELECT prop_value FROM hive.extract_set_witness_properties(value->>'props') WHERE prop_name = 'key' @@ -550,9 +554,14 @@ BEGIN WHERE cw.witness_id = res.witness_id; INSERT INTO hafbe_app.account_operation_cache (account_id, op_type_id) - SELECT account_id, op_type_id - FROM hive.hafbe_app_account_operations_view - WHERE block_num BETWEEN _from AND _to + SELECT DISTINCT ON (haov.account_id, haov.op_type_id) + haov.account_id, haov.op_type_id + FROM hive.hafbe_app_account_operations_view haov + JOIN ( + SELECT id + FROM hive.hafbe_app_operations_view + WHERE block_num BETWEEN _from AND _to + ) hov ON hov.id = haov.operation_id ON CONFLICT ON CONSTRAINT pk_account_operation_cache DO NOTHING; -- get impacted vests balance for block range and update account_vests @@ -578,12 +587,6 @@ BEGIN ON CONFLICT ON CONSTRAINT pk_account_vests DO UPDATE SET vests = hafbe_app.account_vests.vests + EXCLUDED.vests; END LOOP; - - INSERT INTO hafbe_app.account_operation_cache (account_id, op_type_id) - SELECT account_id, op_type_id - FROM hive.hafbe_app_account_operations_view - WHERE block_num BETWEEN _from AND _to - ON CONFLICT ON CONSTRAINT pk_account_operation_cache DO NOTHING; END $$ SET from_collapse_limit = 16 diff --git a/db/indexes.sql b/db/indexes.sql index cf36d80..f7b1bda 100644 --- a/db/indexes.sql +++ b/db/indexes.sql @@ -1,4 +1,3 @@ --- TODO: review if all indexes necessary DROP SCHEMA IF EXISTS hafbe_indexes CASCADE; CREATE SCHEMA IF NOT EXISTS hafbe_indexes AUTHORIZATION hafbe_owner; @@ -27,26 +26,8 @@ BEGIN CREATE UNIQUE INDEX IF NOT EXISTS uq_hive_blocks_reversible_hash ON hive.blocks_reversible USING btree (hash, fork_id); CREATE UNIQUE INDEX IF NOT EXISTS uq_hive_blocks_hash ON hive.blocks USING btree (hash); - CREATE INDEX IF NOT EXISTS hive_operations_reversible_timestamp_id ON hive.operations_reversible USING btree (timestamp, id, fork_id); - CREATE INDEX IF NOT EXISTS hive_operations_timestamp_id ON hive.operations USING btree (timestamp, id); - - CREATE INDEX IF NOT EXISTS hive_operations_reversible_block_num_op_type_id ON hive.operations_reversible USING btree (block_num, op_type_id, fork_id); - CREATE INDEX IF NOT EXISTS hive_operations_block_num_op_type_id ON hive.operations USING btree (block_num, op_type_id); - - CREATE INDEX IF NOT EXISTS hive_operations_reversible_timestamp ON hive.operations_reversible USING btree (timestamp, fork_id); - CREATE INDEX IF NOT EXISTS hive_operations_timestamp ON hive.operations USING btree (timestamp); - - CREATE UNIQUE INDEX IF NOT EXISTS hive_account_operations_reversible_account_id_op_type_id_operation_id ON hive.account_operations_reversible USING btree (account_id, op_type_id, operation_id, fork_id); - CREATE UNIQUE INDEX IF NOT EXISTS hive_account_operations_account_id_op_type_id_operation_id ON hive.account_operations USING btree (account_id, op_type_id, operation_id); - - CREATE INDEX IF NOT EXISTS hive_account_operations_reversible_block_num ON hive.account_operations_reversible USING btree (block_num, fork_id); - CREATE INDEX IF NOT EXISTS hive_account_operations_block_num ON hive.account_operations USING btree (block_num); - - CREATE INDEX IF NOT EXISTS hive_account_operations_reversible_block_num_op_type_id ON hive.account_operations_reversible USING btree (block_num, op_type_id, fork_id); - CREATE INDEX IF NOT EXISTS hive_account_operations_block_num_op_type_id ON hive.account_operations USING btree (block_num, op_type_id); - - CREATE INDEX IF NOT EXISTS hive_account_operations_reversible_operation_id_block_num ON hive.account_operations_reversible USING btree (operation_id, block_num, fork_id); - CREATE INDEX IF NOT EXISTS hive_account_operations_operation_id_block_num ON hive.account_operations USING btree (operation_id, block_num); + CREATE UNIQUE INDEX IF NOT EXISTS uq_hive_blocks_reversible_created_at ON hive.blocks_reversible USING btree (created_at, fork_id); + CREATE UNIQUE INDEX IF NOT EXISTS uq_hive_blocks_created_at ON hive.blocks USING btree (created_at); END $$ ; \ No newline at end of file diff --git a/run.sh b/run.sh index d5579b2..f3739a6 100755 --- a/run.sh +++ b/run.sh @@ -43,6 +43,8 @@ DB_NAME=haf_block_log owner_role=hafbe_owner admin_role=haf_admin +sudo echo + if [ "$1" = "start" ]; then start_webserver $2 elif [ "$1" = "setup" ]; then diff --git a/scripts/setup_db.sh b/scripts/setup_db.sh index f2bc96b..331c9aa 100755 --- a/scripts/setup_db.sh +++ b/scripts/setup_db.sh @@ -129,6 +129,8 @@ owner_role=hafbe_owner postgrest_dir=$PWD/api db_dir=$PWD/db +sudo echo + if [ "$1" = "all" ]; then setup_owner setup_apps -- GitLab From 6a01b0a3acd9b4cad8a6af09a0bea265298c2ce6 Mon Sep 17 00:00:00 2001 From: kristupas Date: Thu, 27 Oct 2022 18:57:32 +0000 Subject: [PATCH 64/89] Replaced JOINs of 'account_operations' with 'get_impacted_accounts()' #22 --- db/hafbe_app.sql | 95 +++++++++++++++++++++++------------------------- 1 file changed, 45 insertions(+), 50 deletions(-) diff --git a/db/hafbe_app.sql b/db/hafbe_app.sql index 350cecb..f7f033a 100644 --- a/db/hafbe_app.sql +++ b/db/hafbe_app.sql @@ -170,10 +170,10 @@ AS $$ DECLARE __prop_op RECORD; - __prop_value TEXT; __balance_change RECORD; __balance_impacting_ops_ids INT[] = (SELECT op_type_ids_arr FROM hafbe_app.balance_impacting_op_ids); BEGIN + -- process vote and proxy ops, fill tables WITH vote_or_proxy_op AS ( SELECT (body::JSON)->'value' AS value, @@ -183,7 +183,7 @@ BEGIN ), select_votes_ops AS ( - SELECT hav_w.witness_id, hav_v.voter_id, approve, timestamp, operation_id + SELECT hav_w.id AS witness_id, hav_v.id AS voter_id, approve, timestamp, operation_id FROM ( SELECT value->>'witness' AS witness, @@ -193,16 +193,8 @@ BEGIN FROM vote_or_proxy_op WHERE op_type_id = 12 ) vote_op - JOIN LATERAL ( - SELECT id AS witness_id - FROM hive.hafbe_app_accounts_view - WHERE name = vote_op.witness - ) hav_w ON TRUE - JOIN LATERAL ( - SELECT id AS voter_id - FROM hive.hafbe_app_accounts_view - WHERE name = vote_op.voter - ) hav_v ON TRUE + JOIN hive.hafbe_app_accounts_view hav_w ON hav_w.name = vote_op.witness + JOIN hive.hafbe_app_accounts_view hav_v ON hav_v.name = vote_op.voter ORDER BY operation_id DESC ), @@ -249,7 +241,7 @@ BEGIN ), select_proxy_ops AS ( - SELECT hav_a.account_id, hav_p.proxy_id, proxy, timestamp, operation_id + SELECT hav_a.id AS account_id, hav_p.id AS proxy_id, proxy, timestamp, operation_id FROM ( SELECT value->>'account' AS account, @@ -259,16 +251,8 @@ BEGIN FROM vote_or_proxy_op WHERE op_type_id = 91 ) proxy_op - JOIN LATERAL ( - SELECT id AS account_id - FROM hive.hafbe_app_accounts_view - WHERE name = proxy_op.account - ) hav_a ON TRUE - JOIN LATERAL ( - SELECT id AS proxy_id - FROM hive.hafbe_app_accounts_view - WHERE name = proxy_op.proxy_account - ) hav_p ON TRUE + JOIN hive.hafbe_app_accounts_view hav_a ON hav_a.name = proxy_op.account + JOIN hive.hafbe_app_accounts_view hav_p ON hav_p.name = proxy_op.proxy_account ORDER BY operation_id DESC ), @@ -404,31 +388,35 @@ BEGIN ON CONFLICT ON CONSTRAINT pk_recursive_account_proxies DO NOTHING; -- add new witnesses per block range + WITH limited_set AS ( + SELECT DISTINCT bia.name + FROM hive.hafbe_app_operations_view hov + JOIN LATERAL ( + SELECT get_impacted_accounts AS name + FROM hive.get_impacted_accounts(hov.body) + ) bia ON TRUE + WHERE hov.op_type_id = ANY('{42,11,7}') AND hov.block_num BETWEEN _from AND _to + ) + INSERT INTO hafbe_app.current_witnesses (witness_id, url, price_feed, bias, feed_age, block_size, signing_key, version) - SELECT DISTINCT ON (haov.account_id) - haov.account_id, NULL, NULL, NULL, NULL, NULL, NULL, '1.25.0' - FROM hive.hafbe_app_account_operations_view haov - JOIN ( - SELECT id - FROM hive.hafbe_app_operations_view - WHERE op_type_id = ANY('{42,11,7}') AND block_num BETWEEN _from AND _to - ) hov ON hov.id = haov.operation_id + SELECT hav.id, NULL, NULL, NULL, NULL, NULL, NULL, '1.25.0' + FROM limited_set ls + JOIN hive.hafbe_app_accounts_view hav ON hav.name = ls.name ON CONFLICT ON CONSTRAINT pk_current_witnesses DO NOTHING; + -- parse props for witnesses table SELECT INTO __prop_op cw.witness_id, (hov.body::JSON)->'value' AS value, - hov.op_type_id, hov.timestamp, haov.operation_id - FROM hive.hafbe_app_account_operations_view haov - JOIN ( - SELECT body, op_type_id, timestamp, id, block_num - FROM hive.hafbe_app_operations_view - WHERE op_type_id = ANY('{42,30,14,11,7}') AND block_num BETWEEN _from AND _to - ) hov ON hov.id = haov.operation_id AND hov.block_num = haov.block_num - JOIN ( - SELECT witness_id - FROM hafbe_app.current_witnesses - ) cw ON cw.witness_id = haov.account_id; + hov.op_type_id, hov.timestamp, hov.id AS operation_id + FROM hive.hafbe_app_operations_view hov + JOIN LATERAL ( + SELECT get_impacted_accounts AS name + FROM hive.get_impacted_accounts(hov.body) + ) bia ON TRUE + JOIN hive.hafbe_app_accounts_view hav ON hav.name = bia.name + JOIN hafbe_app.current_witnesses cw ON cw.witness_id = hav.id + WHERE hov.op_type_id = ANY('{42,30,14,11,7}') AND hov.block_num BETWEEN _from AND _to; UPDATE hafbe_app.current_witnesses cw SET url = res.prop_value FROM ( SELECT prop_value, witness_id @@ -552,16 +540,23 @@ BEGIN WHERE row_n = 1 ) res WHERE cw.witness_id = res.witness_id; + + -- fill account op types cache + WITH limited_set AS ( + SELECT DISTINCT ON (hov.op_type_id, bia.name) + hov.op_type_id, bia.name + FROM hive.hafbe_app_operations_view hov + JOIN LATERAL ( + SELECT get_impacted_accounts AS name + FROM hive.get_impacted_accounts(hov.body) + ) bia ON TRUE + WHERE hov.block_num BETWEEN _from AND _to + ) INSERT INTO hafbe_app.account_operation_cache (account_id, op_type_id) - SELECT DISTINCT ON (haov.account_id, haov.op_type_id) - haov.account_id, haov.op_type_id - FROM hive.hafbe_app_account_operations_view haov - JOIN ( - SELECT id - FROM hive.hafbe_app_operations_view - WHERE block_num BETWEEN _from AND _to - ) hov ON hov.id = haov.operation_id + SELECT hav.id, ls.op_type_id + FROM limited_set ls + JOIN hive.hafbe_app_accounts_view hav ON hav.name = ls.name ON CONFLICT ON CONSTRAINT pk_account_operation_cache DO NOTHING; -- get impacted vests balance for block range and update account_vests -- GitLab From a213cafb59c18938412af2c2501a44a3be78e62a Mon Sep 17 00:00:00 2001 From: kristupas Date: Fri, 28 Oct 2022 20:40:26 +0000 Subject: [PATCH 65/89] UNIONed new witnesses queries to one, updated 'get_ops_by_account()' query to filter only on 'account_operations' #22 --- api/backend.sql | 53 ++++++++++++++++----------------- db/hafbe_app.sql | 76 +++++++++++++++++++++++------------------------- run.sh | 4 ++- 3 files changed, 66 insertions(+), 67 deletions(-) diff --git a/api/backend.sql b/api/backend.sql index c659786..01779d4 100644 --- a/api/backend.sql +++ b/api/backend.sql @@ -115,41 +115,42 @@ DECLARE __filter_ops BOOLEAN = ((SELECT array_length(_filter, 1)) IS NULL); __no_start_date BOOLEAN = (_date_start IS NULL); __no_end_date BOOLEAN = (_date_end IS NULL); + __block_start INT; + __block_end INT; BEGIN + IF __no_start_date IS FALSE THEN + SELECT num FROM hive.blocks_view hbv WHERE hbv.created_at >= _date_start ORDER BY created_at ASC LIMIT 1 INTO __block_start; + END IF; + IF __no_end_date IS FALSE THEN + SELECT num FROM hive.blocks_view hbv WHERE hbv.created_at < _date_end ORDER BY created_at DESC LIMIT 1 INTO __block_end; + END IF; + RETURN QUERY SELECT encode(htv.trx_hash, 'hex')::TEXT, - haov_hov.block_num::INT, - haov_hov.trx_in_block::INT, - haov_hov.op_pos::INT, + ls.block_num::INT, + hov.trx_in_block::INT, + hov.op_pos::INT, hot.is_virtual::BOOLEAN, - haov_hov.timestamp::TEXT, - haov_hov.body::JSON, - haov_hov.operation_id::BIGINT, - haov_hov.account_op_seq_no::BIGINT + hov.timestamp::TEXT, + hov.body::JSON, + ls.operation_id::BIGINT, + ls.account_op_seq_no::BIGINT FROM ( - SELECT * + SELECT haov.operation_id, haov.op_type_id, haov.block_num, haov.account_op_seq_no FROM hive.account_operations_view haov - JOIN ( - SELECT id, trx_in_block, op_pos, timestamp, body - FROM hive.operations_view - ) hov ON hov.id = haov.operation_id WHERE haov.account_id = _account_id AND haov.account_op_seq_no <= _top_op_id AND ( - __filter_ops OR haov.op_type_id=ANY(_filter)) AND - (__no_start_date OR hov.timestamp >= _date_start) AND - (__no_end_date OR hov.timestamp < _date_end) - ) haov_hov - JOIN ( - SELECT is_virtual, id - FROM hive.operation_types - ) hot ON hot.id = haov_hov.op_type_id - JOIN ( - SELECT trx_hash, block_num, trx_in_block - FROM hive.transactions_view - ) htv ON htv.block_num = haov_hov.block_num AND htv.trx_in_block = haov_hov.trx_in_block - ORDER BY haov_hov.operation_id DESC - LIMIT _limit; + __filter_ops OR haov.op_type_id = ANY(_filter)) AND + (__no_start_date OR haov.block_num >= __block_start) AND + (__no_end_date OR haov.block_num < __block_end) + ORDER BY haov.operation_id DESC + LIMIT _limit + ) ls + JOIN hive.operations_view hov ON hov.id = ls.operation_id + JOIN hive.operation_types hot ON hot.id = ls.op_type_id + LEFT JOIN hive.transactions_view htv ON htv.block_num = ls.block_num AND htv.trx_in_block = hov.trx_in_block + ORDER BY ls.operation_id DESC; END $function$ LANGUAGE 'plpgsql' STABLE diff --git a/db/hafbe_app.sql b/db/hafbe_app.sql index f7f033a..a6260a4 100644 --- a/db/hafbe_app.sql +++ b/db/hafbe_app.sql @@ -169,29 +169,28 @@ LANGUAGE 'plpgsql' AS $$ DECLARE + __vote_or_proxy_op RECORD; __prop_op RECORD; __balance_change RECORD; __balance_impacting_ops_ids INT[] = (SELECT op_type_ids_arr FROM hafbe_app.balance_impacting_op_ids); BEGIN - -- process vote and proxy ops, fill tables - WITH vote_or_proxy_op AS ( - SELECT - (body::JSON)->'value' AS value, - timestamp, op_type_id, id AS operation_id - FROM hive.hafbe_app_operations_view - WHERE op_type_id = ANY('{12,91}') AND block_num BETWEEN _from AND _to - ), - select_votes_ops AS ( + SELECT INTO __vote_or_proxy_op + (body::JSON)->'value' AS value, + timestamp, op_type_id, id AS operation_id + FROM hive.hafbe_app_operations_view + WHERE op_type_id = ANY('{12,91}') AND block_num BETWEEN _from AND _to; + + -- process vote ops + WITH select_votes_ops AS ( SELECT hav_w.id AS witness_id, hav_v.id AS voter_id, approve, timestamp, operation_id FROM ( SELECT - value->>'witness' AS witness, - value->>'account' AS voter, - (value->>'approve')::BOOLEAN AS approve, - timestamp, operation_id - FROM vote_or_proxy_op - WHERE op_type_id = 12 + __vote_or_proxy_op.value->>'witness' AS witness, + __vote_or_proxy_op.value->>'account' AS voter, + (__vote_or_proxy_op.value->>'approve')::BOOLEAN AS approve, + __vote_or_proxy_op.timestamp, __vote_or_proxy_op.operation_id + WHERE __vote_or_proxy_op.op_type_id = 12 ) vote_op JOIN hive.hafbe_app_accounts_view hav_w ON hav_w.name = vote_op.witness JOIN hive.hafbe_app_accounts_view hav_v ON hav_v.name = vote_op.voter @@ -222,34 +221,25 @@ BEGIN WHERE approve IS TRUE ON CONFLICT ON CONSTRAINT pk_current_witness_votes DO UPDATE SET timestamp = EXCLUDED.timestamp - ), - - delete_current_votes AS ( - DELETE FROM hafbe_app.current_witness_votes cwv USING ( - SELECT witness_id, voter_id - FROM select_latest_vote_ops - WHERE approve IS FALSE - ) svo - WHERE cwv.witness_id = svo.witness_id AND cwv.voter_id = svo.voter_id - ), + ) - insert_witnesses_from_votes AS ( - INSERT INTO hafbe_app.current_witnesses (witness_id, url, price_feed, bias, feed_age, block_size, signing_key, version) - SELECT witness_id, NULL, NULL, NULL, NULL, NULL, NULL, '1.25.0' - FROM select_votes_ops - ON CONFLICT ON CONSTRAINT pk_current_witnesses DO NOTHING - ), + DELETE FROM hafbe_app.current_witness_votes cwv USING ( + SELECT witness_id, voter_id + FROM select_latest_vote_ops + WHERE approve IS FALSE + ) svo + WHERE cwv.witness_id = svo.witness_id AND cwv.voter_id = svo.voter_id; - select_proxy_ops AS ( + -- process proxy ops + WITH select_proxy_ops AS ( SELECT hav_a.id AS account_id, hav_p.id AS proxy_id, proxy, timestamp, operation_id FROM ( SELECT - value->>'account' AS account, - value->>'proxy' AS proxy_account, - CASE WHEN (value->>'clear')::BOOLEAN IS TRUE THEN FALSE ELSE TRUE END AS proxy, - timestamp, operation_id - FROM vote_or_proxy_op - WHERE op_type_id = 91 + __vote_or_proxy_op.value->>'account' AS account, + __vote_or_proxy_op.value->>'proxy' AS proxy_account, + CASE WHEN (__vote_or_proxy_op.value->>'clear')::BOOLEAN IS TRUE THEN FALSE ELSE TRUE END AS proxy, + __vote_or_proxy_op.timestamp, __vote_or_proxy_op.operation_id + WHERE __vote_or_proxy_op.op_type_id = 91 ) proxy_op JOIN hive.hafbe_app_accounts_view hav_a ON hav_a.name = proxy_op.account JOIN hive.hafbe_app_accounts_view hav_p ON hav_p.name = proxy_op.proxy_account @@ -389,13 +379,19 @@ BEGIN -- add new witnesses per block range WITH limited_set AS ( - SELECT DISTINCT bia.name + SELECT DISTINCT bia.name AS name FROM hive.hafbe_app_operations_view hov JOIN LATERAL ( SELECT get_impacted_accounts AS name FROM hive.get_impacted_accounts(hov.body) ) bia ON TRUE WHERE hov.op_type_id = ANY('{42,11,7}') AND hov.block_num BETWEEN _from AND _to + + UNION + + SELECT DISTINCT name + FROM (SELECT __vote_or_proxy_op.value->>'witness' AS name) witnesses + WHERE witnesses.name IS NOT NULL ) INSERT INTO hafbe_app.current_witnesses (witness_id, url, price_feed, bias, feed_age, block_size, signing_key, version) @@ -540,7 +536,7 @@ BEGIN WHERE row_n = 1 ) res WHERE cw.witness_id = res.witness_id; - + -- fill account op types cache WITH limited_set AS ( SELECT DISTINCT ON (hov.op_type_id, bia.name) diff --git a/run.sh b/run.sh index f3739a6..e92e57f 100755 --- a/run.sh +++ b/run.sh @@ -43,7 +43,9 @@ DB_NAME=haf_block_log owner_role=hafbe_owner admin_role=haf_admin -sudo echo +if [ "$1" != "start" ]; then + sudo echo +fi; if [ "$1" = "start" ]; then start_webserver $2 -- GitLab From 1fccc47a02c076381f74962904c4e1e71ea90712 Mon Sep 17 00:00:00 2001 From: kristupas Date: Sat, 29 Oct 2022 16:42:18 +0000 Subject: [PATCH 66/89] Updated 'get_block()', simplified returned types #22 --- api/backend.sql | 105 +++++++++++++++++++++------------------------- api/endpoints.sql | 14 ++++++- api/types.sql | 12 +++++- 3 files changed, 70 insertions(+), 61 deletions(-) diff --git a/api/backend.sql b/api/backend.sql index 01779d4..d91ddbb 100644 --- a/api/backend.sql +++ b/api/backend.sql @@ -54,10 +54,7 @@ BEGIN RETURN QUERY SELECT aoc.op_type_id, hot.name, hot.is_virtual FROM hafbe_app.account_operation_cache aoc - JOIN ( - SELECT id, name, is_virtual - FROM hive.operation_types - ) hot ON hot.id = aoc.op_type_id + JOIN hive.operation_types hot ON hot.id = aoc.op_type_id WHERE aoc.account_id = _account_id ORDER BY aoc.op_type_id ASC; END @@ -73,13 +70,10 @@ RETURNS SETOF hafbe_types.op_types AS $function$ BEGIN - RETURN QUERY SELECT + RETURN QUERY SELECT DISTINCT ON (hov.op_type_id) hov.op_type_id, hot.name, hot.is_virtual FROM hive.operations_view hov - JOIN ( - SELECT id, name, is_virtual - FROM hive.operation_types - ) hot ON hot.id = hov.op_type_id + JOIN hive.operation_types hot ON hot.id = hov.op_type_id WHERE hov.block_num = _block_num ORDER BY hov.op_type_id ASC; END @@ -126,15 +120,15 @@ BEGIN END IF; RETURN QUERY SELECT - encode(htv.trx_hash, 'hex')::TEXT, - ls.block_num::INT, - hov.trx_in_block::INT, - hov.op_pos::INT, - hot.is_virtual::BOOLEAN, + encode(htv.trx_hash, 'hex'), + ls.block_num, + hov.trx_in_block, + hov.op_pos, + hot.is_virtual, hov.timestamp::TEXT, hov.body::JSON, - ls.operation_id::BIGINT, - ls.account_op_seq_no::BIGINT + ls.operation_id, + ls.account_op_seq_no FROM ( SELECT haov.operation_id, haov.op_type_id, haov.block_num, haov.account_op_seq_no FROM hive.account_operations_view haov @@ -167,31 +161,28 @@ DECLARE __filter_ops BOOLEAN = ((SELECT array_length(_filter, 1)) IS NULL); BEGIN RETURN QUERY SELECT - encode(htv.trx_hash, 'hex')::TEXT, - _block_num::INT, - hov.trx_in_block::INT, - hov.op_pos::INT, - hot.is_virtual::BOOLEAN, - hov.timestamp::TEXT, - hov.body::JSON, - hov.id::BIGINT, - NULL::BIGINT - FROM hive.operations_view hov - JOIN ( - SELECT id, is_virtual - FROM hive.operation_types - ) hot ON hot.id = hov.op_type_id - JOIN ( - SELECT trx_hash, block_num, trx_in_block - FROM hive.transactions_view - ) htv ON htv.block_num = hov.block_num AND htv.trx_in_block = hov.trx_in_block - WHERE - hov.block_num = _block_num AND - hov.id <= _top_op_id AND ( - __filter_ops OR hov.op_type_id=ANY(_filter) - ) - ORDER BY hov.id DESC - LIMIT _limit; + encode(htv.trx_hash, 'hex'), + ls.block_num, + ls.trx_in_block, + ls.op_pos, + hot.is_virtual, + ls.timestamp::TEXT, + ls.body::JSON, + ls.id, + NULL::INT + FROM ( + SELECT hov.id, hov.trx_in_block, hov.op_pos, hov.timestamp, hov.body, hov.op_type_id, hov.block_num + FROM hive.operations_view hov + WHERE + hov.block_num = _block_num AND + hov.id <= _top_op_id AND + (__filter_ops OR hov.op_type_id = ANY(_filter)) + ORDER BY hov.id DESC + LIMIT _limit + ) ls + JOIN hive.operation_types hot ON hot.id = ls.op_type_id + LEFT JOIN hive.transactions_view htv ON htv.block_num = ls.block_num AND htv.trx_in_block = ls.trx_in_block + ORDER BY ls.id DESC; END $function$ LANGUAGE 'plpgsql' STABLE @@ -204,26 +195,24 @@ SET from_collapse_limit=16 Block stats */ -CREATE FUNCTION hafbe_backend.get_block(_block_num INT) -RETURNS JSON +CREATE FUNCTION hafbe_backend.get_set_of_block_data(_block_num INT) +RETURNS SETOF hafbe_types.block AS $function$ BEGIN - RETURN to_json(res) FROM ( - SELECT - hbv.num AS block_num, - encode(hbv.hash, 'hex')::TEXT AS block_hash, - hbv.created_at AS timestamp, - hav.name AS witness, - hbv.signing_key - FROM hive.accounts_view hav - JOIN ( - SELECT num, hash, created_at, producer_account_id, signing_key - FROM hive.blocks_view - WHERE num = _block_num - LIMIT 1 - ) hbv ON hbv.producer_account_id = hav.id - ) res; + RETURN QUERY SELECT + hbv.num, + encode(hbv.hash, 'hex'), + hbv.created_at::TEXT, + hav.name::TEXT, + hbv.signing_key + FROM hive.accounts_view hav + JOIN ( + SELECT num, hash, created_at, producer_account_id, signing_key + FROM hive.blocks_view + WHERE num = _block_num + LIMIT 1 + ) hbv ON hbv.producer_account_id = hav.id; END $function$ LANGUAGE 'plpgsql' STABLE diff --git a/api/endpoints.sql b/api/endpoints.sql index cfdddb3..76ee5a3 100644 --- a/api/endpoints.sql +++ b/api/endpoints.sql @@ -193,7 +193,15 @@ LANGUAGE 'plpgsql' AS $$ BEGIN - RETURN hafbe_backend.get_block(_block_num); + IF _block_num IS NULL THEN + SELECT hafbe_backend.get_head_block_num() INTO _block_num; + END IF; + + RETURN CASE WHEN arr IS NOT NULL THEN to_json(arr) ELSE '[]'::JSON END FROM ( + SELECT ARRAY( + SELECT to_json(hafbe_backend.get_set_of_block_data(_block_num)) + ) arr + ) result; END $$ ; @@ -216,6 +224,10 @@ BEGIN RETURN hafbe_exceptions.raise_ops_limit_exception(_top_op_id, _limit); END IF; + IF _block_num IS NULL THEN + SELECT hafbe_backend.get_head_block_num() INTO _block_num; + END IF; + IF _filter IS NULL THEN _filter = ARRAY[]::SMALLINT[]; END IF; diff --git a/api/types.sql b/api/types.sql index a345864..ead041e 100644 --- a/api/types.sql +++ b/api/types.sql @@ -11,13 +11,21 @@ CREATE TYPE hafbe_types.op_types AS ( CREATE TYPE hafbe_types.operations AS ( trx_id TEXT, block INT, - trx_in_block INT, + trx_in_block SMALLINT, op_in_trx INT, virtual_op BOOLEAN, timestamp TEXT, operations JSON, operation_id BIGINT, - acc_operation_id BIGINT + acc_operation_id INT +); + +CREATE TYPE hafbe_types.block AS ( + block_num INT, + block_hash TEXT, + timestamp TEXT, + witness TEXT, + signing_key TEXT ); CREATE TYPE hafbe_types.witness_voters_by_name AS ( -- GitLab From a312f6f794a4ea00180f7761e80e2174a09a8d09 Mon Sep 17 00:00:00 2001 From: Kristupas Bobraitis Date: Sat, 29 Oct 2022 17:06:02 +0000 Subject: [PATCH 67/89] Update README.md --- README.md | 43 ++++++++++++++++++++++++++++++++++--------- 1 file changed, 34 insertions(+), 9 deletions(-) diff --git a/README.md b/README.md index 2a5a185..6b362c7 100644 --- a/README.md +++ b/README.md @@ -13,23 +13,48 @@ npm: `latest` To start using haf block explorer, first ``` -./run.sh install-postgrest -./run.sh install-plpython +./scripts/setup_dependancies.sh all +./scripts/setup_db.sh all ``` -then install gui dependancies +This will create required postgres schemas and roles, also [indexes](https://gitlab.syncad.com/hive/haf_block_explorer/-/blob/22-create-witness-table/db/indexes.sql#L20) on haf db. + + +Then install gui dependancies ``` cd gui ; npm install ; cd .. ``` -finally start server with: + +## Block processing + +hafbe will process blocks from haf db to own tables +``` +./run.sh process-blocks +``` +Until hafbe catches up to head block on haf db, it will do massive processing + + +If you need to stop and restart processing +``` +./run.sh stop-processing +./run.sh continue-processing +``` + +If you want to destroy hafbe db: ``` -./run.sh re-start +./run.sh drop-db ``` -This will create required postgres schemas and roles. -## Starting +## Starting + +When hafbe is in live sync mode (processing block-by-block), create indexes for it's tables: +``` +./run.sh create-hafbe-indexes +``` After setup start postgREST server with: ``` +sudo su - hafbe_owner +cd ./run.sh start ``` `PORT` is optional, default is 3000. @@ -41,9 +66,9 @@ cd gui ; npm start ## Testing performance -haf block explorer has 10 performance/load test suites ready in `tests/performance/endpoints.jmx`.
To run tests you must have JMeter installed: +Install JMeter if not yet installed ``` -./run.sh install-jmeter +./scripts/setup_dependancies.sh jmeter ``` then run tests with: ``` -- GitLab From f99c7c89e52ed2b65f3ef0e45ab64ded9c5c71fc Mon Sep 17 00:00:00 2001 From: kristupas Date: Mon, 31 Oct 2022 20:05:42 +0000 Subject: [PATCH 68/89] Replaced op_type cache table with CTE #22 --- api/backend.sql | 19 +++++++++++++------ db/hafbe_app.sql | 25 ------------------------- 2 files changed, 13 insertions(+), 31 deletions(-) diff --git a/api/backend.sql b/api/backend.sql index d91ddbb..974b73a 100644 --- a/api/backend.sql +++ b/api/backend.sql @@ -51,12 +51,19 @@ RETURNS SETOF hafbe_types.op_types AS $function$ BEGIN - RETURN QUERY SELECT - aoc.op_type_id, hot.name, hot.is_virtual - FROM hafbe_app.account_operation_cache aoc - JOIN hive.operation_types hot ON hot.id = aoc.op_type_id - WHERE aoc.account_id = _account_id - ORDER BY aoc.op_type_id ASC; + RETURN QUERY WITH op_types_cte AS ( + SELECT id + FROM hive.operation_types hot + WHERE ( + SELECT EXISTS ( + SELECT 1 FROM hive.account_operations_view haov WHERE haov.account_id = _account_id AND haov.op_type_id = hot.id + ) + ) + ) + + SELECT cte.id, hot.name, hot.is_virtual + FROM op_types_cte cte + JOIN hive.operation_types hot ON hot.id = cte.id; END $function$ LANGUAGE 'plpgsql' STABLE diff --git a/db/hafbe_app.sql b/db/hafbe_app.sql index a6260a4..4672ea0 100644 --- a/db/hafbe_app.sql +++ b/db/hafbe_app.sql @@ -76,13 +76,6 @@ BEGIN CONSTRAINT pk_hived_account_cache PRIMARY KEY (account) ); - CREATE TABLE IF NOT EXISTS hafbe_app.account_operation_cache ( - account_id INT NOT NULL, - op_type_id SMALLINT NOT NULL, - - CONSTRAINT pk_account_operation_cache PRIMARY KEY (account_id, op_type_id) - ) INHERITS (hive.hafbe_app); - CREATE TABLE IF NOT EXISTS hafbe_app.balance_impacting_op_ids ( op_type_ids_arr SMALLINT[] NOT NULL ); @@ -537,24 +530,6 @@ BEGIN ) res WHERE cw.witness_id = res.witness_id; - -- fill account op types cache - WITH limited_set AS ( - SELECT DISTINCT ON (hov.op_type_id, bia.name) - hov.op_type_id, bia.name - FROM hive.hafbe_app_operations_view hov - JOIN LATERAL ( - SELECT get_impacted_accounts AS name - FROM hive.get_impacted_accounts(hov.body) - ) bia ON TRUE - WHERE hov.block_num BETWEEN _from AND _to - ) - - INSERT INTO hafbe_app.account_operation_cache (account_id, op_type_id) - SELECT hav.id, ls.op_type_id - FROM limited_set ls - JOIN hive.hafbe_app_accounts_view hav ON hav.name = ls.name - ON CONFLICT ON CONSTRAINT pk_account_operation_cache DO NOTHING; - -- get impacted vests balance for block range and update account_vests FOR __balance_change IN SELECT bio.account_name AS account, bio.amount AS vests -- GitLab From 5a75e4618155c68c13d64859c0b2964104dfd2b1 Mon Sep 17 00:00:00 2001 From: kristupas Date: Thu, 3 Nov 2022 20:25:21 +0000 Subject: [PATCH 69/89] Moved recursive_account_proxies to views from processing, added witnesses caches #22 --- api/backend.sql | 47 +++----- api/views.sql | 111 +++++++++++------- db/hafbe_app.sql | 291 +++++++++++++++++++++-------------------------- run.sh | 1 + 4 files changed, 211 insertions(+), 239 deletions(-) diff --git a/api/backend.sql b/api/backend.sql index 974b73a..6458529 100644 --- a/api/backend.sql +++ b/api/backend.sql @@ -273,8 +273,8 @@ BEGIN RETURN QUERY EXECUTE format( $query$ - SELECT voter_id, vests, account_vests::NUMERIC, proxied_vests, timestamp - FROM hafbe_views.voters_stats_view + SELECT voter_id, vests, account_vests, proxied_vests, timestamp + FROM hafbe_app.witness_voters_stats_cache WHERE witness_id = %L ORDER BY (CASE WHEN %L = 'desc' THEN %I ELSE NULL END) DESC, @@ -307,7 +307,7 @@ BEGIN FROM hafbe_backend.get_set_of_witness_voters_by_name(%L, %L, %L, %L) ls JOIN ( SELECT voter_id, vests, account_vests, proxied_vests, timestamp - FROM hafbe_views.voters_stats_view + FROM hafbe_app.witness_voters_stats_cache WHERE witness_id = %L ) vsv ON vsv.voter_id = ls.voter_id ORDER BY @@ -542,12 +542,8 @@ BEGIN $query$ SELECT witness_id, votes, voters_num FROM ( - SELECT - vsv.witness_id, - SUM(vsv.vests) AS votes, - COUNT(1)::INT AS voters_num - FROM hafbe_views.voters_stats_view vsv - GROUP BY vsv.witness_id + SELECT witness_id, votes, voters_num + FROM hafbe_app.witness_votes_cache ) votes_sum ORDER BY (CASE WHEN %L = 'desc' THEN %I ELSE NULL END) DESC, @@ -649,14 +645,9 @@ BEGIN COALESCE(todays_votes.voters_num_daily_change, 0)::INT, price_feed, bias, feed_age, block_size, signing_key, version FROM hafbe_backend.get_set_of_witnesses_by_name(%L, %L, %L) ls - LEFT JOIN LATERAL ( - SELECT - vsv.witness_id, - SUM(vsv.vests) AS votes, - COUNT(1) AS voters_num - FROM hafbe_views.voters_stats_view vsv - WHERE vsv.witness_id = ls.witness_id - GROUP BY vsv.witness_id + LEFT JOIN ( + SELECT witness_id, votes, voters_num + FROM hafbe_app.witness_votes_cache ) all_votes ON all_votes.witness_id = ls.witness_id LEFT JOIN LATERAL ( SELECT @@ -726,14 +717,9 @@ BEGIN price_feed, bias, feed_age, block_size, signing_key, version FROM hafbe_backend.get_set_of_witnesses_by_votes_change(%L, %L, %L, %L, %L) ls JOIN hafbe_app.current_witnesses cw ON cw.witness_id = ls.witness_id - JOIN LATERAL ( - SELECT - vsv.witness_id, - SUM(vsv.vests) AS votes, - COUNT(1) AS voters_num - FROM hafbe_views.voters_stats_view vsv - WHERE vsv.witness_id = ls.witness_id - GROUP BY vsv.witness_id + JOIN ( + SELECT witness_id, votes, voters_num + FROM hafbe_app.witness_votes_cache ) all_votes ON all_votes.witness_id = ls.witness_id JOIN ( SELECT name, id @@ -761,14 +747,9 @@ BEGIN COALESCE(todays_votes.voters_num_daily_change, 0)::INT, price_feed, bias, feed_age, block_size, signing_key, version FROM hafbe_backend.get_set_of_witnesses_by_prop(%L, %L, %L, %L) ls - LEFT JOIN LATERAL ( - SELECT - vsv.witness_id, - SUM(vsv.vests) AS votes, - COUNT(1) AS voters_num - FROM hafbe_views.voters_stats_view vsv - WHERE vsv.witness_id = ls.witness_id - GROUP BY vsv.witness_id + LEFT JOIN ( + SELECT witness_id, votes, voters_num + FROM hafbe_app.witness_votes_cache ) all_votes ON all_votes.witness_id = ls.witness_id LEFT JOIN LATERAL ( SELECT diff --git a/api/views.sql b/api/views.sql index cdfacab..0a0e4a6 100644 --- a/api/views.sql +++ b/api/views.sql @@ -1,58 +1,85 @@ -DROP SCHEMA IF EXISTS hafbe_views CASCADE; +CREATE SCHEMA IF NOT EXISTS hafbe_views AUTHORIZATION hafbe_owner; + +CREATE OR REPLACE VIEW hafbe_views.recursive_account_proxies_view AS +WITH proxies1 AS ( + SELECT + prox1.proxy_id AS top_proxy_id, + prox1.account_id + FROM hafbe_app.current_account_proxies prox1 +), + +proxies2 AS ( + SELECT prox1.top_proxy_id, prox2.account_id + FROM proxies1 prox1 + JOIN hafbe_app.current_account_proxies prox2 ON prox2.proxy_id = prox1.account_id +), + +proxies3 AS ( + SELECT prox2.top_proxy_id, prox3.account_id + FROM proxies2 prox2 + JOIN hafbe_app.current_account_proxies prox3 ON prox3.proxy_id = prox2.account_id +), + +proxies4 AS ( + SELECT prox3.top_proxy_id, prox4.account_id + FROM proxies3 prox3 + JOIN hafbe_app.current_account_proxies prox4 ON prox4.proxy_id = prox3.account_id +), + +proxies5 AS ( + SELECT prox4.top_proxy_id, prox5.account_id + FROM proxies4 prox4 + JOIN hafbe_app.current_account_proxies prox5 ON prox5.proxy_id = prox4.account_id +) + +SELECT top_proxy_id AS proxy_id, account_id +FROM ( + SELECT top_proxy_id, account_id FROM proxies1 + UNION + SELECT top_proxy_id, account_id FROM proxies2 + UNION + SELECT top_proxy_id, account_id FROM proxies3 + UNION + SELECT top_proxy_id, account_id FROM proxies4 + UNION + SELECT top_proxy_id, account_id FROM proxies5 +) rap; -CREATE SCHEMA hafbe_views AUTHORIZATION hafbe_owner; +------ -DROP VIEW IF EXISTS hafbe_views.voters_account_vests_view CASCADE; -CREATE VIEW hafbe_views.voters_account_vests_view AS +CREATE OR REPLACE VIEW hafbe_views.witness_voters_vests_view AS SELECT - av.account_id AS voter_id, - CASE WHEN cap.account_id IS NULL THEN av.vests ELSE 0 END AS account_vests -FROM hafbe_app.account_vests av - -LEFT JOIN LATERAL ( - SELECT account_id - FROM hafbe_app.current_account_proxies - WHERE account_id = av.account_id -) cap ON TRUE; + cwv_cap.witness_id, cwv_cap.voter_id, + CASE WHEN cwv_cap.proxy_id IS NULL THEN COALESCE(av.vests, 0) ELSE 0 END AS account_vests, + cwv_cap.timestamp +FROM ( + SELECT cwv.witness_id, cwv.voter_id, cwv.timestamp, cap.proxy_id + FROM hafbe_app.current_witness_votes cwv + LEFT JOIN hafbe_app.current_account_proxies cap ON cap.account_id = cwv.voter_id +) cwv_cap +LEFT JOIN hafbe_app.account_vests av ON av.account_id = cwv_cap.voter_id; ------ -DROP VIEW IF EXISTS hafbe_views.voters_proxied_vests_view CASCADE; -CREATE VIEW hafbe_views.voters_proxied_vests_view AS +CREATE OR REPLACE VIEW hafbe_views.voters_proxied_vests_view AS SELECT - rap.proxy_id, + rapv.proxy_id, SUM(av.vests) AS proxied_vests -FROM hafbe_app.recursive_account_proxies rap - -JOIN ( - SELECT account_id, vests - FROM hafbe_app.account_vests -) av ON av.account_id = rap.account_id -GROUP BY rap.proxy_id; +FROM hafbe_views.recursive_account_proxies_view rapv +JOIN hafbe_app.account_vests av ON av.account_id = rapv.account_id +GROUP BY rapv.proxy_id; ------ -DROP VIEW IF EXISTS hafbe_views.voters_stats_view CASCADE; -CREATE VIEW hafbe_views.voters_stats_view AS +CREATE OR REPLACE VIEW hafbe_views.voters_stats_view AS SELECT - cwv.witness_id, cwv.voter_id, - COALESCE(vavv.account_vests, 0) + COALESCE(vpvv.proxied_vests, 0) AS vests, - COALESCE(vavv.account_vests, 0) AS account_vests, + wvvv.witness_id, wvvv.voter_id, + wvvv.account_vests + COALESCE(vpvv.proxied_vests, 0) AS vests, + wvvv.account_vests, COALESCE(vpvv.proxied_vests, 0) AS proxied_vests, - cwv.timestamp -FROM hafbe_app.current_witness_votes cwv - -LEFT JOIN LATERAL ( - SELECT voter_id, account_vests - FROM hafbe_views.voters_account_vests_view - WHERE voter_id = cwv.voter_id -) vavv ON TRUE - -LEFT JOIN LATERAL ( - SELECT proxy_id, proxied_vests - FROM hafbe_views.voters_proxied_vests_view - WHERE proxy_id = cwv.voter_id -) vpvv ON TRUE; + wvvv.timestamp +FROM hafbe_views.witness_voters_vests_view wvvv +LEFT JOIN hafbe_views.voters_proxied_vests_view vpvv ON vpvv.proxy_id = wvvv.voter_id; ------ diff --git a/db/hafbe_app.sql b/db/hafbe_app.sql index 4672ea0..08e8d08 100644 --- a/db/hafbe_app.sql +++ b/db/hafbe_app.sql @@ -14,11 +14,12 @@ BEGIN continue_processing BOOLEAN, last_processed_block INT, started_processing_at TIMESTAMP, + finished_processing_at TIMESTAMP, last_reported_at TIMESTAMP, last_reported_block INT ); - INSERT INTO hafbe_app.app_status (continue_processing, last_processed_block, started_processing_at, last_reported_at, last_reported_block) - VALUES (TRUE, 0, NULL, to_timestamp(0), 0); + INSERT INTO hafbe_app.app_status (continue_processing, last_processed_block, started_processing_at, finished_processing_at, last_reported_at, last_reported_block) + VALUES (TRUE, 0, NULL, NULL, to_timestamp(0), 0); CREATE TABLE IF NOT EXISTS hafbe_app.witness_votes_history ( witness_id INT NOT NULL, @@ -62,13 +63,6 @@ BEGIN CONSTRAINT pk_current_account_proxies PRIMARY KEY (account_id) ) INHERITS (hive.hafbe_app); - CREATE TABLE IF NOT EXISTS hafbe_app.recursive_account_proxies ( - proxy_id INT NOT NULL, - account_id INT NOT NULL, - - CONSTRAINT pk_recursive_account_proxies PRIMARY KEY (proxy_id, account_id) - ) INHERITS (hive.hafbe_app); - CREATE TABLE IF NOT EXISTS hafbe_app.hived_account_cache ( account TEXT NOT NULL, data JSON NOT NULL, @@ -94,6 +88,33 @@ BEGIN CONSTRAINT pk_account_vests PRIMARY KEY (account_id) ) INHERITS (hive.hafbe_app); + + CREATE TABLE IF NOT EXISTS hafbe_app.witnesses_cache_config ( + update_interval INTERVAL, + last_updated_at TIMESTAMP + ); + + INSERT INTO hafbe_app.witnesses_cache_config (update_interval, last_updated_at) + VALUES ('1 hour', to_timestamp(0)); + + CREATE TABLE IF NOT EXISTS hafbe_app.witness_voters_stats_cache ( + witness_id INT, + voter_id INT, + vests NUMERIC, + account_vests NUMERIC, + proxied_vests NUMERIC, + timestamp TIMESTAMP, + + CONSTRAINT pk_witness_voters_stats_cache PRIMARY KEY (witness_id, voter_id) + ); + + CREATE TABLE IF NOT EXISTS hafbe_app.witness_votes_cache ( + witness_id INT, + votes NUMERIC, + voters_num INT, + + CONSTRAINT pk_witness_votes_cache PRIMARY KEY (witness_id) + ); END $$ ; @@ -162,32 +183,31 @@ LANGUAGE 'plpgsql' AS $$ DECLARE - __vote_or_proxy_op RECORD; + __ops_in_range RECORD; __prop_op RECORD; __balance_change RECORD; __balance_impacting_ops_ids INT[] = (SELECT op_type_ids_arr FROM hafbe_app.balance_impacting_op_ids); BEGIN - - SELECT INTO __vote_or_proxy_op + SELECT INTO __ops_in_range + body, (body::JSON)->'value' AS value, timestamp, op_type_id, id AS operation_id FROM hive.hafbe_app_operations_view - WHERE op_type_id = ANY('{12,91}') AND block_num BETWEEN _from AND _to; + WHERE op_type_id = ANY('{12,13,91,42,30,14,11,7}') AND block_num BETWEEN _from AND _to; -- process vote ops WITH select_votes_ops AS ( SELECT hav_w.id AS witness_id, hav_v.id AS voter_id, approve, timestamp, operation_id FROM ( SELECT - __vote_or_proxy_op.value->>'witness' AS witness, - __vote_or_proxy_op.value->>'account' AS voter, - (__vote_or_proxy_op.value->>'approve')::BOOLEAN AS approve, - __vote_or_proxy_op.timestamp, __vote_or_proxy_op.operation_id - WHERE __vote_or_proxy_op.op_type_id = 12 + __ops_in_range.value->>'witness' AS witness, + __ops_in_range.value->>'account' AS voter, + (__ops_in_range.value->>'approve')::BOOLEAN AS approve, + __ops_in_range.timestamp, __ops_in_range.operation_id + WHERE __ops_in_range.op_type_id = 12 ) vote_op JOIN hive.hafbe_app_accounts_view hav_w ON hav_w.name = vote_op.witness JOIN hive.hafbe_app_accounts_view hav_v ON hav_v.name = vote_op.voter - ORDER BY operation_id DESC ), insert_votes_history AS ( @@ -228,15 +248,23 @@ BEGIN SELECT hav_a.id AS account_id, hav_p.id AS proxy_id, proxy, timestamp, operation_id FROM ( SELECT - __vote_or_proxy_op.value->>'account' AS account, - __vote_or_proxy_op.value->>'proxy' AS proxy_account, - CASE WHEN (__vote_or_proxy_op.value->>'clear')::BOOLEAN IS TRUE THEN FALSE ELSE TRUE END AS proxy, - __vote_or_proxy_op.timestamp, __vote_or_proxy_op.operation_id - WHERE __vote_or_proxy_op.op_type_id = 91 + __ops_in_range.value->>'account' AS account, + __ops_in_range.value->>'proxy' AS proxy_account, + TRUE AS proxy, + __ops_in_range.timestamp, __ops_in_range.operation_id + WHERE __ops_in_range.op_type_id = 13 + + UNION + + SELECT + __ops_in_range.value->>'account' AS account, + __ops_in_range.value->>'proxy' AS proxy_account, + FALSE AS proxy, + __ops_in_range.timestamp, __ops_in_range.operation_id + WHERE __ops_in_range.op_type_id = 91 ) proxy_op JOIN hive.hafbe_app_accounts_view hav_a ON hav_a.name = proxy_op.account JOIN hive.hafbe_app_accounts_view hav_p ON hav_p.name = proxy_op.proxy_account - ORDER BY operation_id DESC ), insert_proxy_history AS ( @@ -261,130 +289,28 @@ BEGIN SELECT account_id, proxy_id FROM select_latest_proxy_ops WHERE proxy IS TRUE - ON CONFLICT ON CONSTRAINT pk_current_account_proxies DO UPDATE SET proxy_id = EXCLUDED.proxy_id RETURNING cap.account_id, cap.proxy_id - ), - - delete_current_proxies AS ( - DELETE FROM hafbe_app.current_account_proxies cap USING ( - SELECT account_id - FROM select_latest_proxy_ops - WHERE proxy IS FALSE - ) spo - WHERE cap.account_id = spo.account_id - RETURNING cap.account_id, cap.proxy_id - ), - - unproxies1 AS ( - SELECT - prox1.proxy_id AS top_proxy_id, - prox1.account_id - FROM delete_current_proxies prox1 - ), - - unproxies2 AS ( - SELECT prox1.top_proxy_id, prox2.account_id - FROM unproxies1 prox1 - JOIN hafbe_app.current_account_proxies prox2 ON prox2.proxy_id = prox1.account_id - ), - - unproxies3 AS ( - SELECT prox2.top_proxy_id, prox3.account_id - FROM unproxies2 prox2 - JOIN hafbe_app.current_account_proxies prox3 ON prox3.proxy_id = prox2.account_id - ), - - unproxies4 AS ( - SELECT prox3.top_proxy_id, prox4.account_id - FROM unproxies3 prox3 - JOIN hafbe_app.current_account_proxies prox4 ON prox4.proxy_id = prox3.account_id - ), - - unproxies5 AS ( - SELECT prox4.top_proxy_id, prox5.account_id - FROM unproxies4 prox4 - JOIN hafbe_app.current_account_proxies prox5 ON prox5.proxy_id = prox4.account_id - ), - - delete_recursive_account_unproxies AS ( - DELETE FROM hafbe_app.recursive_account_proxies rap USING ( - SELECT top_proxy_id, account_id FROM unproxies1 - UNION - SELECT top_proxy_id, account_id FROM unproxies2 - UNION - SELECT top_proxy_id, account_id FROM unproxies3 - UNION - SELECT top_proxy_id, account_id FROM unproxies4 - UNION - SELECT top_proxy_id, account_id FROM unproxies5 - ) raup - WHERE rap.proxy_id = raup.top_proxy_id AND rap.account_id = raup.account_id - ), - - proxies1 AS ( - SELECT - prox1.proxy_id AS top_proxy_id, - prox1.account_id - FROM insert_current_proxies prox1 - ), - - proxies2 AS ( - SELECT prox1.top_proxy_id, prox2.account_id - FROM proxies1 prox1 - JOIN hafbe_app.current_account_proxies prox2 ON prox2.proxy_id = prox1.account_id - ), - - proxies3 AS ( - SELECT prox2.top_proxy_id, prox3.account_id - FROM proxies2 prox2 - JOIN hafbe_app.current_account_proxies prox3 ON prox3.proxy_id = prox2.account_id - ), - - proxies4 AS ( - SELECT prox3.top_proxy_id, prox4.account_id - FROM proxies3 prox3 - JOIN hafbe_app.current_account_proxies prox4 ON prox4.proxy_id = prox3.account_id - ), - - proxies5 AS ( - SELECT prox4.top_proxy_id, prox5.account_id - FROM proxies4 prox4 - JOIN hafbe_app.current_account_proxies prox5 ON prox5.proxy_id = prox4.account_id ) - INSERT INTO hafbe_app.recursive_account_proxies (proxy_id, account_id) - SELECT top_proxy_id, account_id - FROM ( - SELECT top_proxy_id, account_id FROM proxies1 - UNION - SELECT top_proxy_id, account_id FROM proxies2 - UNION - SELECT top_proxy_id, account_id FROM proxies3 - UNION - SELECT top_proxy_id, account_id FROM proxies4 - UNION - SELECT top_proxy_id, account_id FROM proxies5 - ) rap - WHERE top_proxy_id != account_id - ON CONFLICT ON CONSTRAINT pk_recursive_account_proxies DO NOTHING; + DELETE FROM hafbe_app.current_account_proxies cap USING ( + SELECT account_id + FROM select_latest_proxy_ops + WHERE proxy IS FALSE + ) spo + WHERE cap.account_id = spo.account_id; -- add new witnesses per block range WITH limited_set AS ( - SELECT DISTINCT bia.name AS name - FROM hive.hafbe_app_operations_view hov - JOIN LATERAL ( - SELECT get_impacted_accounts AS name - FROM hive.get_impacted_accounts(hov.body) - ) bia ON TRUE - WHERE hov.op_type_id = ANY('{42,11,7}') AND hov.block_num BETWEEN _from AND _to + SELECT DISTINCT get_impacted_accounts AS name + FROM hive.get_impacted_accounts(__ops_in_range.body) + WHERE __ops_in_range.op_type_id = ANY('{42,11,7}') UNION - SELECT DISTINCT name - FROM (SELECT __vote_or_proxy_op.value->>'witness' AS name) witnesses - WHERE witnesses.name IS NOT NULL + SELECT DISTINCT __ops_in_range.value->>'witness' AS name + WHERE __ops_in_range.op_type_id = 12 ) INSERT INTO hafbe_app.current_witnesses (witness_id, url, price_feed, bias, feed_age, block_size, signing_key, version) @@ -396,16 +322,18 @@ BEGIN -- parse props for witnesses table SELECT INTO __prop_op cw.witness_id, - (hov.body::JSON)->'value' AS value, - hov.op_type_id, hov.timestamp, hov.id AS operation_id - FROM hive.hafbe_app_operations_view hov - JOIN LATERAL ( - SELECT get_impacted_accounts AS name - FROM hive.get_impacted_accounts(hov.body) - ) bia ON TRUE + bia.value, + bia.op_type_id, bia.timestamp, bia.operation_id + FROM ( + SELECT + get_impacted_accounts AS name, + __ops_in_range.value, + __ops_in_range.op_type_id, __ops_in_range.timestamp, __ops_in_range.operation_id + FROM hive.get_impacted_accounts(__ops_in_range.body) + WHERE __ops_in_range.op_type_id = ANY('{42,30,14,11,7}') + ) bia JOIN hive.hafbe_app_accounts_view hav ON hav.name = bia.name - JOIN hafbe_app.current_witnesses cw ON cw.witness_id = hav.id - WHERE hov.op_type_id = ANY('{42,30,14,11,7}') AND hov.block_num BETWEEN _from AND _to; + JOIN hafbe_app.current_witnesses cw ON cw.witness_id = hav.id; UPDATE hafbe_app.current_witnesses cw SET url = res.prop_value FROM ( SELECT prop_value, witness_id @@ -531,28 +459,27 @@ BEGIN WHERE cw.witness_id = res.witness_id; -- get impacted vests balance for block range and update account_vests - FOR __balance_change IN - SELECT bio.account_name AS account, bio.amount AS vests - FROM hive.hafbe_app_operations_view hov + WITH balance_change AS ( + SELECT hav.id AS account_id, bio.amount AS vests + FROM hive.operations_view hov JOIN LATERAL ( SELECT account_name, amount FROM hive.get_impacted_balances(hov.body, hov.block_num > 905693) WHERE asset_symbol_nai = 37 ) bio ON TRUE - - WHERE hov.op_type_id = ANY(__balance_impacting_ops_ids) AND hov.block_num BETWEEN _from AND _to - ORDER BY hov.block_num, hov.id - LOOP - INSERT INTO hafbe_app.account_vests (account_id, vests) - SELECT hav.id, __balance_change.vests - FROM hive.hafbe_app_accounts_view hav - WHERE hav.name = __balance_change.account + JOIN hive.accounts_view hav ON hav.name = bio.account_name + WHERE hov.op_type_id = ANY(__balance_impacting_ops_ids) AND hov.block_num BETWEEN _from AND _to + ) - ON CONFLICT ON CONSTRAINT pk_account_vests DO - UPDATE SET vests = hafbe_app.account_vests.vests + EXCLUDED.vests; - END LOOP; + INSERT INTO hafbe_app.account_vests (account_id, vests) + SELECT account_id, SUM(vests) AS vests + FROM balance_change + GROUP BY account_id + ON CONFLICT ON CONSTRAINT pk_account_vests DO + UPDATE SET vests = hafbe_app.account_vests.vests + EXCLUDED.vests + ; END $$ SET from_collapse_limit = 16 @@ -586,13 +513,13 @@ BEGIN --RAISE NOTICE 'Block range: <%, %> processed successfully.', b, _last_block; - IF (NOW() - (SELECT last_reported_at FROM hafbe_app.app_status))::INTERVAL >= '5 second'::INTERVAL THEN + IF (NOW() - (SELECT last_reported_at FROM hafbe_app.app_status LIMIT 1)) >= '5 second'::INTERVAL THEN RAISE NOTICE 'Last processed block %', _last_block; - RAISE NOTICE 'Processed % blocks in 5 seconds', (SELECT _last_block - last_reported_block FROM hafbe_app.app_status); + RAISE NOTICE 'Processed % blocks in 5 seconds', (SELECT _last_block - last_reported_block FROM hafbe_app.app_status LIMIT 1); RAISE NOTICE 'Block processing running for % minutes ', ROUND((EXTRACT(epoch FROM ( - SELECT NOW() - started_processing_at FROM hafbe_app.app_status + SELECT NOW() - started_processing_at FROM hafbe_app.app_status LIMIT 1 )) / 60)::NUMERIC, 2); UPDATE hafbe_app.app_status SET last_reported_at = NOW(); @@ -700,10 +627,46 @@ BEGIN IF __next_block_range.first_block != __next_block_range.last_block THEN CALL hafbe_app.do_massive_processing(_appContext, __next_block_range.first_block, __next_block_range.last_block, 100, __last_block); + UPDATE hafbe_app.app_status SET finished_processing_at = NOW(); ELSE CALL hafbe_app.processBlock(__next_block_range.last_block); __last_block := __next_block_range.last_block; END IF; + + IF __next_block_range.first_block = __next_block_range.last_block AND + (NOW() - (SELECT last_updated_at FROM hafbe_app.witnesses_cache_config LIMIT 1)) >= + (SELECT update_interval FROM hafbe_app.witnesses_cache_config LIMIT 1) THEN + + RAISE NOTICE 'Updating witnesses caches'; + + WITH select_voters_stats AS ( + SELECT witness_id, voter_id, vests, account_vests, proxied_vests + FROM hafbe_views.voters_stats_view + ), + + insert_witness_voters_stats_cache AS ( + INSERT INTO hafbe_app.witness_voters_stats_cache (witness_id, voter_id, vests, account_vests, proxied_vests) + SELECT witness_id, voter_id, vests, account_vests, proxied_vests + FROM select_voters_stats + ON CONFLICT ON CONSTRAINT pk_witness_voters_stats_cache DO UPDATE SET + vests = EXCLUDED.vests, + account_vests = EXCLUDED.account_vests, + proxied_vests = EXCLUDED.proxied_vests, + timestamp = EXCLUDED.timestamp + ) + + INSERT INTO hafbe_app.witness_votes_cache (witness_id, votes, voters_num) + SELECT witness_id, SUM(vests), COUNT(1) + FROM select_voters_stats + GROUP BY witness_id + ON CONFLICT ON CONSTRAINT pk_witness_votes_cache DO UPDATE SET + votes = EXCLUDED.votes, + voters_num = EXCLUDED.voters_num + ; + + UPDATE hafbe_app.witnesses_cache_config SET last_updated_at = NOW(); + + END IF; END IF; diff --git a/run.sh b/run.sh index e92e57f..c3f6d29 100755 --- a/run.sh +++ b/run.sh @@ -20,6 +20,7 @@ continue_processing() { drop_db() { sudo -nu $admin_role psql -d $DB_NAME -a -v "ON_ERROR_STOP=on" -c "SELECT hive.app_remove_context('hafbe_app');" sudo -nu $owner_role psql -d $DB_NAME -a -v "ON_ERROR_STOP=on" -c "DROP SCHEMA IF EXISTS hafbe_app CASCADE;" + sudo -nu $owner_role psql -d $DB_NAME -a -v "ON_ERROR_STOP=on" -c "DROP SCHEMA IF EXISTS hafbe_views CASCADE;" } create_hafbe_indexes() { -- GitLab From a8fdf26429e335db71bfa119cdff5cd77565ba61 Mon Sep 17 00:00:00 2001 From: kristupas Date: Fri, 4 Nov 2022 20:34:11 +0000 Subject: [PATCH 70/89] Fix bug of RECORD having single row #22 --- db/hafbe_app.sql | 318 ++++++++++++++++++++++++----------------------- 1 file changed, 161 insertions(+), 157 deletions(-) diff --git a/db/hafbe_app.sql b/db/hafbe_app.sql index 08e8d08..f0522bd 100644 --- a/db/hafbe_app.sql +++ b/db/hafbe_app.sql @@ -183,28 +183,24 @@ LANGUAGE 'plpgsql' AS $$ DECLARE - __ops_in_range RECORD; - __prop_op RECORD; - __balance_change RECORD; __balance_impacting_ops_ids INT[] = (SELECT op_type_ids_arr FROM hafbe_app.balance_impacting_op_ids); BEGIN - SELECT INTO __ops_in_range - body, - (body::JSON)->'value' AS value, - timestamp, op_type_id, id AS operation_id - FROM hive.hafbe_app_operations_view - WHERE op_type_id = ANY('{12,13,91,42,30,14,11,7}') AND block_num BETWEEN _from AND _to; - -- process vote ops WITH select_votes_ops AS ( SELECT hav_w.id AS witness_id, hav_v.id AS voter_id, approve, timestamp, operation_id FROM ( SELECT - __ops_in_range.value->>'witness' AS witness, - __ops_in_range.value->>'account' AS voter, - (__ops_in_range.value->>'approve')::BOOLEAN AS approve, - __ops_in_range.timestamp, __ops_in_range.operation_id - WHERE __ops_in_range.op_type_id = 12 + value->>'witness' AS witness, + value->>'account' AS voter, + (value->>'approve')::BOOLEAN AS approve, + timestamp, operation_id + FROM ( + SELECT + (body::JSON)->'value' AS value, + timestamp, id AS operation_id + FROM hive.hafbe_app_operations_view + WHERE op_type_id = 12 AND block_num BETWEEN _from AND _to + ) ops_in_range ) vote_op JOIN hive.hafbe_app_accounts_view hav_w ON hav_w.name = vote_op.witness JOIN hive.hafbe_app_accounts_view hav_v ON hav_v.name = vote_op.voter @@ -248,20 +244,17 @@ BEGIN SELECT hav_a.id AS account_id, hav_p.id AS proxy_id, proxy, timestamp, operation_id FROM ( SELECT - __ops_in_range.value->>'account' AS account, - __ops_in_range.value->>'proxy' AS proxy_account, - TRUE AS proxy, - __ops_in_range.timestamp, __ops_in_range.operation_id - WHERE __ops_in_range.op_type_id = 13 - - UNION - - SELECT - __ops_in_range.value->>'account' AS account, - __ops_in_range.value->>'proxy' AS proxy_account, - FALSE AS proxy, - __ops_in_range.timestamp, __ops_in_range.operation_id - WHERE __ops_in_range.op_type_id = 91 + value->>'account' AS account, + value->>'proxy' AS proxy_account, + CASE WHEN op_type_id = 13 THEN TRUE ELSE FALSE END AS proxy, + timestamp, operation_id + FROM ( + SELECT + (body::JSON)->'value' AS value, + timestamp, id AS operation_id, op_type_id + FROM hive.hafbe_app_operations_view + WHERE op_type_id = ANY('{13,91}') AND block_num BETWEEN _from AND _to + ) ops_in_range ) proxy_op JOIN hive.hafbe_app_accounts_view hav_a ON hav_a.name = proxy_op.account JOIN hive.hafbe_app_accounts_view hav_p ON hav_p.name = proxy_op.proxy_account @@ -291,7 +284,6 @@ BEGIN WHERE proxy IS TRUE ON CONFLICT ON CONSTRAINT pk_current_account_proxies DO UPDATE SET proxy_id = EXCLUDED.proxy_id - RETURNING cap.account_id, cap.proxy_id ) DELETE FROM hafbe_app.current_account_proxies cap USING ( @@ -302,161 +294,173 @@ BEGIN WHERE cap.account_id = spo.account_id; -- add new witnesses per block range - WITH limited_set AS ( - SELECT DISTINCT get_impacted_accounts AS name - FROM hive.get_impacted_accounts(__ops_in_range.body) - WHERE __ops_in_range.op_type_id = ANY('{42,11,7}') - - UNION - - SELECT DISTINCT __ops_in_range.value->>'witness' AS name - WHERE __ops_in_range.op_type_id = 12 + WITH select_witness_names AS ( + SELECT DISTINCT + CASE WHEN op_type_id = 12 THEN + value->>'witness' + ELSE + (SELECT hive.get_impacted_accounts(body)) + END AS name + FROM ( + SELECT body, (body::JSON)->'value' AS value, op_type_id + FROM hive.hafbe_app_operations_view + WHERE op_type_id = ANY('{12,42,11,7}') AND block_num BETWEEN _from AND _to + ) ops_in_range ) INSERT INTO hafbe_app.current_witnesses (witness_id, url, price_feed, bias, feed_age, block_size, signing_key, version) - SELECT hav.id, NULL, NULL, NULL, NULL, NULL, NULL, '1.25.0' - FROM limited_set ls - JOIN hive.hafbe_app_accounts_view hav ON hav.name = ls.name + SELECT hav.id, NULL, NULL, NULL, NULL, NULL, NULL, '1.27.0' + FROM select_witness_names swn + JOIN hive.hafbe_app_accounts_view hav ON hav.name = swn.name ON CONFLICT ON CONSTRAINT pk_current_witnesses DO NOTHING; -- parse props for witnesses table - SELECT INTO __prop_op - cw.witness_id, - bia.value, - bia.op_type_id, bia.timestamp, bia.operation_id - FROM ( + WITH select_witness_prop_ops AS ( SELECT - get_impacted_accounts AS name, - __ops_in_range.value, - __ops_in_range.op_type_id, __ops_in_range.timestamp, __ops_in_range.operation_id - FROM hive.get_impacted_accounts(__ops_in_range.body) - WHERE __ops_in_range.op_type_id = ANY('{42,30,14,11,7}') - ) bia - JOIN hive.hafbe_app_accounts_view hav ON hav.name = bia.name - JOIN hafbe_app.current_witnesses cw ON cw.witness_id = hav.id; - - UPDATE hafbe_app.current_witnesses cw SET url = res.prop_value FROM ( - SELECT prop_value, witness_id + cw.witness_id, + oir.value, + oir.op_type_id, oir.timestamp, oir.operation_id FROM ( SELECT - prop_value, witness_id, operation_id, - ROW_NUMBER() OVER (PARTITION BY witness_id ORDER BY operation_id DESC) AS row_n - FROM ( - SELECT - __prop_op.value->>'url' AS prop_value, - __prop_op.operation_id, __prop_op.witness_id - WHERE __prop_op.op_type_id = 11 + bia.name, + (body::JSON)->'value' AS value, + op_type_id, timestamp, id AS operation_id + FROM hive.hafbe_app_operations_view hov + + JOIN LATERAL ( + SELECT get_impacted_accounts AS name + FROM hive.get_impacted_accounts(hov.body) + ) bia ON TRUE + WHERE op_type_id = ANY('{42,30,14,11,7}') AND block_num BETWEEN _from AND _to + ) oir + JOIN hive.hafbe_app_accounts_view hav ON hav.name = oir.name + JOIN hafbe_app.current_witnesses cw ON cw.witness_id = hav.id + ), - UNION + parse_witness_set_properties_ops AS ( + SELECT + ex_prop.prop_value, ex_prop.prop_name, + timestamp, operation_id, witness_id + FROM select_witness_prop_ops swpo - SELECT - trim(both '"' FROM prop_value::TEXT), - __prop_op.operation_id, __prop_op.witness_id - FROM hive.extract_set_witness_properties(__prop_op.value->>'props') - WHERE prop_name = 'url' AND __prop_op.op_type_id = 42 - ) parsed - WHERE prop_value IS NOT NULL - ) row_count - WHERE row_n = 1 - ) res - WHERE cw.witness_id = res.witness_id; + JOIN LATERAL ( + SELECT + trim(both '"' FROM prop_value::TEXT) AS prop_value, + CASE WHEN prop_name = 'hbd_exchange_rate' THEN 'exchange_rate' ELSE prop_name END AS prop_name + FROM hive.extract_set_witness_properties(swpo.value->>'props') + ) ex_prop ON TRUE + WHERE op_type_id = 42 + ), + + /* + TODO: + -- witness_set_properties_operation may contain old and new signing keys + -- new_signing_key -- key + trim(both '"' FROM + (CASE WHEN ex_res1.prop_value IS NULL THEN ex_res2.prop_value ELSE ex_res1.prop_value END)::TEXT + ), + */ - UPDATE hafbe_app.current_witnesses cw SET - price_feed = (res.prop_value->'base'->>'amount')::NUMERIC / (res.prop_value->'quote'->>'amount')::NUMERIC, - bias = ((res.prop_value->'quote'->>'amount')::NUMERIC - 1000)::NUMERIC, - feed_age = (NOW() - res.timestamp)::INTERVAL - FROM ( - SELECT prop_value::JSON, witness_id, timestamp + parse_witness_update_and_pow_ops AS ( + SELECT + value->>'url' AS prop_value, 'url' AS prop_name, + timestamp, operation_id, witness_id + FROM select_witness_prop_ops + WHERE op_type_id = 11 + + UNION + + SELECT + value->>'block_signing_key' AS prop_value, 'signing_key' AS prop_name, + timestamp, operation_id, witness_id + FROM select_witness_prop_ops + WHERE op_type_id = 11 + + UNION + + SELECT + value->'props'->>'maximum_block_size' AS prop_value, 'block_size' AS prop_name, + timestamp, operation_id, witness_id + FROM select_witness_prop_ops + WHERE op_type_id = ANY('{30,14,11}') + ), + + parse_feed_publish_ops AS ( + SELECT + value->>'exchange_rate' AS prop_value, 'exchange_rate' AS prop_name, + timestamp, operation_id, witness_id + FROM select_witness_prop_ops + WHERE op_type_id = 7 + ), + + stack_parsed_props AS ( + SELECT prop_value, prop_name, timestamp, operation_id, witness_id FROM ( SELECT - prop_value, witness_id, operation_id, timestamp, - ROW_NUMBER() OVER (PARTITION BY witness_id ORDER BY operation_id DESC) AS row_n + ROW_NUMBER() OVER (PARTITION BY witness_id, prop_name ORDER BY operation_id DESC) AS row_n, + prop_value, prop_name, timestamp, operation_id, witness_id FROM ( - SELECT - __prop_op.value->>'exchange_rate' AS prop_value, - __prop_op.operation_id, __prop_op.witness_id, __prop_op.timestamp - WHERE __prop_op.op_type_id = 7 + SELECT prop_value, prop_name, timestamp, operation_id, witness_id + FROM parse_witness_set_properties_ops UNION - SELECT - prop_value::TEXT, - __prop_op.operation_id, __prop_op.witness_id, __prop_op.timestamp - FROM hive.extract_set_witness_properties(__prop_op.value->>'props') - WHERE prop_name = 'hbd_exchange_rate' AND __prop_op.op_type_id = 42 - ) parsed - WHERE prop_value IS NOT NULL - ) row_count - WHERE row_n = 1 - ) res - WHERE cw.witness_id = res.witness_id; - - UPDATE hafbe_app.current_witnesses cw SET block_size = res.prop_value FROM ( - SELECT prop_value::INT, witness_id - FROM ( - SELECT - prop_value, witness_id, operation_id, - ROW_NUMBER() OVER (PARTITION BY witness_id ORDER BY operation_id DESC) AS row_n - FROM ( - SELECT - __prop_op.value->'props'->>'maximum_block_size' AS prop_value, - __prop_op.operation_id, __prop_op.witness_id - WHERE __prop_op.op_type_id = ANY('{30,14,11}') + SELECT prop_value, prop_name, timestamp, operation_id, witness_id + FROM parse_witness_update_and_pow_ops UNION - SELECT - prop_value::TEXT, - __prop_op.operation_id, __prop_op.witness_id - FROM hive.extract_set_witness_properties(__prop_op.value->>'props') - WHERE prop_name = 'maximum_block_size' AND __prop_op.op_type_id = 42 - ) parsed - WHERE prop_value IS NOT NULL + SELECT prop_value, prop_name, timestamp, operation_id, witness_id + FROM parse_feed_publish_ops + ) pp ) row_count WHERE row_n = 1 - ) res - WHERE cw.witness_id = res.witness_id; - - UPDATE hafbe_app.current_witnesses cw SET signing_key = res.prop_value FROM ( - SELECT prop_value, witness_id + ), + + update_witness_url AS ( + UPDATE hafbe_app.current_witnesses cw SET url = spp.url FROM ( + SELECT prop_value AS url, witness_id + FROM stack_parsed_props + WHERE prop_name = 'url' + ) spp + WHERE cw.witness_id = spp.witness_id + ), + + update_witness_exchange_rate_data AS ( + UPDATE hafbe_app.current_witnesses cw SET + price_feed = spp.price_feed, + bias = spp.bias, + feed_age = spp.feed_age FROM ( SELECT - prop_value, witness_id, operation_id, - ROW_NUMBER() OVER (PARTITION BY witness_id ORDER BY operation_id DESC) AS row_n + (prop_value->'base'->>'amount')::NUMERIC / (prop_value->'quote'->>'amount')::NUMERIC AS price_feed, + ((prop_value->'quote'->>'amount')::NUMERIC - 1000)::NUMERIC AS bias, + (NOW() - timestamp)::INTERVAL AS feed_age, + witness_id FROM ( - SELECT - __prop_op.value->>'block_signing_key' AS prop_value, - __prop_op.operation_id, __prop_op.witness_id - WHERE __prop_op.op_type_id = 11 + SELECT (prop_value::JSON) AS prop_value, timestamp, witness_id + FROM stack_parsed_props + WHERE prop_name = 'exchange_rate' + ) vals + ) spp + WHERE cw.witness_id = spp.witness_id + ), - UNION + update_witness_block_size AS ( + UPDATE hafbe_app.current_witnesses cw SET block_size = spp.block_size FROM ( + SELECT prop_value::INT AS block_size, witness_id + FROM stack_parsed_props + WHERE prop_name = 'block_size' + ) spp + WHERE cw.witness_id = spp.witness_id + ) - SELECT - -- witness_set_properties_operation may contain old and new signing keys - trim(both '"' FROM - (CASE WHEN ex_res1.prop_value IS NULL THEN ex_res2.prop_value ELSE ex_res1.prop_value END)::TEXT - ), - operation_id, witness_id - FROM ( - SELECT __prop_op.value, __prop_op.operation_id, __prop_op.witness_id - ) encoded_op - LEFT JOIN LATERAL ( - SELECT prop_value - FROM hive.extract_set_witness_properties(value->>'props') - WHERE prop_name = 'new_signing_key' - ) ex_res1 ON TRUE - LEFT JOIN LATERAL ( - SELECT prop_value - FROM hive.extract_set_witness_properties(value->>'props') - WHERE prop_name = 'key' - ) ex_res2 ON ex_res1.prop_value IS NULL - WHERE __prop_op.op_type_id = 42 - ) parsed - WHERE prop_value IS NOT NULL - ) row_count - WHERE row_n = 1 - ) res - WHERE cw.witness_id = res.witness_id; + UPDATE hafbe_app.current_witnesses cw SET signing_key = spp.signing_key FROM ( + SELECT prop_value AS signing_key, witness_id + FROM stack_parsed_props + WHERE prop_name = 'signing_key' + ) spp + WHERE cw.witness_id = spp.witness_id; -- get impacted vests balance for block range and update account_vests WITH balance_change AS ( -- GitLab From bcaecf4ced878149590950b5460dcb28998be0e0 Mon Sep 17 00:00:00 2001 From: kristupas Date: Tue, 8 Nov 2022 18:20:46 +0000 Subject: [PATCH 71/89] Fixed CTE related prop processing bug #22 --- api/backend.sql | 24 +++- api/views.sql | 14 +++ db/hafbe_app.sql | 294 ++++++++++++++++++++++++++++------------------- run.sh | 2 +- 4 files changed, 209 insertions(+), 125 deletions(-) diff --git a/api/backend.sql b/api/backend.sql index 6458529..89ecdf8 100644 --- a/api/backend.sql +++ b/api/backend.sql @@ -513,7 +513,9 @@ BEGIN SELECT witness_id, name::TEXT AS witness, - url, price_feed, bias, feed_age, block_size, signing_key, version + url, price_feed, bias, + (NOW() - feed_updated_at)::INTERVAL AS feed_age, + block_size, signing_key, version FROM hive.accounts_view hav JOIN hafbe_app.current_witnesses cw ON hav.id = cw.witness_id ORDER BY @@ -603,7 +605,9 @@ BEGIN $query$ SELECT - witness_id, url, price_feed, bias, feed_age, block_size, signing_key, version + witness_id, url, price_feed, bias, + (NOW() - feed_updated_at)::INTERVAL AS feed_age, + block_size, signing_key, version FROM hafbe_app.current_witnesses WHERE %I IS NOT NULL ORDER BY @@ -643,7 +647,9 @@ BEGIN COALESCE(todays_votes.votes_daily_change, 0)::BIGINT, COALESCE(all_votes.voters_num, 0)::INT, COALESCE(todays_votes.voters_num_daily_change, 0)::INT, - price_feed, bias, feed_age, block_size, signing_key, version + price_feed, bias, + (NOW() - feed_updated_at)::INTERVAL, + block_size, signing_key, version FROM hafbe_backend.get_set_of_witnesses_by_name(%L, %L, %L) ls LEFT JOIN ( SELECT witness_id, votes, voters_num @@ -678,7 +684,9 @@ BEGIN COALESCE(todays_votes.votes_daily_change, 0)::BIGINT AS votes_daily_change, ls.voters_num, COALESCE(todays_votes.voters_num_daily_change, 0)::INT AS voters_num_daily_change, - price_feed, bias, feed_age, block_size, signing_key, version + price_feed, bias, + (NOW() - feed_updated_at)::INTERVAL, + block_size, signing_key, version FROM hafbe_backend.get_set_of_witnesses_by_votes(%L, %L, %L, %L) ls JOIN hafbe_app.current_witnesses cw ON cw.witness_id = ls.witness_id LEFT JOIN LATERAL ( @@ -714,7 +722,9 @@ BEGIN ls.votes_daily_change, all_votes.voters_num::INT, ls.voters_num_daily_change, - price_feed, bias, feed_age, block_size, signing_key, version + price_feed, bias, + (NOW() - feed_updated_at)::INTERVAL, + block_size, signing_key, version FROM hafbe_backend.get_set_of_witnesses_by_votes_change(%L, %L, %L, %L, %L) ls JOIN hafbe_app.current_witnesses cw ON cw.witness_id = ls.witness_id JOIN ( @@ -745,7 +755,9 @@ BEGIN COALESCE(todays_votes.votes_daily_change, 0)::BIGINT, COALESCE(all_votes.voters_num, 0)::INT, COALESCE(todays_votes.voters_num_daily_change, 0)::INT, - price_feed, bias, feed_age, block_size, signing_key, version + price_feed, bias, + (NOW() - feed_updated_at)::INTERVAL, + block_size, signing_key, version FROM hafbe_backend.get_set_of_witnesses_by_prop(%L, %L, %L, %L) ls LEFT JOIN ( SELECT witness_id, votes, voters_num diff --git a/api/views.sql b/api/views.sql index 0a0e4a6..6d13b00 100644 --- a/api/views.sql +++ b/api/views.sql @@ -1,5 +1,19 @@ CREATE SCHEMA IF NOT EXISTS hafbe_views AUTHORIZATION hafbe_owner; +CREATE OR REPLACE VIEW hafbe_views.witness_prop_op_view AS +SELECT + bia.name AS witness, + (body::JSON)->'value' AS value, + block_num, op_type_id, timestamp, id AS operation_id +FROM hive.hafbe_app_operations_view hov + +JOIN LATERAL ( + SELECT get_impacted_accounts AS name + FROM hive.get_impacted_accounts(hov.body) +) bia ON TRUE; + +------ + CREATE OR REPLACE VIEW hafbe_views.recursive_account_proxies_view AS WITH proxies1 AS ( SELECT diff --git a/db/hafbe_app.sql b/db/hafbe_app.sql index f0522bd..59f6b8d 100644 --- a/db/hafbe_app.sql +++ b/db/hafbe_app.sql @@ -41,7 +41,7 @@ BEGIN url TEXT, price_feed FLOAT, bias NUMERIC, - feed_age INTERVAL, + feed_updated_at TIMESTAMP, block_size INT, signing_key TEXT, version TEXT, @@ -308,159 +308,217 @@ BEGIN ) ops_in_range ) - INSERT INTO hafbe_app.current_witnesses (witness_id, url, price_feed, bias, feed_age, block_size, signing_key, version) + INSERT INTO hafbe_app.current_witnesses (witness_id, url, price_feed, bias, feed_updated_at, block_size, signing_key, version) SELECT hav.id, NULL, NULL, NULL, NULL, NULL, NULL, '1.27.0' FROM select_witness_names swn JOIN hive.hafbe_app_accounts_view hav ON hav.name = swn.name ON CONFLICT ON CONSTRAINT pk_current_witnesses DO NOTHING; - -- parse props for witnesses table - WITH select_witness_prop_ops AS ( - SELECT - cw.witness_id, - oir.value, - oir.op_type_id, oir.timestamp, oir.operation_id - FROM ( - SELECT - bia.name, - (body::JSON)->'value' AS value, - op_type_id, timestamp, id AS operation_id - FROM hive.hafbe_app_operations_view hov - - JOIN LATERAL ( - SELECT get_impacted_accounts AS name - FROM hive.get_impacted_accounts(hov.body) - ) bia ON TRUE - WHERE op_type_id = ANY('{42,30,14,11,7}') AND block_num BETWEEN _from AND _to - ) oir - JOIN hive.hafbe_app_accounts_view hav ON hav.name = oir.name - JOIN hafbe_app.current_witnesses cw ON cw.witness_id = hav.id + -- parse witness url + WITH select_ops_with_url AS ( + SELECT witness, value, op_type_id, operation_id + FROM hafbe_views.witness_prop_op_view + WHERE op_type_id = ANY('{42,11}') AND block_num BETWEEN _from AND _to ), - parse_witness_set_properties_ops AS ( - SELECT - ex_prop.prop_value, ex_prop.prop_name, - timestamp, operation_id, witness_id - FROM select_witness_prop_ops swpo + select_url_from_set_witness_properties AS ( + SELECT ex_prop.url, operation_id, witness + FROM select_ops_with_url sowu JOIN LATERAL ( - SELECT - trim(both '"' FROM prop_value::TEXT) AS prop_value, - CASE WHEN prop_name = 'hbd_exchange_rate' THEN 'exchange_rate' ELSE prop_name END AS prop_name - FROM hive.extract_set_witness_properties(swpo.value->>'props') + SELECT trim(both '"' FROM prop_value::TEXT) AS url + FROM hive.extract_set_witness_properties(sowu.value->>'props') + WHERE prop_name = 'url' ) ex_prop ON TRUE WHERE op_type_id = 42 ), - /* - TODO: - -- witness_set_properties_operation may contain old and new signing keys - -- new_signing_key -- key - trim(both '"' FROM - (CASE WHEN ex_res1.prop_value IS NULL THEN ex_res2.prop_value ELSE ex_res1.prop_value END)::TEXT - ), - */ - - parse_witness_update_and_pow_ops AS ( - SELECT - value->>'url' AS prop_value, 'url' AS prop_name, - timestamp, operation_id, witness_id - FROM select_witness_prop_ops - WHERE op_type_id = 11 - - UNION + select_url_from_witness_update_op AS ( + SELECT value->>'url' AS url, operation_id, witness + FROM select_ops_with_url + WHERE op_type_id != 42 + ) - SELECT - value->>'block_signing_key' AS prop_value, 'signing_key' AS prop_name, - timestamp, operation_id, witness_id - FROM select_witness_prop_ops - WHERE op_type_id = 11 + UPDATE hafbe_app.current_witnesses cw SET url = ops.url FROM ( + SELECT hav.id AS witness_id, url + FROM ( + SELECT + url, witness, + ROW_NUMBER() OVER (PARTITION BY witness ORDER BY operation_id DESC) AS row_n + FROM ( + SELECT url, operation_id, witness + FROM select_url_from_set_witness_properties - UNION + UNION - SELECT - value->'props'->>'maximum_block_size' AS prop_value, 'block_size' AS prop_name, - timestamp, operation_id, witness_id - FROM select_witness_prop_ops - WHERE op_type_id = ANY('{30,14,11}') + SELECT url, operation_id, witness + FROM select_url_from_witness_update_op + ) sp + WHERE url IS NOT NULL + ) prop + JOIN hive.accounts_view hav ON hav.name = prop.witness + WHERE row_n = 1 + ) ops + WHERE cw.witness_id = ops.witness_id; + + -- parse witness exchange_rate + WITH select_ops_with_exchange_rate AS ( + SELECT witness, value, op_type_id, operation_id, timestamp + FROM hafbe_views.witness_prop_op_view + WHERE op_type_id = ANY('{42,7}') AND block_num BETWEEN _from AND _to ), - parse_feed_publish_ops AS ( - SELECT - value->>'exchange_rate' AS prop_value, 'exchange_rate' AS prop_name, - timestamp, operation_id, witness_id - FROM select_witness_prop_ops - WHERE op_type_id = 7 + select_exchange_rate_from_set_witness_properties AS ( + SELECT ex_prop.exchange_rate, operation_id, timestamp, witness + FROM select_ops_with_exchange_rate sower + + JOIN LATERAL ( + SELECT trim(both '"' FROM prop_value::TEXT) AS exchange_rate + FROM hive.extract_set_witness_properties(sower.value->>'props') + WHERE prop_name = 'hbd_exchange_rate' + ) ex_prop ON TRUE + WHERE op_type_id = 42 ), - stack_parsed_props AS ( - SELECT prop_value, prop_name, timestamp, operation_id, witness_id + select_exchange_rate_from_feed_publish_op AS ( + SELECT value->>'exchange_rate' AS exchange_rate, operation_id, timestamp, witness + FROM select_ops_with_exchange_rate + WHERE op_type_id != 42 + ) + + UPDATE hafbe_app.current_witnesses cw SET + price_feed = ops.price_feed, + bias = ops.bias, + feed_updated_at = ops.feed_updated_at + FROM ( + SELECT + hav.id AS witness_id, + (exchange_rate->'base'->>'amount')::NUMERIC / (exchange_rate->'quote'->>'amount')::NUMERIC AS price_feed, + ((exchange_rate->'quote'->>'amount')::NUMERIC - 1000)::NUMERIC AS bias, + timestamp AS feed_updated_at FROM ( SELECT - ROW_NUMBER() OVER (PARTITION BY witness_id, prop_name ORDER BY operation_id DESC) AS row_n, - prop_value, prop_name, timestamp, operation_id, witness_id + exchange_rate::JSON, witness, timestamp, + ROW_NUMBER() OVER (PARTITION BY witness ORDER BY operation_id DESC) AS row_n FROM ( - SELECT prop_value, prop_name, timestamp, operation_id, witness_id - FROM parse_witness_set_properties_ops + SELECT exchange_rate, operation_id, timestamp, witness + FROM select_exchange_rate_from_set_witness_properties UNION - SELECT prop_value, prop_name, timestamp, operation_id, witness_id - FROM parse_witness_update_and_pow_ops + SELECT exchange_rate, operation_id, timestamp, witness + FROM select_exchange_rate_from_feed_publish_op + ) sp + WHERE exchange_rate IS NOT NULL + ) prop + JOIN hive.accounts_view hav ON hav.name = prop.witness + WHERE row_n = 1 + ) ops + WHERE cw.witness_id = ops.witness_id; + + -- parse witness block_size + WITH select_ops_with_block_size AS ( + SELECT witness, value, op_type_id, operation_id + FROM hafbe_views.witness_prop_op_view + WHERE op_type_id = ANY('{42,11,30,14}') AND block_num BETWEEN _from AND _to + ), + + select_block_size_from_set_witness_properties AS ( + SELECT ex_prop.block_size, operation_id, witness + FROM select_ops_with_block_size sowbs + + JOIN LATERAL ( + SELECT trim(both '"' FROM prop_value::TEXT) AS block_size + FROM hive.extract_set_witness_properties(sowbs.value->>'props') + WHERE prop_name = 'maximum_block_size' + ) ex_prop ON TRUE + WHERE op_type_id = 42 + ), + + select_block_size_from_witness_update_op AS ( + SELECT value->'props'->>'maximum_block_size' AS block_size, operation_id, witness + FROM select_ops_with_block_size + WHERE op_type_id != 42 + ) + + UPDATE hafbe_app.current_witnesses cw SET block_size = ops.block_size FROM ( + SELECT hav.id AS witness_id, block_size + FROM ( + SELECT + block_size::INT, witness, + ROW_NUMBER() OVER (PARTITION BY witness ORDER BY operation_id DESC) AS row_n + FROM ( + SELECT block_size, operation_id, witness + FROM select_block_size_from_set_witness_properties UNION - SELECT prop_value, prop_name, timestamp, operation_id, witness_id - FROM parse_feed_publish_ops - ) pp - ) row_count + SELECT block_size, operation_id, witness + FROM select_block_size_from_witness_update_op + ) sp + WHERE block_size IS NOT NULL + ) prop + JOIN hive.accounts_view hav ON hav.name = prop.witness WHERE row_n = 1 + ) ops + WHERE cw.witness_id = ops.witness_id; + + -- parse witness signing_key + WITH select_ops_with_signing_key AS ( + SELECT witness, value, op_type_id, operation_id + FROM hafbe_views.witness_prop_op_view + WHERE op_type_id = ANY('{42,11}') AND block_num BETWEEN _from AND _to ), - update_witness_url AS ( - UPDATE hafbe_app.current_witnesses cw SET url = spp.url FROM ( - SELECT prop_value AS url, witness_id - FROM stack_parsed_props - WHERE prop_name = 'url' - ) spp - WHERE cw.witness_id = spp.witness_id + select_signing_key_from_set_witness_properties AS ( + SELECT + CASE WHEN ex_prop2.signing_key IS NULL THEN ex_prop1.signing_key ELSE ( + CASE WHEN ex_prop1.signing_key IS NULL THEN ex_prop2.signing_key ELSE ex_prop1.signing_key END + ) END AS signing_key, + operation_id, witness + FROM select_ops_with_signing_key sowsk + + LEFT JOIN LATERAL ( + SELECT trim(both '"' FROM prop_value::TEXT) AS signing_key + FROM hive.extract_set_witness_properties(sowsk.value->>'props') + WHERE prop_name = 'new_signing_key' + ) ex_prop1 ON TRUE + + LEFT JOIN LATERAL ( + SELECT trim(both '"' FROM prop_value::TEXT) AS signing_key + FROM hive.extract_set_witness_properties(sowsk.value->>'props') + WHERE prop_name = 'key' + ) ex_prop2 ON TRUE + WHERE op_type_id = 42 ), - update_witness_exchange_rate_data AS ( - UPDATE hafbe_app.current_witnesses cw SET - price_feed = spp.price_feed, - bias = spp.bias, - feed_age = spp.feed_age + select_signing_key_from_witness_update_op AS ( + SELECT value->>'block_signing_key' AS signing_key, operation_id, witness + FROM select_ops_with_signing_key + WHERE op_type_id != 42 + ) + + UPDATE hafbe_app.current_witnesses cw SET signing_key = ops.signing_key FROM ( + SELECT hav.id AS witness_id, signing_key FROM ( SELECT - (prop_value->'base'->>'amount')::NUMERIC / (prop_value->'quote'->>'amount')::NUMERIC AS price_feed, - ((prop_value->'quote'->>'amount')::NUMERIC - 1000)::NUMERIC AS bias, - (NOW() - timestamp)::INTERVAL AS feed_age, - witness_id + signing_key, witness, + ROW_NUMBER() OVER (PARTITION BY witness ORDER BY operation_id DESC) AS row_n FROM ( - SELECT (prop_value::JSON) AS prop_value, timestamp, witness_id - FROM stack_parsed_props - WHERE prop_name = 'exchange_rate' - ) vals - ) spp - WHERE cw.witness_id = spp.witness_id - ), + SELECT signing_key, operation_id, witness + FROM select_signing_key_from_set_witness_properties - update_witness_block_size AS ( - UPDATE hafbe_app.current_witnesses cw SET block_size = spp.block_size FROM ( - SELECT prop_value::INT AS block_size, witness_id - FROM stack_parsed_props - WHERE prop_name = 'block_size' - ) spp - WHERE cw.witness_id = spp.witness_id - ) + UNION - UPDATE hafbe_app.current_witnesses cw SET signing_key = spp.signing_key FROM ( - SELECT prop_value AS signing_key, witness_id - FROM stack_parsed_props - WHERE prop_name = 'signing_key' - ) spp - WHERE cw.witness_id = spp.witness_id; + SELECT signing_key, operation_id, witness + FROM select_signing_key_from_witness_update_op + ) sp + WHERE signing_key IS NOT NULL + ) prop + JOIN hive.accounts_view hav ON hav.name = prop.witness + WHERE row_n = 1 + ) ops + WHERE cw.witness_id = ops.witness_id; -- get impacted vests balance for block range and update account_vests WITH balance_change AS ( @@ -644,13 +702,13 @@ BEGIN RAISE NOTICE 'Updating witnesses caches'; WITH select_voters_stats AS ( - SELECT witness_id, voter_id, vests, account_vests, proxied_vests + SELECT witness_id, voter_id, vests, account_vests, proxied_vests, timestamp FROM hafbe_views.voters_stats_view ), insert_witness_voters_stats_cache AS ( - INSERT INTO hafbe_app.witness_voters_stats_cache (witness_id, voter_id, vests, account_vests, proxied_vests) - SELECT witness_id, voter_id, vests, account_vests, proxied_vests + INSERT INTO hafbe_app.witness_voters_stats_cache (witness_id, voter_id, vests, account_vests, proxied_vests, timestamp) + SELECT witness_id, voter_id, vests, account_vests, proxied_vests, timestamp FROM select_voters_stats ON CONFLICT ON CONSTRAINT pk_witness_voters_stats_cache DO UPDATE SET vests = EXCLUDED.vests, diff --git a/run.sh b/run.sh index c3f6d29..2adb372 100755 --- a/run.sh +++ b/run.sh @@ -18,9 +18,9 @@ continue_processing() { } drop_db() { + sudo -nu $owner_role psql -d $DB_NAME -a -v "ON_ERROR_STOP=on" -c "DROP SCHEMA IF EXISTS hafbe_views CASCADE;" sudo -nu $admin_role psql -d $DB_NAME -a -v "ON_ERROR_STOP=on" -c "SELECT hive.app_remove_context('hafbe_app');" sudo -nu $owner_role psql -d $DB_NAME -a -v "ON_ERROR_STOP=on" -c "DROP SCHEMA IF EXISTS hafbe_app CASCADE;" - sudo -nu $owner_role psql -d $DB_NAME -a -v "ON_ERROR_STOP=on" -c "DROP SCHEMA IF EXISTS hafbe_views CASCADE;" } create_hafbe_indexes() { -- GitLab From 009c56e8b97c5065c84158f0d4c4557b69c28261 Mon Sep 17 00:00:00 2001 From: kristupas Date: Tue, 8 Nov 2022 20:21:09 +0000 Subject: [PATCH 72/89] Added 'rank' to 'get_witnesses()' #22 --- api/backend.sql | 71 ++++++++++++++++++++++++----------- api/endpoints.sql | 2 +- api/types.sql | 2 + db/hafbe_app.sql | 94 ++++++++++++++++++++++++++++------------------- 4 files changed, 108 insertions(+), 61 deletions(-) diff --git a/api/backend.sql b/api/backend.sql index 89ecdf8..4db16e8 100644 --- a/api/backend.sql +++ b/api/backend.sql @@ -542,9 +542,9 @@ $function$ BEGIN RETURN QUERY EXECUTE format( $query$ - SELECT witness_id, votes, voters_num + SELECT witness_id, rank, votes, voters_num FROM ( - SELECT witness_id, votes, voters_num + SELECT witness_id, rank, votes, voters_num FROM hafbe_app.witness_votes_cache ) votes_sum ORDER BY @@ -572,13 +572,16 @@ BEGIN RETURN QUERY EXECUTE format( $query$ - SELECT - witness_id, - SUM(vests)::BIGINT AS votes_daily_change, - COUNT(1)::INT AS voters_num_daily_change - FROM hafbe_views.voters_stats_change_view vscv - WHERE timestamp >= %L - GROUP BY witness_id + SELECT witness_id, votes_daily_change, voters_num_daily_change + FROM ( + SELECT + witness_id, + SUM(vests)::BIGINT AS votes_daily_change, + COUNT(1)::INT AS voters_num_daily_change + FROM hafbe_views.voters_stats_change_view + WHERE timestamp >= %L + GROUP BY witness_id + ) vscv ORDER BY (CASE WHEN %L = 'desc' THEN %I ELSE NULL END) DESC, (CASE WHEN %L = 'asc' THEN %I ELSE NULL END) ASC @@ -642,17 +645,15 @@ BEGIN $query$ SELECT - witness, url, + witness, rank::INT, url, COALESCE(all_votes.votes, 0)::NUMERIC, COALESCE(todays_votes.votes_daily_change, 0)::BIGINT, COALESCE(all_votes.voters_num, 0)::INT, COALESCE(todays_votes.voters_num_daily_change, 0)::INT, - price_feed, bias, - (NOW() - feed_updated_at)::INTERVAL, - block_size, signing_key, version + price_feed, bias, feed_age, block_size, signing_key, version FROM hafbe_backend.get_set_of_witnesses_by_name(%L, %L, %L) ls LEFT JOIN ( - SELECT witness_id, votes, voters_num + SELECT witness_id, rank, votes, voters_num FROM hafbe_app.witness_votes_cache ) all_votes ON all_votes.witness_id = ls.witness_id LEFT JOIN LATERAL ( @@ -673,13 +674,41 @@ BEGIN _order_is, _order_by, _order_is, _order_by ); + ELSIF _order_by = 'rank' THEN + + RETURN QUERY SELECT + hav.name::TEXT, rank::INT, url, + ls.votes, + COALESCE(todays_votes.votes_daily_change, 0)::BIGINT, + ls.voters_num, + COALESCE(todays_votes.voters_num_daily_change, 0)::INT, + price_feed, bias, + (NOW() - feed_updated_at)::INTERVAL, + block_size, signing_key, version + FROM hafbe_app.witness_votes_cache ls + JOIN hafbe_app.current_witnesses cw ON cw.witness_id = ls.witness_id + LEFT JOIN LATERAL ( + SELECT + vscv.witness_id, + SUM(vscv.vests) AS votes_daily_change, + COUNT(1) AS voters_num_daily_change + FROM hafbe_views.voters_stats_change_view vscv + WHERE vscv.timestamp >= __today AND vscv.witness_id = ls.witness_id + GROUP BY vscv.witness_id + ) todays_votes ON TRUE + JOIN hive.accounts_view ON hav.id = ls.witness_id + ORDER BY + (CASE WHEN _order_is = 'desc' THEN _order_by ELSE NULL END) DESC, + (CASE WHEN _order_is = 'asc' THEN _order_by ELSE NULL END) ASC + LIMIT _limit; + ELSIF _order_by = ANY('{votes,voters_num}'::TEXT[]) THEN RETURN QUERY EXECUTE format( $query$ SELECT - hav.name::TEXT, url, + hav.name::TEXT, rank::INT, url, ls.votes, COALESCE(todays_votes.votes_daily_change, 0)::BIGINT AS votes_daily_change, ls.voters_num, @@ -717,7 +746,7 @@ BEGIN $query$ SELECT - hav.name::TEXT, url, + hav.name::TEXT, rank::INT, url, all_votes.votes::NUMERIC, ls.votes_daily_change, all_votes.voters_num::INT, @@ -728,7 +757,7 @@ BEGIN FROM hafbe_backend.get_set_of_witnesses_by_votes_change(%L, %L, %L, %L, %L) ls JOIN hafbe_app.current_witnesses cw ON cw.witness_id = ls.witness_id JOIN ( - SELECT witness_id, votes, voters_num + SELECT witness_id, rank, votes, voters_num FROM hafbe_app.witness_votes_cache ) all_votes ON all_votes.witness_id = ls.witness_id JOIN ( @@ -750,17 +779,15 @@ BEGIN $query$ SELECT - hav.name::TEXT, url, + hav.name::TEXT, rank::INT, url, COALESCE(all_votes.votes, 0)::NUMERIC, COALESCE(todays_votes.votes_daily_change, 0)::BIGINT, COALESCE(all_votes.voters_num, 0)::INT, COALESCE(todays_votes.voters_num_daily_change, 0)::INT, - price_feed, bias, - (NOW() - feed_updated_at)::INTERVAL, - block_size, signing_key, version + price_feed, bias, feed_age, block_size, signing_key, version FROM hafbe_backend.get_set_of_witnesses_by_prop(%L, %L, %L, %L) ls LEFT JOIN ( - SELECT witness_id, votes, voters_num + SELECT witness_id, rank, votes, voters_num FROM hafbe_app.witness_votes_cache ) all_votes ON all_votes.witness_id = ls.witness_id LEFT JOIN LATERAL ( diff --git a/api/endpoints.sql b/api/endpoints.sql index 76ee5a3..39c07bc 100644 --- a/api/endpoints.sql +++ b/api/endpoints.sql @@ -346,7 +346,7 @@ BEGIN END IF; IF _order_by NOT SIMILAR TO - '(witness|url|votes|votes_daily_change|voters_num|voters_num_daily_change|price_feed|bias|feed_age|block_size|signing_key|version)' THEN + '(witness|rank|url|votes|votes_daily_change|voters_num|voters_num_daily_change|price_feed|bias|feed_age|block_size|signing_key|version)' THEN RETURN hafbe_exceptions.raise_no_such_column_exception(_order_by); END IF; IF _order_by IS NULL THEN diff --git a/api/types.sql b/api/types.sql index ead041e..c28427b 100644 --- a/api/types.sql +++ b/api/types.sql @@ -88,6 +88,7 @@ CREATE TYPE hafbe_types.witnesses_by_name AS ( CREATE TYPE hafbe_types.witnesses_by_votes AS ( witness_id INT, + rank INT, votes NUMERIC, voters_num INT ); @@ -111,6 +112,7 @@ CREATE TYPE hafbe_types.witnesses_by_prop AS ( CREATE TYPE hafbe_types.witnesses AS ( witness TEXT, + rank INT, url TEXT, votes NUMERIC, votes_daily_change BIGINT, diff --git a/db/hafbe_app.sql b/db/hafbe_app.sql index 59f6b8d..78c6d5c 100644 --- a/db/hafbe_app.sql +++ b/db/hafbe_app.sql @@ -98,20 +98,21 @@ BEGIN VALUES ('1 hour', to_timestamp(0)); CREATE TABLE IF NOT EXISTS hafbe_app.witness_voters_stats_cache ( - witness_id INT, - voter_id INT, - vests NUMERIC, - account_vests NUMERIC, - proxied_vests NUMERIC, - timestamp TIMESTAMP, + witness_id INT NOT NULL, + voter_id INT NOT NULL, + vests NUMERIC NOT NULL, + account_vests NUMERIC NOT NULL, + proxied_vests NUMERIC NOT NULL, + timestamp TIMESTAMP NOT NULL, CONSTRAINT pk_witness_voters_stats_cache PRIMARY KEY (witness_id, voter_id) ); CREATE TABLE IF NOT EXISTS hafbe_app.witness_votes_cache ( - witness_id INT, - votes NUMERIC, - voters_num INT, + witness_id INT NOT NULL, + rank INT NOT NULL, + votes NUMERIC NOT NULL, + voters_num INT NOT NULL, CONSTRAINT pk_witness_votes_cache PRIMARY KEY (witness_id) ); @@ -638,6 +639,46 @@ END $$ ; +CREATE OR REPLACE PROCEDURE hafbe_app.update_witnesses_cache() +AS +$function$ +BEGIN + RAISE NOTICE 'Updating witnesses caches'; + + INSERT INTO hafbe_app.witness_voters_stats_cache (witness_id, voter_id, vests, account_vests, proxied_vests, timestamp) + SELECT witness_id, voter_id, vests, account_vests, proxied_vests, timestamp + FROM hafbe_views.voters_stats_view + ON CONFLICT ON CONSTRAINT pk_witness_voters_stats_cache DO UPDATE SET + vests = EXCLUDED.vests, + account_vests = EXCLUDED.account_vests, + proxied_vests = EXCLUDED.proxied_vests, + timestamp = EXCLUDED.timestamp + ; + + INSERT INTO hafbe_app.witness_votes_cache (witness_id, rank, votes, voters_num) + SELECT witness_id, RANK() OVER (ORDER BY votes DESC), votes, voters_num + FROM ( + SELECT + witness_id, + SUM(vests) AS votes, + COUNT(1) AS voters_num + FROM hafbe_views.voters_stats_view + GROUP BY witness_id + ) vsv + ON CONFLICT ON CONSTRAINT pk_witness_votes_cache DO UPDATE SET + votes = EXCLUDED.votes, + voters_num = EXCLUDED.voters_num + ; + + UPDATE hafbe_app.witnesses_cache_config SET last_updated_at = NOW(); +END +$function$ +LANGUAGE 'plpgsql' +SET JIT=OFF +SET join_collapse_limit=16 +SET from_collapse_limit=16 +; + /** Application entry point, which: - defines its data schema, - creates HAF application context, @@ -686,6 +727,10 @@ BEGIN END IF; RAISE NOTICE 'Attempting to process block range: <%,%>', __next_block_range.first_block, __next_block_range.last_block; + + IF __next_block_range.first_block >= 1000000 THEN + __next_block_range.first_block := __next_block_range.last_block; + END IF; IF __next_block_range.first_block != __next_block_range.last_block THEN CALL hafbe_app.do_massive_processing(_appContext, __next_block_range.first_block, __next_block_range.last_block, 100, __last_block); @@ -694,39 +739,12 @@ BEGIN CALL hafbe_app.processBlock(__next_block_range.last_block); __last_block := __next_block_range.last_block; END IF; - + IF __next_block_range.first_block = __next_block_range.last_block AND (NOW() - (SELECT last_updated_at FROM hafbe_app.witnesses_cache_config LIMIT 1)) >= (SELECT update_interval FROM hafbe_app.witnesses_cache_config LIMIT 1) THEN - RAISE NOTICE 'Updating witnesses caches'; - - WITH select_voters_stats AS ( - SELECT witness_id, voter_id, vests, account_vests, proxied_vests, timestamp - FROM hafbe_views.voters_stats_view - ), - - insert_witness_voters_stats_cache AS ( - INSERT INTO hafbe_app.witness_voters_stats_cache (witness_id, voter_id, vests, account_vests, proxied_vests, timestamp) - SELECT witness_id, voter_id, vests, account_vests, proxied_vests, timestamp - FROM select_voters_stats - ON CONFLICT ON CONSTRAINT pk_witness_voters_stats_cache DO UPDATE SET - vests = EXCLUDED.vests, - account_vests = EXCLUDED.account_vests, - proxied_vests = EXCLUDED.proxied_vests, - timestamp = EXCLUDED.timestamp - ) - - INSERT INTO hafbe_app.witness_votes_cache (witness_id, votes, voters_num) - SELECT witness_id, SUM(vests), COUNT(1) - FROM select_voters_stats - GROUP BY witness_id - ON CONFLICT ON CONSTRAINT pk_witness_votes_cache DO UPDATE SET - votes = EXCLUDED.votes, - voters_num = EXCLUDED.voters_num - ; - - UPDATE hafbe_app.witnesses_cache_config SET last_updated_at = NOW(); + CALL hafbe_app.update_witnesses_cache(); END IF; -- GitLab From 6e49dfdebf637ab8527a3356b961bfef143cafe4 Mon Sep 17 00:00:00 2001 From: kristupas Date: Wed, 9 Nov 2022 00:42:16 +0000 Subject: [PATCH 73/89] Replaced helper functions with CTE statements in backend #22 --- api/backend.sql | 515 ++++++++++++++++-------------------------------- api/types.sql | 65 ------ 2 files changed, 172 insertions(+), 408 deletions(-) diff --git a/api/backend.sql b/api/backend.sql index 4db16e8..ceab7ea 100644 --- a/api/backend.sql +++ b/api/backend.sql @@ -232,67 +232,6 @@ SET from_collapse_limit=16 witness voters */ -CREATE FUNCTION hafbe_backend.get_set_of_witness_voters_by_name(_witness_id INT, _limit INT, _offset INT, _order_is TEXT) -RETURNS SETOF hafbe_types.witness_voters_by_name -AS -$function$ -BEGIN - RETURN QUERY EXECUTE format( - $query$ - - SELECT cwv.voter_id, hav.name::TEXT AS voter - FROM hafbe_app.current_witness_votes cwv - JOIN LATERAL ( - SELECT name - FROM hive.accounts_view - WHERE id = cwv.voter_id - ) hav ON TRUE - WHERE cwv.witness_id = %L - ORDER BY - (CASE WHEN %L = 'desc' THEN hav.name ELSE NULL END) DESC, - (CASE WHEN %L = 'asc' THEN hav.name ELSE NULL END) ASC - OFFSET %L - LIMIT %L - - $query$, - _witness_id, _order_is, _order_is, _offset, _limit - ); -END -$function$ -LANGUAGE 'plpgsql' STABLE -SET JIT=OFF -SET join_collapse_limit=16 -SET from_collapse_limit=16 -; - -CREATE FUNCTION hafbe_backend.get_set_of_witness_voters_by_vests(_witness_id INT, _limit INT, _offset INT, _order_by TEXT, _order_is TEXT) -RETURNS SETOF hafbe_types.witness_voters_by_vests -AS -$function$ -BEGIN - RETURN QUERY EXECUTE format( - $query$ - - SELECT voter_id, vests, account_vests, proxied_vests, timestamp - FROM hafbe_app.witness_voters_stats_cache - WHERE witness_id = %L - ORDER BY - (CASE WHEN %L = 'desc' THEN %I ELSE NULL END) DESC, - (CASE WHEN %L = 'asc' THEN %I ELSE NULL END) ASC - OFFSET %L - LIMIT %L - - $query$, - _witness_id, _order_is, _order_by, _order_is, _order_by, _offset, _limit - ); -END -$function$ -LANGUAGE 'plpgsql' STABLE -SET JIT=OFF -SET join_collapse_limit=16 -SET from_collapse_limit=16 -; - CREATE FUNCTION hafbe_backend.get_set_of_witness_voters(_witness_id INT, _limit INT, _offset INT, _order_by TEXT, _order_is TEXT) RETURNS SETOF hafbe_types.witness_voters AS @@ -303,41 +242,67 @@ BEGIN RETURN QUERY EXECUTE format( $query$ - SELECT voter, vsv.vests, vsv.account_vests::NUMERIC, vsv.proxied_vests, vsv.timestamp - FROM hafbe_backend.get_set_of_witness_voters_by_name(%L, %L, %L, %L) ls + WITH limited_set AS ( + SELECT cwv.voter_id, hav.name::TEXT AS voter + FROM hafbe_app.current_witness_votes cwv + + JOIN LATERAL ( + SELECT name + FROM hive.accounts_view + WHERE id = cwv.voter_id + ) hav ON TRUE + WHERE cwv.witness_id = %L + ORDER BY + (CASE WHEN %L = 'desc' THEN hav.name ELSE NULL END) DESC, + (CASE WHEN %L = 'asc' THEN hav.name ELSE NULL END) ASC + OFFSET %L + LIMIT %L + ) + + SELECT ls.voter, vsv.vests, vsv.account_vests::NUMERIC, vsv.proxied_vests, vsv.timestamp + FROM limited_set ls + JOIN ( SELECT voter_id, vests, account_vests, proxied_vests, timestamp FROM hafbe_app.witness_voters_stats_cache WHERE witness_id = %L ) vsv ON vsv.voter_id = ls.voter_id ORDER BY - (CASE WHEN %L = 'desc' THEN %I ELSE NULL END) DESC, - (CASE WHEN %L = 'asc' THEN %I ELSE NULL END) ASC + (CASE WHEN %L = 'desc' THEN ls.voter ELSE NULL END) DESC, + (CASE WHEN %L = 'asc' THEN ls.voter ELSE NULL END) ASC ; $query$, - _witness_id, _limit, _offset, _order_is, - _witness_id, _order_is, _order_by, _order_is, _order_by + _witness_id, _order_is, _order_is, _offset, _limit, + _witness_id, _order_is, _order_is ) res; - ELSIF _order_by = ANY('{vests,account_vests,proxied_vests,timestamp}'::TEXT[]) THEN + ELSE RETURN QUERY EXECUTE format( $query$ + WITH limited_set AS ( + SELECT voter_id, vests, account_vests, proxied_vests, timestamp + FROM hafbe_app.witness_voters_stats_cache + WHERE witness_id = %L + ORDER BY + (CASE WHEN %L = 'desc' THEN %I ELSE NULL END) DESC, + (CASE WHEN %L = 'asc' THEN %I ELSE NULL END) ASC + OFFSET %L + LIMIT %L + ) + SELECT hav.name::TEXT, ls.vests, ls.account_vests, ls.proxied_vests, ls.timestamp - FROM hafbe_backend.get_set_of_witness_voters_by_vests(%L, %L, %L, %L, %L) ls - JOIN ( - SELECT id, name - FROM hive.accounts_view - ) hav ON hav.id = ls.voter_id + FROM limited_set ls + JOIN hive.accounts_view hav ON hav.id = ls.voter_id ORDER BY (CASE WHEN %L = 'desc' THEN %I ELSE NULL END) DESC, (CASE WHEN %L = 'asc' THEN %I ELSE NULL END) ASC ; $query$, - _witness_id, _limit, _offset, _order_by, _order_is, + _witness_id, _order_is, _order_by, _order_is, _order_by, _offset, _limit, _order_is, _order_by, _order_is, _order_by ) res; @@ -374,69 +339,6 @@ END $$ ; -CREATE FUNCTION hafbe_backend.get_set_of_witness_voters_daily_change_by_name(_witness_id INT, _limit INT, _offset INT, _order_is TEXT, _today DATE) -RETURNS SETOF hafbe_types.witness_voters_daily_change_by_name -AS -$function$ -BEGIN - RETURN QUERY EXECUTE format( - $query$ - - SELECT wvh.witness_id, wvh.voter_id, hav.name::TEXT, wvh.approve - FROM hafbe_app.witness_votes_history wvh - JOIN LATERAL ( - SELECT name - FROM hive.accounts_view - WHERE id = wvh.voter_id - ) hav ON TRUE - WHERE wvh.witness_id = %L AND wvh.timestamp >= %L - ORDER BY - (CASE WHEN %L = 'desc' THEN hav.name ELSE NULL END) DESC, - (CASE WHEN %L = 'asc' THEN hav.name ELSE NULL END) ASC - OFFSET %L - LIMIT %L - - $query$, - _witness_id, _today, - _order_is, _order_is, _offset, _limit - ); -END -$function$ -LANGUAGE 'plpgsql' STABLE -SET JIT=OFF -SET join_collapse_limit=16 -SET from_collapse_limit=16 -; - -CREATE FUNCTION hafbe_backend.get_set_of_witness_voters_daily_change_by_vests(_witness_id INT, _limit INT, _offset INT, _order_by TEXT, _order_is TEXT, _today DATE) -RETURNS SETOF hafbe_types.witness_voters_daily_change_by_vests -AS -$function$ -BEGIN - RETURN QUERY EXECUTE format( - $query$ - - SELECT voter_id, vests::BIGINT, account_vests::BIGINT, proxied_vests::BIGINT, timestamp, approve - FROM hafbe_views.voters_stats_change_view - WHERE witness_id = %L AND timestamp >= %L - ORDER BY - (CASE WHEN %L = 'desc' THEN %I ELSE NULL END) DESC, - (CASE WHEN %L = 'asc' THEN %I ELSE NULL END) ASC - OFFSET %L - LIMIT %L - - $query$, - _witness_id, _today, - _order_is, _order_by, _order_is, _order_by, _offset, _limit - ); -END -$function$ -LANGUAGE 'plpgsql' STABLE -SET JIT=OFF -SET join_collapse_limit=16 -SET from_collapse_limit=16 -; - CREATE FUNCTION hafbe_backend.get_set_of_witness_voters_daily_change(_witness_id INT, _limit INT, _offset INT, _order_by TEXT, _order_is TEXT) RETURNS SETOF hafbe_types.witness_voters_daily_change AS @@ -451,42 +353,73 @@ BEGIN RETURN QUERY EXECUTE format( $query$ - SELECT ls.voter, ls.approve, vscv.vests::BIGINT, vscv.account_vests::BIGINT, vscv.proxied_vests::BIGINT, vscv.timestamp - FROM hafbe_backend.get_set_of_witness_voters_daily_change_by_name(%L, %L, %L, %L, %L) ls - JOIN ( + WITH limited_set AS ( + SELECT wvh.voter_id, hav.name::TEXT AS voter, wvh.approve + FROM hafbe_app.witness_votes_history wvh + JOIN LATERAL ( + SELECT name + FROM hive.accounts_view + WHERE id = wvh.voter_id + ) hav ON TRUE + WHERE wvh.witness_id = %L AND wvh.timestamp >= %L + ORDER BY + (CASE WHEN %L = 'desc' THEN hav.name ELSE NULL END) DESC, + (CASE WHEN %L = 'asc' THEN hav.name ELSE NULL END) ASC + OFFSET %L + LIMIT %L + ) + + SELECT + ls.voter, ls.approve, + COALESCE(vscv.vests, 0)::BIGINT, + COALESCE(vscv.account_vests, 0)::BIGINT, + COALESCE(vscv.proxied_vests, 0)::BIGINT, + vscv.timestamp + FROM limited_set ls + LEFT JOIN ( SELECT voter_id, vests, account_vests, proxied_vests, timestamp - FROM hafbe_views.voters_stats_change_view vscv + FROM hafbe_views.voters_stats_change_view WHERE witness_id = %L AND timestamp >= %L ) vscv ON vscv.voter_id = ls.voter_id ORDER BY - (CASE WHEN %L = 'desc' THEN %I ELSE NULL END) DESC, - (CASE WHEN %L = 'asc' THEN %I ELSE NULL END) ASC + (CASE WHEN %L = 'desc' THEN ls.voter ELSE NULL END) DESC, + (CASE WHEN %L = 'asc' THEN ls.voter ELSE NULL END) ASC ; $query$, - _witness_id, _limit, _offset, _order_is, __today, _witness_id, __today, - _order_is, _order_by, _order_is, _order_by + _order_is, _order_is, _offset, _limit, + _witness_id, __today, + _order_is, _order_is ) res; - ELSIF _order_by = ANY('{vests,account_vests,proxied_vests,timestamp}'::TEXT[]) THEN + ELSE RETURN QUERY EXECUTE format( $query$ + WITH limited_set AS ( + SELECT voter_id, vests::BIGINT, account_vests::BIGINT, proxied_vests::BIGINT, timestamp, approve + FROM hafbe_views.voters_stats_change_view + WHERE witness_id = %L AND timestamp >= %L + ORDER BY + (CASE WHEN %L = 'desc' THEN %I ELSE NULL END) DESC, + (CASE WHEN %L = 'asc' THEN %I ELSE NULL END) ASC + OFFSET %L + LIMIT %L + ) + SELECT hav.name::TEXT, ls.approve, ls.vests, ls.account_vests, ls.proxied_vests, ls.timestamp - FROM hafbe_backend.get_set_of_witness_voters_daily_change_by_vests(%L, %L, %L, %L, %L, %L) ls - JOIN ( - SELECT id, name - FROM hive.accounts_view - ) hav ON hav.id = ls.voter_id + FROM limited_set ls + JOIN hive.accounts_view hav ON hav.id = ls.voter_id ORDER BY (CASE WHEN %L = 'desc' THEN %I ELSE NULL END) DESC, (CASE WHEN %L = 'asc' THEN %I ELSE NULL END) ASC ; $query$, - _witness_id, _limit, _offset, _order_by, _order_is, __today, + _witness_id, _today, + _order_is, _order_by, _order_is, _order_by, _offset, _limit, _order_is, _order_by, _order_is, _order_by ) res; @@ -503,133 +436,6 @@ SET from_collapse_limit=16 witnesses */ -CREATE FUNCTION hafbe_backend.get_set_of_witnesses_by_name(_limit INT, _offset INT, _order_is TEXT) -RETURNS SETOF hafbe_types.witnesses_by_name -AS -$function$ -BEGIN - RETURN QUERY EXECUTE format( - $query$ - - SELECT - witness_id, name::TEXT AS witness, - url, price_feed, bias, - (NOW() - feed_updated_at)::INTERVAL AS feed_age, - block_size, signing_key, version - FROM hive.accounts_view hav - JOIN hafbe_app.current_witnesses cw ON hav.id = cw.witness_id - ORDER BY - (CASE WHEN %L = 'desc' THEN name ELSE NULL END) DESC, - (CASE WHEN %L = 'asc' THEN name ELSE NULL END) ASC - OFFSET %L - LIMIT %L - - $query$, - _order_is, _order_is, _offset, _limit - ); -END -$function$ -LANGUAGE 'plpgsql' STABLE -SET JIT=OFF -SET join_collapse_limit=16 -SET from_collapse_limit=16 -; - -CREATE FUNCTION hafbe_backend.get_set_of_witnesses_by_votes(_limit INT, _offset INT, _order_by TEXT, _order_is TEXT) -RETURNS SETOF hafbe_types.witnesses_by_votes -AS -$function$ -BEGIN - RETURN QUERY EXECUTE format( - $query$ - SELECT witness_id, rank, votes, voters_num - FROM ( - SELECT witness_id, rank, votes, voters_num - FROM hafbe_app.witness_votes_cache - ) votes_sum - ORDER BY - (CASE WHEN %L = 'desc' THEN %I ELSE NULL END) DESC, - (CASE WHEN %L = 'asc' THEN %I ELSE NULL END) ASC - OFFSET %L - LIMIT %L - - $query$, - _order_is, _order_by, _order_is, _order_by, _offset, _limit - ); -END -$function$ -LANGUAGE 'plpgsql' STABLE -SET JIT=OFF -SET join_collapse_limit=16 -SET from_collapse_limit=16 -; - -CREATE FUNCTION hafbe_backend.get_set_of_witnesses_by_votes_change(_limit INT, _offset INT, _order_by TEXT, _order_is TEXT, _today DATE) -RETURNS SETOF hafbe_types.witnesses_by_votes_change -AS -$function$ -BEGIN - RETURN QUERY EXECUTE format( - $query$ - - SELECT witness_id, votes_daily_change, voters_num_daily_change - FROM ( - SELECT - witness_id, - SUM(vests)::BIGINT AS votes_daily_change, - COUNT(1)::INT AS voters_num_daily_change - FROM hafbe_views.voters_stats_change_view - WHERE timestamp >= %L - GROUP BY witness_id - ) vscv - ORDER BY - (CASE WHEN %L = 'desc' THEN %I ELSE NULL END) DESC, - (CASE WHEN %L = 'asc' THEN %I ELSE NULL END) ASC - OFFSET %L - LIMIT %L - - $query$, - _today, _order_is, _order_by, _order_is, _order_by, _offset, _limit - ); -END -$function$ -LANGUAGE 'plpgsql' STABLE -SET JIT=OFF -SET join_collapse_limit=16 -SET from_collapse_limit=16 -; - -CREATE FUNCTION hafbe_backend.get_set_of_witnesses_by_prop(_limit INT, _offset INT, _order_by TEXT, _order_is TEXT) -RETURNS SETOF hafbe_types.witnesses_by_prop -AS -$function$ -BEGIN - RETURN QUERY EXECUTE format( - $query$ - - SELECT - witness_id, url, price_feed, bias, - (NOW() - feed_updated_at)::INTERVAL AS feed_age, - block_size, signing_key, version - FROM hafbe_app.current_witnesses - WHERE %I IS NOT NULL - ORDER BY - (CASE WHEN %L = 'desc' THEN %I ELSE NULL END) DESC, - (CASE WHEN %L = 'asc' THEN %I ELSE NULL END) ASC - OFFSET %L - LIMIT %L - - $query$, - _order_by, _order_is, _order_by, _order_is, _order_by, _offset, _limit - ); -END -$function$ -LANGUAGE 'plpgsql' STABLE -SET JIT=OFF -SET join_collapse_limit=16 -SET from_collapse_limit=16 -; - CREATE FUNCTION hafbe_backend.get_set_of_witnesses(_limit INT, _offset INT, _order_by TEXT, _order_is TEXT) RETURNS SETOF hafbe_types.witnesses AS @@ -643,19 +449,31 @@ BEGIN RETURN QUERY EXECUTE format( $query$ - + + WITH limited_set AS ( + SELECT + cw.witness_id, hav.name::TEXT AS witness, + cw.url, cw.price_feed, cw.bias, + (NOW() - cw.feed_updated_at)::INTERVAL AS feed_age, + cw.block_size, cw.signing_key, cw.version + FROM hive.accounts_view hav + JOIN hafbe_app.current_witnesses cw ON hav.id = cw.witness_id + ORDER BY + (CASE WHEN %L = 'desc' THEN hav.name ELSE NULL END) DESC, + (CASE WHEN %L = 'asc' THEN hav.name ELSE NULL END) ASC + OFFSET %L + LIMIT %L + ) + SELECT - witness, rank::INT, url, + ls.witness, all_votes.rank, ls.url, COALESCE(all_votes.votes, 0)::NUMERIC, COALESCE(todays_votes.votes_daily_change, 0)::BIGINT, COALESCE(all_votes.voters_num, 0)::INT, COALESCE(todays_votes.voters_num_daily_change, 0)::INT, - price_feed, bias, feed_age, block_size, signing_key, version - FROM hafbe_backend.get_set_of_witnesses_by_name(%L, %L, %L) ls - LEFT JOIN ( - SELECT witness_id, rank, votes, voters_num - FROM hafbe_app.witness_votes_cache - ) all_votes ON all_votes.witness_id = ls.witness_id + ls.price_feed, ls.bias, ls.feed_age, ls.block_size, ls.signing_key, ls.version + FROM limited_set ls + LEFT JOIN hafbe_app.witness_votes_cache all_votes ON all_votes.witness_id = ls.witness_id LEFT JOIN LATERAL ( SELECT vscv.witness_id, @@ -666,57 +484,40 @@ BEGIN GROUP BY vscv.witness_id ) todays_votes ON TRUE ORDER BY - (CASE WHEN %L = 'desc' THEN %I ELSE NULL END) DESC, - (CASE WHEN %L = 'asc' THEN %I ELSE NULL END) ASC + (CASE WHEN %L = 'desc' THEN witness ELSE NULL END) DESC, + (CASE WHEN %L = 'asc' THEN witness ELSE NULL END) ASC $query$, - _limit, _offset, _order_is, __today, - _order_is, _order_by, _order_is, _order_by + _order_is, _order_is, _offset, _limit, + __today, + _order_is, _order_is ); - ELSIF _order_by = 'rank' THEN - - RETURN QUERY SELECT - hav.name::TEXT, rank::INT, url, - ls.votes, - COALESCE(todays_votes.votes_daily_change, 0)::BIGINT, - ls.voters_num, - COALESCE(todays_votes.voters_num_daily_change, 0)::INT, - price_feed, bias, - (NOW() - feed_updated_at)::INTERVAL, - block_size, signing_key, version - FROM hafbe_app.witness_votes_cache ls - JOIN hafbe_app.current_witnesses cw ON cw.witness_id = ls.witness_id - LEFT JOIN LATERAL ( - SELECT - vscv.witness_id, - SUM(vscv.vests) AS votes_daily_change, - COUNT(1) AS voters_num_daily_change - FROM hafbe_views.voters_stats_change_view vscv - WHERE vscv.timestamp >= __today AND vscv.witness_id = ls.witness_id - GROUP BY vscv.witness_id - ) todays_votes ON TRUE - JOIN hive.accounts_view ON hav.id = ls.witness_id - ORDER BY - (CASE WHEN _order_is = 'desc' THEN _order_by ELSE NULL END) DESC, - (CASE WHEN _order_is = 'asc' THEN _order_by ELSE NULL END) ASC - LIMIT _limit; - - ELSIF _order_by = ANY('{votes,voters_num}'::TEXT[]) THEN + ELSIF _order_by = ANY('{rank,votes,voters_num}'::TEXT[]) THEN RETURN QUERY EXECUTE format( $query$ + WITH limited_set AS ( + SELECT witness_id, rank, votes, voters_num + FROM hafbe_app.witness_votes_cache + ORDER BY + (CASE WHEN %L = 'desc' THEN %I ELSE NULL END) DESC, + (CASE WHEN %L = 'asc' THEN %I ELSE NULL END) ASC + OFFSET %L + LIMIT %L + ) + SELECT - hav.name::TEXT, rank::INT, url, + hav.name::TEXT, ls.rank, cw.url, ls.votes, COALESCE(todays_votes.votes_daily_change, 0)::BIGINT AS votes_daily_change, ls.voters_num, COALESCE(todays_votes.voters_num_daily_change, 0)::INT AS voters_num_daily_change, - price_feed, bias, - (NOW() - feed_updated_at)::INTERVAL, - block_size, signing_key, version - FROM hafbe_backend.get_set_of_witnesses_by_votes(%L, %L, %L, %L) ls + cw.price_feed, cw.bias, + (NOW() - cw.feed_updated_at)::INTERVAL, + cw.block_size, cw.signing_key, cw.version + FROM limited_set ls JOIN hafbe_app.current_witnesses cw ON cw.witness_id = ls.witness_id LEFT JOIN LATERAL ( SELECT @@ -736,7 +537,8 @@ BEGIN (CASE WHEN %L = 'asc' THEN %I ELSE NULL END) ASC $query$, - _limit, _offset, _order_by, _order_is, __today, + _order_is, _order_by, _order_is, _order_by, _offset, _limit, + __today, _order_is, _order_by, _order_is, _order_by ); @@ -745,31 +547,46 @@ BEGIN RETURN QUERY EXECUTE format( $query$ + WITH limited_set AS ( + SELECT witness_id, votes_daily_change, voters_num_daily_change + FROM ( + SELECT + witness_id, + SUM(vests)::BIGINT AS votes_daily_change, + COUNT(1)::INT AS voters_num_daily_change + FROM hafbe_views.voters_stats_change_view + WHERE timestamp >= %L + GROUP BY witness_id + ) vscv + ORDER BY + (CASE WHEN %L = 'desc' THEN %I ELSE NULL END) DESC, + (CASE WHEN %L = 'asc' THEN %I ELSE NULL END) ASC + OFFSET %L + LIMIT %L + ) + SELECT - hav.name::TEXT, rank::INT, url, + hav.name::TEXT, all_votes.rank, cw.url, all_votes.votes::NUMERIC, ls.votes_daily_change, all_votes.voters_num::INT, ls.voters_num_daily_change, - price_feed, bias, - (NOW() - feed_updated_at)::INTERVAL, - block_size, signing_key, version - FROM hafbe_backend.get_set_of_witnesses_by_votes_change(%L, %L, %L, %L, %L) ls + cw.price_feed, cw.bias, + (NOW() - cw.feed_updated_at)::INTERVAL, + cw.block_size, cw.signing_key, cw.version + FROM limited_set ls JOIN hafbe_app.current_witnesses cw ON cw.witness_id = ls.witness_id - JOIN ( + LEFT JOIN ( SELECT witness_id, rank, votes, voters_num FROM hafbe_app.witness_votes_cache ) all_votes ON all_votes.witness_id = ls.witness_id - JOIN ( - SELECT name, id - FROM hive.accounts_view - ) hav ON hav.id = ls.witness_id + JOIN hive.accounts_view hav ON hav.id = ls.witness_id ORDER BY (CASE WHEN %L = 'desc' THEN %I ELSE NULL END) DESC, (CASE WHEN %L = 'asc' THEN %I ELSE NULL END) ASC $query$, - _limit, _offset, _order_by, _order_is, __today, + __today, _order_is, _order_by, _order_is, _order_by, _offset, _limit, _order_is, _order_by, _order_is, _order_by ); @@ -778,6 +595,20 @@ BEGIN RETURN QUERY EXECUTE format( $query$ + WITH limited_set AS ( + SELECT + witness_id, url, price_feed, bias, + (NOW() - feed_updated_at)::INTERVAL AS feed_age, + block_size, signing_key, version + FROM hafbe_app.current_witnesses + WHERE %I IS NOT NULL + ORDER BY + (CASE WHEN %L = 'desc' THEN %I ELSE NULL END) DESC, + (CASE WHEN %L = 'asc' THEN %I ELSE NULL END) ASC + OFFSET %L + LIMIT %L + ) + SELECT hav.name::TEXT, rank::INT, url, COALESCE(all_votes.votes, 0)::NUMERIC, @@ -785,7 +616,7 @@ BEGIN COALESCE(all_votes.voters_num, 0)::INT, COALESCE(todays_votes.voters_num_daily_change, 0)::INT, price_feed, bias, feed_age, block_size, signing_key, version - FROM hafbe_backend.get_set_of_witnesses_by_prop(%L, %L, %L, %L) ls + FROM limited_set ls LEFT JOIN ( SELECT witness_id, rank, votes, voters_num FROM hafbe_app.witness_votes_cache @@ -799,16 +630,14 @@ BEGIN WHERE vscv.timestamp >= %L AND vscv.witness_id = ls.witness_id GROUP BY vscv.witness_id ) todays_votes ON TRUE - JOIN ( - SELECT name, id - FROM hive.accounts_view - ) hav ON hav.id = ls.witness_id + JOIN hive.accounts_view hav ON hav.id = ls.witness_id ORDER BY (CASE WHEN %L = 'desc' THEN %I ELSE NULL END) DESC, (CASE WHEN %L = 'asc' THEN %I ELSE NULL END) ASC $query$, - _limit, _offset, _order_by, _order_is, __today, + _order_by, _order_is, _order_by, _order_is, _order_by, _offset, _limit, + __today, _order_is, _order_by, _order_is, _order_by ); diff --git a/api/types.sql b/api/types.sql index c28427b..c8c108a 100644 --- a/api/types.sql +++ b/api/types.sql @@ -28,19 +28,6 @@ CREATE TYPE hafbe_types.block AS ( signing_key TEXT ); -CREATE TYPE hafbe_types.witness_voters_by_name AS ( - voter_id INT, - voter TEXT -); - -CREATE TYPE hafbe_types.witness_voters_by_vests AS ( - voter_id INT, - vests NUMERIC, - account_vests NUMERIC, - proxied_vests NUMERIC, - timestamp TIMESTAMP -); - CREATE TYPE hafbe_types.witness_voters AS ( account TEXT, vests NUMERIC, @@ -49,22 +36,6 @@ CREATE TYPE hafbe_types.witness_voters AS ( timestamp TIMESTAMP ); -CREATE TYPE hafbe_types.witness_voters_daily_change_by_name AS ( - witness_id INT, - voter_id INT, - voter TEXT, - approve BOOLEAN -); - -CREATE TYPE hafbe_types.witness_voters_daily_change_by_vests AS ( - voter_id INT, - vests BIGINT, - account_vests BIGINT, - proxied_vests BIGINT, - timestamp TIMESTAMP, - approve BOOLEAN -); - CREATE TYPE hafbe_types.witness_voters_daily_change AS ( account TEXT, approve BOOLEAN, @@ -74,42 +45,6 @@ CREATE TYPE hafbe_types.witness_voters_daily_change AS ( timestamp TIMESTAMP ); -CREATE TYPE hafbe_types.witnesses_by_name AS ( - witness_id INT, - witness TEXT, - url TEXT, - price_feed FLOAT, - bias NUMERIC, - feed_age INTERVAL, - block_size INT, - signing_key TEXT, - version TEXT -); - -CREATE TYPE hafbe_types.witnesses_by_votes AS ( - witness_id INT, - rank INT, - votes NUMERIC, - voters_num INT -); - -CREATE TYPE hafbe_types.witnesses_by_votes_change AS ( - witness_id INT, - votes_daily_change BIGINT, - voters_num_daily_change INT -); - -CREATE TYPE hafbe_types.witnesses_by_prop AS ( - witness_id INT, - url TEXT, - price_feed FLOAT, - bias NUMERIC, - feed_age INTERVAL, - block_size INT, - signing_key TEXT, - version TEXT -); - CREATE TYPE hafbe_types.witnesses AS ( witness TEXT, rank INT, -- GitLab From e9a05c13e71d31024395f28d9f0afa6160009c7f Mon Sep 17 00:00:00 2001 From: kristupas Date: Thu, 10 Nov 2022 23:57:31 +0000 Subject: [PATCH 74/89] Added witness votes history cache #22 --- api/backend.sql | 70 ++++++++++++++++-------------------------- api/views.sql | 9 ++---- db/hafbe_app.sql | 80 ++++++++++++++++++++++++++++++++++++------------ 3 files changed, 90 insertions(+), 69 deletions(-) diff --git a/api/backend.sql b/api/backend.sql index ceab7ea..6739f7c 100644 --- a/api/backend.sql +++ b/api/backend.sql @@ -371,16 +371,16 @@ BEGIN SELECT ls.voter, ls.approve, - COALESCE(vscv.vests, 0)::BIGINT, - COALESCE(vscv.account_vests, 0)::BIGINT, - COALESCE(vscv.proxied_vests, 0)::BIGINT, - vscv.timestamp + COALESCE(wvcc.vests, 0)::BIGINT, + COALESCE(wvcc.account_vests, 0)::BIGINT, + COALESCE(wvcc.proxied_vests, 0)::BIGINT, + wvcc.timestamp FROM limited_set ls LEFT JOIN ( SELECT voter_id, vests, account_vests, proxied_vests, timestamp - FROM hafbe_views.voters_stats_change_view - WHERE witness_id = %L AND timestamp >= %L - ) vscv ON vscv.voter_id = ls.voter_id + FROM hafbe_app.witness_voters_stats_change_cache + WHERE witness_id = %L + ) wvcc ON wvcc.voter_id = ls.voter_id ORDER BY (CASE WHEN %L = 'desc' THEN ls.voter ELSE NULL END) DESC, (CASE WHEN %L = 'asc' THEN ls.voter ELSE NULL END) ASC @@ -389,7 +389,7 @@ BEGIN $query$, _witness_id, __today, _order_is, _order_is, _offset, _limit, - _witness_id, __today, + _witness_id, _order_is, _order_is ) res; @@ -400,8 +400,8 @@ BEGIN WITH limited_set AS ( SELECT voter_id, vests::BIGINT, account_vests::BIGINT, proxied_vests::BIGINT, timestamp, approve - FROM hafbe_views.voters_stats_change_view - WHERE witness_id = %L AND timestamp >= %L + FROM hafbe_app.witness_voters_stats_change_cache + WHERE witness_id = %L ORDER BY (CASE WHEN %L = 'desc' THEN %I ELSE NULL END) DESC, (CASE WHEN %L = 'asc' THEN %I ELSE NULL END) ASC @@ -418,7 +418,7 @@ BEGIN ; $query$, - _witness_id, _today, + _witness_id, _order_is, _order_by, _order_is, _order_by, _offset, _limit, _order_is, _order_by, _order_is, _order_by ) res; @@ -475,13 +475,10 @@ BEGIN FROM limited_set ls LEFT JOIN hafbe_app.witness_votes_cache all_votes ON all_votes.witness_id = ls.witness_id LEFT JOIN LATERAL ( - SELECT - vscv.witness_id, - SUM(vscv.vests) AS votes_daily_change, - COUNT(1) AS voters_num_daily_change - FROM hafbe_views.voters_stats_change_view vscv - WHERE vscv.timestamp >= %L AND vscv.witness_id = ls.witness_id - GROUP BY vscv.witness_id + SELECT wvcc.witness_id, wvcc.votes_daily_change, wvcc.voters_num_daily_change + FROM hafbe_app.witness_votes_change_cache wvcc + WHERE wvcc.witness_id = ls.witness_id + GROUP BY wvcc.witness_id ) todays_votes ON TRUE ORDER BY (CASE WHEN %L = 'desc' THEN witness ELSE NULL END) DESC, @@ -489,7 +486,6 @@ BEGIN $query$, _order_is, _order_is, _offset, _limit, - __today, _order_is, _order_is ); @@ -520,13 +516,10 @@ BEGIN FROM limited_set ls JOIN hafbe_app.current_witnesses cw ON cw.witness_id = ls.witness_id LEFT JOIN LATERAL ( - SELECT - vscv.witness_id, - SUM(vscv.vests) AS votes_daily_change, - COUNT(1) AS voters_num_daily_change - FROM hafbe_views.voters_stats_change_view vscv - WHERE vscv.timestamp >= %L AND vscv.witness_id = ls.witness_id - GROUP BY vscv.witness_id + SELECT wvcc.witness_id, wvcc.votes_daily_change, wvcc.voters_num_daily_change + FROM hafbe_app.witness_votes_change_cache wvcc + WHERE wvcc.witness_id = ls.witness_id + GROUP BY wvcc.witness_id ) todays_votes ON TRUE JOIN ( SELECT name, id @@ -538,7 +531,6 @@ BEGIN $query$, _order_is, _order_by, _order_is, _order_by, _offset, _limit, - __today, _order_is, _order_by, _order_is, _order_by ); @@ -550,14 +542,10 @@ BEGIN WITH limited_set AS ( SELECT witness_id, votes_daily_change, voters_num_daily_change FROM ( - SELECT - witness_id, - SUM(vests)::BIGINT AS votes_daily_change, - COUNT(1)::INT AS voters_num_daily_change - FROM hafbe_views.voters_stats_change_view - WHERE timestamp >= %L + SELECT witness_id, votes_daily_change, voters_num_daily_change + FROM hafbe_app.witness_votes_change_cache wvcc GROUP BY witness_id - ) vscv + ) wvcc ORDER BY (CASE WHEN %L = 'desc' THEN %I ELSE NULL END) DESC, (CASE WHEN %L = 'asc' THEN %I ELSE NULL END) ASC @@ -586,7 +574,7 @@ BEGIN (CASE WHEN %L = 'asc' THEN %I ELSE NULL END) ASC $query$, - __today, _order_is, _order_by, _order_is, _order_by, _offset, _limit, + _order_is, _order_by, _order_is, _order_by, _offset, _limit, _order_is, _order_by, _order_is, _order_by ); @@ -622,13 +610,10 @@ BEGIN FROM hafbe_app.witness_votes_cache ) all_votes ON all_votes.witness_id = ls.witness_id LEFT JOIN LATERAL ( - SELECT - vscv.witness_id, - SUM(vscv.vests) AS votes_daily_change, - COUNT(1) AS voters_num_daily_change - FROM hafbe_views.voters_stats_change_view vscv - WHERE vscv.timestamp >= %L AND vscv.witness_id = ls.witness_id - GROUP BY vscv.witness_id + SELECT wvcc.witness_id, wvcc.votes_daily_change, wvcc.voters_num_daily_change + FROM hafbe_app.witness_votes_change_cache wvcc + WHERE wvcc.witness_id = ls.witness_id + GROUP BY wvcc.witness_id ) todays_votes ON TRUE JOIN hive.accounts_view hav ON hav.id = ls.witness_id ORDER BY @@ -637,7 +622,6 @@ BEGIN $query$, _order_by, _order_is, _order_by, _order_is, _order_by, _offset, _limit, - __today, _order_is, _order_by, _order_is, _order_by ); diff --git a/api/views.sql b/api/views.sql index 6d13b00..0d187d0 100644 --- a/api/views.sql +++ b/api/views.sql @@ -97,8 +97,7 @@ LEFT JOIN hafbe_views.voters_proxied_vests_view vpvv ON vpvv.proxy_id = wvvv.vot ------ -DROP VIEW IF EXISTS hafbe_views.voters_approve_vests_change_view CASCADE; -CREATE VIEW hafbe_views.voters_approve_vests_change_view AS +CREATE OR REPLACE VIEW hafbe_views.voters_approve_vests_change_view AS SELECT wvh.witness_id, wvh.voter_id, wvh.approve, wvh.timestamp, CASE WHEN wvh.approve THEN av.vests ELSE -1 * av.vests END AS account_vests, @@ -118,8 +117,7 @@ LEFT JOIN LATERAL ( ------ -DROP VIEW IF EXISTS hafbe_views.voters_proxy_vests_change_view CASCADE; -CREATE VIEW hafbe_views.voters_proxy_vests_change_view AS +CREATE OR REPLACE VIEW hafbe_views.voters_proxy_vests_change_view AS SELECT aph.account_id AS voter_id, SUM(CASE WHEN aph.proxy THEN -1 * av.vests ELSE av.vests END) AS account_vests, @@ -140,8 +138,7 @@ GROUP BY aph.account_id; ------ -DROP VIEW IF EXISTS hafbe_views.voters_stats_change_view CASCADE; -CREATE VIEW hafbe_views.voters_stats_change_view AS +CREATE OR REPLACE VIEW hafbe_views.voters_stats_change_view AS SELECT vavcv.witness_id, vavcv.voter_id, vavcv.account_vests + vavcv.proxied_vests + COALESCE(vpvcv.account_vests, 0) + COALESCE(vpvcv.proxied_vests, 0) AS vests, diff --git a/db/hafbe_app.sql b/db/hafbe_app.sql index 78c6d5c..a425860 100644 --- a/db/hafbe_app.sql +++ b/db/hafbe_app.sql @@ -116,6 +116,24 @@ BEGIN CONSTRAINT pk_witness_votes_cache PRIMARY KEY (witness_id) ); + + CREATE TABLE hafbe_app.witness_voters_stats_change_cache ( + witness_id INT NOT NULL, + voter_id INT NOT NULL, + vests NUMERIC NOT NULL, + account_vests NUMERIC NOT NULL, + proxied_vests NUMERIC NOT NULL, + approve BOOLEAN NOT NULL, + timestamp TIMESTAMP NOT NULL + ); + + CREATE TABLE hafbe_app.witness_votes_change_cache ( + witness_id INT NOT NULL, + votes_daily_change BIGINT NOT NULL, + voters_num_daily_change INT NOT NULL, + + CONSTRAINT pk_witness_votes_change_cache PRIMARY KEY (witness_id) + ); END $$ ; @@ -184,7 +202,7 @@ LANGUAGE 'plpgsql' AS $$ DECLARE - __balance_impacting_ops_ids INT[] = (SELECT op_type_ids_arr FROM hafbe_app.balance_impacting_op_ids); + __balance_impacting_ops_ids INT[] = (SELECT op_type_ids_arr FROM hafbe_app.balance_impacting_op_ids LIMIT 1); BEGIN -- process vote ops WITH select_votes_ops AS ( @@ -645,31 +663,52 @@ $function$ BEGIN RAISE NOTICE 'Updating witnesses caches'; + TRUNCATE TABLE hafbe_app.witness_voters_stats_cache; + INSERT INTO hafbe_app.witness_voters_stats_cache (witness_id, voter_id, vests, account_vests, proxied_vests, timestamp) SELECT witness_id, voter_id, vests, account_vests, proxied_vests, timestamp - FROM hafbe_views.voters_stats_view - ON CONFLICT ON CONSTRAINT pk_witness_voters_stats_cache DO UPDATE SET - vests = EXCLUDED.vests, - account_vests = EXCLUDED.account_vests, - proxied_vests = EXCLUDED.proxied_vests, - timestamp = EXCLUDED.timestamp - ; + FROM hafbe_views.voters_stats_view; + + RAISE NOTICE 'Updated witness voters cache'; + + TRUNCATE TABLE hafbe_app.witness_votes_cache; INSERT INTO hafbe_app.witness_votes_cache (witness_id, rank, votes, voters_num) - SELECT witness_id, RANK() OVER (ORDER BY votes DESC), votes, voters_num + SELECT witness_id, RANK() OVER (ORDER BY votes DESC, voters_num DESC, feed_updated_at DESC), votes, voters_num FROM ( SELECT witness_id, SUM(vests) AS votes, - COUNT(1) AS voters_num + COUNT(1) AS voters_num, + MAX(timestamp) AS feed_updated_at FROM hafbe_views.voters_stats_view GROUP BY witness_id - ) vsv - ON CONFLICT ON CONSTRAINT pk_witness_votes_cache DO UPDATE SET - votes = EXCLUDED.votes, - voters_num = EXCLUDED.voters_num - ; + ) vsv; + + RAISE NOTICE 'Updated witnesses cache'; + + TRUNCATE TABLE hafbe_app.witness_voters_stats_change_cache; + + INSERT INTO hafbe_app.witness_voters_stats_change_cache (witness_id, voter_id, vests, account_vests, proxied_vests, approve, timestamp) + SELECT witness_id, voter_id, vests, account_vests, proxied_vests, approve, timestamp + FROM hafbe_views.voters_stats_change_view + WHERE timestamp >= 'today'::DATE; + RAISE NOTICE 'Updated witness voters change cache'; + + TRUNCATE TABLE hafbe_app.witness_votes_change_cache; + + INSERT INTO hafbe_app.witness_votes_change_cache (witness_id, votes_daily_change, voters_num_daily_change) + SELECT + witness_id, + SUM(CASE WHEN approve THEN vests ELSE -1 * vests END)::BIGINT, + SUM(CASE WHEN approve THEN 1 ELSE -1 END)::INT + FROM hafbe_views.voters_stats_change_view + WHERE timestamp >= 'today'::DATE + GROUP BY witness_id; + + RAISE NOTICE 'Updated witness change cache'; + UPDATE hafbe_app.witnesses_cache_config SET last_updated_at = NOW(); END $function$ @@ -728,13 +767,14 @@ BEGIN RAISE NOTICE 'Attempting to process block range: <%,%>', __next_block_range.first_block, __next_block_range.last_block; - IF __next_block_range.first_block >= 1000000 THEN - __next_block_range.first_block := __next_block_range.last_block; - END IF; - IF __next_block_range.first_block != __next_block_range.last_block THEN CALL hafbe_app.do_massive_processing(_appContext, __next_block_range.first_block, __next_block_range.last_block, 100, __last_block); - UPDATE hafbe_app.app_status SET finished_processing_at = NOW(); + UPDATE hafbe_app.app_status SET finished_processing_at = NOW() FROM ( + SELECT CASE WHEN finished_processing_at IS NULL THEN TRUE ELSE FALSE END AS not_updated + FROM hafbe_app.app_status + LIMIT 1 + ) app_stat + WHERE app_stat.not_updated; ELSE CALL hafbe_app.processBlock(__next_block_range.last_block); __last_block := __next_block_range.last_block; -- GitLab From 5f605269302dd7a6ebcb7f4b03e2678e4a95bcc5 Mon Sep 17 00:00:00 2001 From: kristupas Date: Fri, 11 Nov 2022 18:05:58 +0000 Subject: [PATCH 75/89] Added 'get_account_resource_credits()' method #22 --- api/backend.sql | 22 ++++++++ api/endpoints.sql | 128 +++++++++++++++++++++++++++++----------------- api/roles.sql | 6 ++- db/hafbe_app.sql | 9 ++++ 4 files changed, 116 insertions(+), 49 deletions(-) diff --git a/api/backend.sql b/api/backend.sql index 6739f7c..fd1d99f 100644 --- a/api/backend.sql +++ b/api/backend.sql @@ -678,4 +678,26 @@ BEGIN RETURN __profile_image; END $$ +; + +CREATE FUNCTION hafbe_backend.get_account_resource_credits(_account TEXT) +RETURNS JSON +LANGUAGE 'plpython3u' +AS +$$ + import subprocess + import json + + return json.dumps( + json.loads( + subprocess.check_output([ + """ + curl -X POST https://api.hive.blog \ + -H 'Content-Type: application/json' \ + -d '{"jsonrpc": "2.0", "method": "rc_api.find_rc_accounts", "params": {"accounts":["%s"]}, "id": null}' + """ % _account + ], shell=True).decode('utf-8') + )['result']['rc_accounts'][0] + ) +$$ ; \ No newline at end of file diff --git a/api/endpoints.sql b/api/endpoints.sql index 39c07bc..557506f 100644 --- a/api/endpoints.sql +++ b/api/endpoints.sql @@ -375,66 +375,100 @@ LANGUAGE 'plpgsql' AS $$ DECLARE - __account_data JSON; - __profile_image TEXT; __response_data JSON; + __profile_image TEXT; BEGIN - SELECT data FROM hafbe_app.hived_account_cache WHERE account = _account INTO __response_data; + SELECT INTO __response_data + data + FROM hafbe_app.hived_account_cache + WHERE account = _account AND (NOW() - last_updated_at)::INTERVAL >= '1 hour'::INTERVAL; - IF __response_data IS NOT NULL THEN - RETURN __response_data; - ELSE - SELECT hafbe_backend.get_account(_account) INTO __account_data; + IF __response_data IS NULL THEN + SELECT hafbe_backend.get_account(_account) INTO __response_data; - SELECT hafbe_backend.parse_profile_picture(__account_data, 'json_metadata') INTO __profile_image; + SELECT hafbe_backend.parse_profile_picture(__response_data, 'json_metadata') INTO __profile_image; IF __profile_image IS NULL THEN - SELECT hafbe_backend.parse_profile_picture(__account_data, 'posting_json_metadata') INTO __profile_image; + SELECT hafbe_backend.parse_profile_picture(__response_data, 'posting_json_metadata') INTO __profile_image; END IF; SELECT json_build_object( - 'id', __account_data->>'id', + 'id', __response_data->>'id', 'name', _account, 'profile_image', __profile_image, - 'last_owner_update', __account_data->>'last_owner_update', - 'last_account_update', __account_data->>'last_account_update', - 'created', __account_data->>'created', - 'mined', __account_data->>'mined', - 'recovery_account', __account_data->>'recovery_account', - 'comment_count', __account_data->>'comment_count', - 'post_count', __account_data->>'post_count', - 'can_vote', __account_data->>'can_vote', - 'voting_manabar', __account_data->'voting_manabar', - 'downvote_manabar', __account_data->'downvote_manabar', - 'voting_power', __account_data->>'voting_power', - 'balance', __account_data->>'balance', - 'savings_balance', __account_data->>'savings_balance', - 'hbd_balance', __account_data->>'hbd_balance', - 'savings_withdraw_requests', __account_data->>'savings_withdraw_requests', - 'reward_hbd_balance', __account_data->>'reward_hbd_balance', - 'reward_hive_balance', __account_data->>'reward_hive_balance', - 'reward_vesting_balance', __account_data->>'reward_vesting_balance', - 'reward_vesting_hive', __account_data->>'reward_vesting_hive', - 'vesting_shares', __account_data->>'vesting_shares', - 'delegated_vesting_shares', __account_data->>'delegated_vesting_shares', - 'received_vesting_shares', __account_data->>'received_vesting_shares', - 'vesting_withdraw_rate', __account_data->>'vesting_withdraw_rate', - 'post_voting_power', __account_data->>'post_voting_power', - 'posting_rewards', __account_data->>'posting_rewards', - 'proxied_vsf_votes', __account_data->'proxied_vsf_votes', - 'witnesses_voted_for', __account_data->>'witnesses_voted_for', - 'last_post', __account_data->>'last_post', - 'last_root_post', __account_data->>'last_root_post', - 'last_vote_time', __account_data->>'last_vote_time', - 'vesting_balance', __account_data->>'vesting_balance', - 'reputation', __account_data->>'reputation' + 'last_owner_update', __response_data->>'last_owner_update', + 'last_account_update', __response_data->>'last_account_update', + 'created', __response_data->>'created', + 'mined', __response_data->>'mined', + 'recovery_account', __response_data->>'recovery_account', + 'comment_count', __response_data->>'comment_count', + 'post_count', __response_data->>'post_count', + 'can_vote', __response_data->>'can_vote', + 'voting_manabar', __response_data->'voting_manabar', + 'downvote_manabar', __response_data->'downvote_manabar', + 'voting_power', __response_data->>'voting_power', + 'balance', __response_data->>'balance', + 'savings_balance', __response_data->>'savings_balance', + 'hbd_balance', __response_data->>'hbd_balance', + 'savings_withdraw_requests', __response_data->>'savings_withdraw_requests', + 'reward_hbd_balance', __response_data->>'reward_hbd_balance', + 'reward_hive_balance', __response_data->>'reward_hive_balance', + 'reward_vesting_balance', __response_data->>'reward_vesting_balance', + 'reward_vesting_hive', __response_data->>'reward_vesting_hive', + 'vesting_shares', __response_data->>'vesting_shares', + 'delegated_vesting_shares', __response_data->>'delegated_vesting_shares', + 'received_vesting_shares', __response_data->>'received_vesting_shares', + 'vesting_withdraw_rate', __response_data->>'vesting_withdraw_rate', + 'post_voting_power', __response_data->>'post_voting_power', + 'posting_rewards', __response_data->>'posting_rewards', + 'proxied_vsf_votes', __response_data->'proxied_vsf_votes', + 'witnesses_voted_for', __response_data->>'witnesses_voted_for', + 'last_post', __response_data->>'last_post', + 'last_root_post', __response_data->>'last_root_post', + 'last_vote_time', __response_data->>'last_vote_time', + 'vesting_balance', __response_data->>'vesting_balance', + 'reputation', __response_data->>'reputation' ) INTO __response_data; - INSERT INTO hafbe_app.hived_account_cache (account, data) - SELECT _account, __response_data - ON CONFLICT DO NOTHING; - - RETURN __response_data; + INSERT INTO hafbe_app.hived_account_cache (account, data, last_updated_at) + SELECT _account, __response_data, NOW() + ON CONFLICT ON CONSTRAINT pk_hived_account_cache DO + UPDATE SET + data = EXCLUDED.data, + last_updated_at = EXCLUDED.last_updated_at + ; END IF; + + RETURN __response_data; END $$ ; + +CREATE FUNCTION hafbe_endpoints.get_account_resource_credits(_account TEXT) +RETURNS JSON +LANGUAGE 'plpgsql' +AS +$$ +DECLARE + __response_data JSON; +BEGIN + SELECT INTO __response_data + data + FROM hafbe_app.hived_account_resource_credits_cache + WHERE account = _account AND (NOW() - last_updated_at)::INTERVAL >= '1 hour'::INTERVAL; + + IF __response_data IS NULL THEN + SELECT hafbe_backend.get_account_resource_credits(_account) INTO __response_data; + + INSERT INTO hafbe_app.hived_account_resource_credits_cache (account, data, last_updated_at) + SELECT _account, __response_data, NOW() + ON CONFLICT ON CONSTRAINT pk_hived_account_resource_credits_cache DO + UPDATE SET + data = EXCLUDED.data, + last_updated_at = EXCLUDED.last_updated_at + ; + END IF; + + RETURN __response_data; +END +$$ +; \ No newline at end of file diff --git a/api/roles.sql b/api/roles.sql index 3a1f57e..9c1db22 100755 --- a/api/roles.sql +++ b/api/roles.sql @@ -43,8 +43,10 @@ GRANT EXECUTE ON ALL FUNCTIONS IN SCHEMA hive TO hafbe_user; GRANT USAGE ON SCHEMA hafbe_app TO hafbe_user; GRANT USAGE, SELECT ON ALL SEQUENCES IN SCHEMA hafbe_app TO hafbe_user; -GRANT SELECT, INSERT ON ALL TABLES IN SCHEMA hafbe_app TO hafbe_user; +GRANT SELECT ON ALL TABLES IN SCHEMA hafbe_app TO hafbe_user; GRANT EXECUTE ON ALL FUNCTIONS IN SCHEMA hafbe_app TO hafbe_user; --- plpython3u must be trusted language +GRANT INSERT, UPDATE ON hafbe_app.hived_account_cache, hafbe_app.hived_account_resource_credits_cache TO hafbe_user; + +-- plpython3u must be GRANT SELECT, INSERT, UPDATE ON ALL TABLES IN SCHEMA hafbe_app TO hafbe_user;trusted language GRANT USAGE ON LANGUAGE plpython3u TO hafbe_owner; \ No newline at end of file diff --git a/db/hafbe_app.sql b/db/hafbe_app.sql index a425860..1763b5f 100644 --- a/db/hafbe_app.sql +++ b/db/hafbe_app.sql @@ -66,10 +66,19 @@ BEGIN CREATE TABLE IF NOT EXISTS hafbe_app.hived_account_cache ( account TEXT NOT NULL, data JSON NOT NULL, + last_updated_at TIMESTAMP, CONSTRAINT pk_hived_account_cache PRIMARY KEY (account) ); + CREATE TABLE IF NOT EXISTS hafbe_app.hived_account_resource_credits_cache ( + account TEXT NOT NULL, + data JSON NOT NULL, + last_updated_at TIMESTAMP, + + CONSTRAINT pk_hived_account_resource_credits_cache PRIMARY KEY (account) + ); + CREATE TABLE IF NOT EXISTS hafbe_app.balance_impacting_op_ids ( op_type_ids_arr SMALLINT[] NOT NULL ); -- GitLab From af9fc4febc28af8d87acd6bf279f87ae18503a30 Mon Sep 17 00:00:00 2001 From: kristupas Date: Fri, 11 Nov 2022 21:22:44 +0000 Subject: [PATCH 76/89] Added mechanism to convert vests to hive power #22 --- api/backend.sql | 101 +++++++++++++++++++++++++++++++++++++++++++--- api/endpoints.sql | 84 +++++++++++++++++++++++++++++--------- api/types.sql | 39 ++++++++++++++++-- db/hafbe_app.sql | 44 ++++++++++++++++++++ 4 files changed, 241 insertions(+), 27 deletions(-) diff --git a/api/backend.sql b/api/backend.sql index fd1d99f..e1a36fe 100644 --- a/api/backend.sql +++ b/api/backend.sql @@ -232,8 +232,8 @@ SET from_collapse_limit=16 witness voters */ -CREATE FUNCTION hafbe_backend.get_set_of_witness_voters(_witness_id INT, _limit INT, _offset INT, _order_by TEXT, _order_is TEXT) -RETURNS SETOF hafbe_types.witness_voters +CREATE FUNCTION hafbe_backend.get_set_of_witness_voters_in_vests(_witness_id INT, _limit INT, _offset INT, _order_by TEXT, _order_is TEXT) +RETURNS SETOF hafbe_types.witness_voters_in_vests AS $function$ BEGIN @@ -315,6 +315,28 @@ SET join_collapse_limit=16 SET from_collapse_limit=16 ; +CREATE FUNCTION hafbe_backend.get_set_of_witness_voters_in_hp(_witness_id INT, _limit INT, _offset INT, _order_by TEXT, _order_is TEXT) +RETURNS SETOF hafbe_types.witness_voters_in_hp +AS +$function$ +BEGIN + RETURN QUERY SELECT account, hive_power, account_hive_power, proxied_hive_power, timestamp + FROM hafbe_backend.get_set_of_witness_voters_in_vests(_witness_id, _limit, _offset, _order_by, _order_is) + JOIN LATERAL ( + SELECT arr_hp[1] AS hive_power, arr_hp[2] AS account_hive_power, arr_hp[3] AS proxied_hive_power + FROM ( + SELECT array_agg(hp) AS arr_hp + FROM hafbe_backend.vests_to_hive_power(vests, account_vests, proxied_vests) hp + ) to_arr + ) conv ON TRUE; +END +$function$ +LANGUAGE 'plpgsql' STABLE +SET JIT=OFF +SET join_collapse_limit=16 +SET from_collapse_limit=16 +; + /* witness voters change */ @@ -339,8 +361,8 @@ END $$ ; -CREATE FUNCTION hafbe_backend.get_set_of_witness_voters_daily_change(_witness_id INT, _limit INT, _offset INT, _order_by TEXT, _order_is TEXT) -RETURNS SETOF hafbe_types.witness_voters_daily_change +CREATE FUNCTION hafbe_backend.get_set_of_witness_voters_daily_change_in_vests(_witness_id INT, _limit INT, _offset INT, _order_by TEXT, _order_is TEXT) +RETURNS SETOF hafbe_types.witness_voters_daily_change_in_vests AS $function$ DECLARE @@ -432,12 +454,34 @@ SET join_collapse_limit=16 SET from_collapse_limit=16 ; +CREATE FUNCTION hafbe_backend.get_set_of_witness_voters_daily_change_in_hp(_witness_id INT, _limit INT, _offset INT, _order_by TEXT, _order_is TEXT) +RETURNS SETOF hafbe_types.witness_voters_in_hp +AS +$function$ +BEGIN + RETURN QUERY SELECT account, hive_power, account_hive_power, proxied_hive_power, timestamp + FROM hafbe_backend.get_set_of_witness_voters_daily_change_in_vests(_witness_id, _limit, _offset, _order_by, _order_is) + JOIN LATERAL ( + SELECT arr_hp[1] AS hive_power, arr_hp[2] AS account_hive_power, arr_hp[3] AS proxied_hive_power + FROM ( + SELECT array_agg(hp) AS arr_hp + FROM hafbe_backend.vests_to_hive_power(vests, account_vests, proxied_vests) hp + ) to_arr + ) conv ON TRUE; +END +$function$ +LANGUAGE 'plpgsql' STABLE +SET JIT=OFF +SET join_collapse_limit=16 +SET from_collapse_limit=16 +; + /* witnesses */ -CREATE FUNCTION hafbe_backend.get_set_of_witnesses(_limit INT, _offset INT, _order_by TEXT, _order_is TEXT) -RETURNS SETOF hafbe_types.witnesses +CREATE FUNCTION hafbe_backend.get_set_of_witnesses_in_vests(_limit INT, _offset INT, _order_by TEXT, _order_is TEXT) +RETURNS SETOF hafbe_types.witnesses_in_vests AS $function$ DECLARE @@ -634,6 +678,51 @@ SET join_collapse_limit=16 SET from_collapse_limit=16 ; +CREATE FUNCTION hafbe_backend.get_set_of_witnesses_in_hp(_limit INT, _offset INT, _order_by TEXT, _order_is TEXT) +RETURNS SETOF hafbe_types.witnesses_in_hp +AS +$function$ +BEGIN + RETURN QUERY SELECT + witness, rank, url, conv.votes, conv.votes_daily_change, voters_num, voters_num_daily_change, + price_feed, bias, feed_age, block_size, signing_key, version + FROM hafbe_backend.get_set_of_witnesses_in_vests(_limit, _offset, _order_by, _order_is) + JOIN LATERAL ( + SELECT arr_hp[1] AS votes, arr_hp[2] AS votes_daily_change + FROM ( + SELECT array_agg(hp) AS arr_hp + FROM hafbe_backend.vests_to_hive_power(votes, votes_daily_change) hp + ) to_arr + ) conv ON TRUE; +END +$function$ +LANGUAGE 'plpgsql' STABLE +SET JIT=OFF +SET join_collapse_limit=16 +SET from_collapse_limit=16 +; + +CREATE FUNCTION hafbe_backend.vests_to_hive_power(VARIADIC vests_value NUMERIC[]) +RETURNS SETOF FLOAT +LANGUAGE 'plpgsql' +AS +$$ +BEGIN + RETURN QUERY SELECT ( + unnest(vests_value) + * + (SELECT value FROM hafbe_app.dynamic_global_properties_cache WHERE property = 'vesting_fund') + * + 10 ^ (SELECT precision FROM hafbe_app.dynamic_global_properties_cache WHERE property = 'vesting_fund') + ) / ( + (SELECT value FROM hafbe_app.dynamic_global_properties_cache WHERE property = 'vesting_shares') + * + 10 ^ (SELECT precision FROM hafbe_app.dynamic_global_properties_cache WHERE property = 'vesting_shares') + )::FLOAT; +END +$$ +; + /* account data */ diff --git a/api/endpoints.sql b/api/endpoints.sql index 557506f..2eaff5f 100644 --- a/api/endpoints.sql +++ b/api/endpoints.sql @@ -253,7 +253,7 @@ END $$ ; -CREATE FUNCTION hafbe_endpoints.get_witness_voters(_witness TEXT, _limit INT = 1000, _offset INT = 0, _order_by TEXT = 'vests', _order_is TEXT = 'desc') +CREATE FUNCTION hafbe_endpoints.get_witness_voters(_witness TEXT, _limit INT = 1000, _offset INT = 0, _order_by TEXT = 'vests', _order_is TEXT = 'desc', _to_hp BOOLEAN = TRUE) RETURNS JSON LANGUAGE 'plpgsql' AS @@ -283,16 +283,32 @@ BEGIN _order_is = 'desc'; END IF; - RETURN CASE WHEN arr IS NOT NULL THEN to_json(arr) ELSE '[]'::JSON END FROM ( - SELECT ARRAY( - SELECT hafbe_backend.get_set_of_witness_voters(__witness_id, _limit, _offset, _order_by, _order_is) - ) arr - ) result; + IF _to_hp IS NULL THEN + _to_hp = TRUE; + END IF; + + IF _to_hp THEN + + RETURN CASE WHEN arr IS NOT NULL THEN to_json(arr) ELSE '[]'::JSON END FROM ( + SELECT ARRAY( + SELECT hafbe_backend.get_set_of_witness_voters_in_hp(__witness_id, _limit, _offset, _order_by, _order_is) + ) arr + ) result; + + ELSE + + RETURN CASE WHEN arr IS NOT NULL THEN to_json(arr) ELSE '[]'::JSON END FROM ( + SELECT ARRAY( + SELECT hafbe_backend.get_set_of_witness_voters_in_vests(__witness_id, _limit, _offset, _order_by, _order_is) + ) arr + ) result; + + END IF; END $$ ; -CREATE FUNCTION hafbe_endpoints.get_witness_voters_daily_change(_witness TEXT, _limit INT = 1000, _offset INT = 0, _order_by TEXT = 'vests', _order_is TEXT = 'desc') +CREATE FUNCTION hafbe_endpoints.get_witness_voters_daily_change(_witness TEXT, _limit INT = 1000, _offset INT = 0, _order_by TEXT = 'vests', _order_is TEXT = 'desc', _to_hp BOOLEAN = TRUE) RETURNS JSON LANGUAGE 'plpgsql' AS @@ -322,16 +338,32 @@ BEGIN _order_is = 'desc'; END IF; - RETURN CASE WHEN arr IS NOT NULL THEN to_json(arr) ELSE '[]'::JSON END FROM ( - SELECT ARRAY( - SELECT hafbe_backend.get_set_of_witness_voters_daily_change(__witness_id, _limit, _offset, _order_by, _order_is) - ) arr - ) result; + IF _to_hp IS NULL THEN + _to_hp = TRUE; + END IF; + + IF _to_hp THEN + + RETURN CASE WHEN arr IS NOT NULL THEN to_json(arr) ELSE '[]'::JSON END FROM ( + SELECT ARRAY( + SELECT hafbe_backend.get_set_of_witness_voters_daily_change_in_hp(__witness_id, _limit, _offset, _order_by, _order_is) + ) arr + ) result; + + ELSE + + RETURN CASE WHEN arr IS NOT NULL THEN to_json(arr) ELSE '[]'::JSON END FROM ( + SELECT ARRAY( + SELECT hafbe_backend.get_set_of_witness_voters_daily_change_in_vests(__witness_id, _limit, _offset, _order_by, _order_is) + ) arr + ) result; + + END IF; END $$ ; -CREATE FUNCTION hafbe_endpoints.get_witnesses(_limit INT = 50, _offset INT = 0, _order_by TEXT = 'votes', _order_is TEXT = 'desc') +CREATE FUNCTION hafbe_endpoints.get_witnesses(_limit INT = 50, _offset INT = 0, _order_by TEXT = 'votes', _order_is TEXT = 'desc', _to_hp BOOLEAN = TRUE) RETURNS JSON LANGUAGE 'plpgsql' AS @@ -360,11 +392,27 @@ BEGIN _order_is = 'desc'; END IF; - RETURN CASE WHEN arr IS NOT NULL THEN to_json(arr) ELSE '[]'::JSON END FROM ( - SELECT ARRAY( - SELECT hafbe_backend.get_set_of_witnesses(_limit, _offset, _order_by, _order_is) - ) arr - ) result; + IF _to_hp IS NULL THEN + _to_hp = TRUE; + END IF; + + IF _to_hp THEN + + RETURN CASE WHEN arr IS NOT NULL THEN to_json(arr) ELSE '[]'::JSON END FROM ( + SELECT ARRAY( + SELECT hafbe_backend.get_set_of_witnesses_in_hp(_limit, _offset, _order_by, _order_is) + ) arr + ) result; + + ELSE + + RETURN CASE WHEN arr IS NOT NULL THEN to_json(arr) ELSE '[]'::JSON END FROM ( + SELECT ARRAY( + SELECT hafbe_backend.get_set_of_witnesses_in_vests(_limit, _offset, _order_by, _order_is) + ) arr + ) result; + + END IF; END $$ ; diff --git a/api/types.sql b/api/types.sql index c8c108a..e187783 100644 --- a/api/types.sql +++ b/api/types.sql @@ -28,7 +28,7 @@ CREATE TYPE hafbe_types.block AS ( signing_key TEXT ); -CREATE TYPE hafbe_types.witness_voters AS ( +CREATE TYPE hafbe_types.witness_voters_in_vests AS ( account TEXT, vests NUMERIC, account_vests NUMERIC, @@ -36,7 +36,15 @@ CREATE TYPE hafbe_types.witness_voters AS ( timestamp TIMESTAMP ); -CREATE TYPE hafbe_types.witness_voters_daily_change AS ( +CREATE TYPE hafbe_types.witness_voters_in_hp AS ( + account TEXT, + hive_power FLOAT, + account_hive_power FLOAT, + proxied_hive_power FLOAT, + timestamp TIMESTAMP +); + +CREATE TYPE hafbe_types.witness_voters_daily_change_in_vests AS ( account TEXT, approve BOOLEAN, vests BIGINT, @@ -45,7 +53,16 @@ CREATE TYPE hafbe_types.witness_voters_daily_change AS ( timestamp TIMESTAMP ); -CREATE TYPE hafbe_types.witnesses AS ( +CREATE TYPE hafbe_types.witness_voters_daily_change_in_hp AS ( + account TEXT, + approve BOOLEAN, + hive_power FLOAT, + account_hive_power FLOAT, + proxied_hive_power FLOAT, + timestamp TIMESTAMP +); + +CREATE TYPE hafbe_types.witnesses_in_vests AS ( witness TEXT, rank INT, url TEXT, @@ -59,4 +76,20 @@ CREATE TYPE hafbe_types.witnesses AS ( block_size INT, signing_key TEXT, version TEXT +); + +CREATE TYPE hafbe_types.witnesses_in_hp AS ( + witness TEXT, + rank INT, + url TEXT, + votes FLOAT, + votes_daily_change FLOAT, + voters_num INT, + voters_num_daily_change INT, + price_feed FLOAT, + bias NUMERIC, + feed_age INTERVAL, + block_size INT, + signing_key TEXT, + version TEXT ); \ No newline at end of file diff --git a/db/hafbe_app.sql b/db/hafbe_app.sql index 1763b5f..87fca05 100644 --- a/db/hafbe_app.sql +++ b/db/hafbe_app.sql @@ -18,6 +18,7 @@ BEGIN last_reported_at TIMESTAMP, last_reported_block INT ); + INSERT INTO hafbe_app.app_status (continue_processing, last_processed_block, started_processing_at, finished_processing_at, last_reported_at, last_reported_block) VALUES (TRUE, 0, NULL, NULL, to_timestamp(0), 0); @@ -143,6 +144,14 @@ BEGIN CONSTRAINT pk_witness_votes_change_cache PRIMARY KEY (witness_id) ); + + CREATE TABLE hafbe_app.dynamic_global_properties_cache ( + property TEXT NOT NULL, + value NUMERIC NOT NULL, + precision SMALLINT NOT NULL, + + CONSTRAINT pk_dynamic_global_properties_cache PRIMARY KEY (property) + ); END $$ ; @@ -666,6 +675,28 @@ END $$ ; +CREATE OR REPLACE FUNCTION hafbe_app.get_dynamic_global_properties() +RETURNS JSON +LANGUAGE 'plpython3u' +AS +$$ + import subprocess + import json + + return json.dumps( + json.loads( + subprocess.check_output([ + """ + curl -X POST https://api.hive.blog \ + -H 'Content-Type: application/json' \ + -d '{"jsonrpc": "2.0", "method": "database_api.get_dynamic_global_properties", "id": null}' + """ + ], shell=True).decode('utf-8') + )['result'] + ) +$$ +; + CREATE OR REPLACE PROCEDURE hafbe_app.update_witnesses_cache() AS $function$ @@ -717,7 +748,20 @@ BEGIN GROUP BY witness_id; RAISE NOTICE 'Updated witness change cache'; + + INSERT INTO hafbe_app.dynamic_global_properties_cache(property, value, precision) + SELECT + unnest(array['vesting_fund', 'vesting_shares']), + unnest(array[(props->'total_vesting_fund_hive'->>'amount'), (props->'total_vesting_shares'->>'amount')])::NUMERIC, + unnest(array[(props->'total_vesting_fund_hive'->>'precision'), (props->'total_vesting_shares'->>'precision')])::SMALLINT + FROM hafbe_app.get_dynamic_global_properties() props + ON CONFLICT ON CONSTRAINT pk_dynamic_global_properties_cache DO UPDATE SET + value = EXCLUDED.value, + precision = EXCLUDED.precision + ; + RAISE NOTICE 'Updated global properties cache'; + UPDATE hafbe_app.witnesses_cache_config SET last_updated_at = NOW(); END $function$ -- GitLab From 5be4b3fe463c3024225687f8c0403ecee37ab0b2 Mon Sep 17 00:00:00 2001 From: kristupas Date: Sun, 13 Nov 2022 18:42:51 +0000 Subject: [PATCH 77/89] Added index creation after massive processing #22 --- api/endpoints.sql | 6 +++--- db/hafbe_app.sql | 18 ++++++++---------- 2 files changed, 11 insertions(+), 13 deletions(-) diff --git a/api/endpoints.sql b/api/endpoints.sql index 2eaff5f..70c9b2f 100644 --- a/api/endpoints.sql +++ b/api/endpoints.sql @@ -180,7 +180,7 @@ BEGIN RETURN CASE WHEN arr IS NOT NULL THEN to_json(arr) ELSE '[]'::JSON END FROM ( SELECT ARRAY( - SELECT to_json(hafbe_backend.get_set_of_ops_by_account(__account_id, _top_op_id, _limit, _filter, _date_start, _date_end)) + SELECT hafbe_backend.get_set_of_ops_by_account(__account_id, _top_op_id, _limit, _filter, _date_start, _date_end) ) arr ) result; END @@ -199,7 +199,7 @@ BEGIN RETURN CASE WHEN arr IS NOT NULL THEN to_json(arr) ELSE '[]'::JSON END FROM ( SELECT ARRAY( - SELECT to_json(hafbe_backend.get_set_of_block_data(_block_num)) + SELECT hafbe_backend.get_set_of_block_data(_block_num) ) arr ) result; END @@ -234,7 +234,7 @@ BEGIN RETURN CASE WHEN arr IS NOT NULL THEN to_json(arr) ELSE '[]'::JSON END FROM ( SELECT ARRAY( - SELECT to_json(hafbe_backend.get_set_of_ops_by_block(_block_num, _top_op_id, _limit, _filter)) + SELECT hafbe_backend.get_set_of_ops_by_block(_block_num, _top_op_id, _limit, _filter) ) arr ) result; END diff --git a/db/hafbe_app.sql b/db/hafbe_app.sql index 87fca05..e3a75c9 100644 --- a/db/hafbe_app.sql +++ b/db/hafbe_app.sql @@ -822,23 +822,21 @@ BEGIN IF __next_block_range.first_block != __next_block_range.last_block THEN CALL hafbe_app.do_massive_processing(_appContext, __next_block_range.first_block, __next_block_range.last_block, 100, __last_block); - UPDATE hafbe_app.app_status SET finished_processing_at = NOW() FROM ( - SELECT CASE WHEN finished_processing_at IS NULL THEN TRUE ELSE FALSE END AS not_updated - FROM hafbe_app.app_status - LIMIT 1 - ) app_stat - WHERE app_stat.not_updated; ELSE CALL hafbe_app.processBlock(__next_block_range.last_block); __last_block := __next_block_range.last_block; END IF; - IF __next_block_range.first_block = __next_block_range.last_block AND - (NOW() - (SELECT last_updated_at FROM hafbe_app.witnesses_cache_config LIMIT 1)) >= - (SELECT update_interval FROM hafbe_app.witnesses_cache_config LIMIT 1) THEN + IF __next_block_range.first_block = __next_block_range.last_block AND + (SELECT finished_processing_at FROM hafbe_app.app_status LIMIT 1) IS NULL THEN + UPDATE hafbe_app.app_status SET finished_processing_at = NOW(); + PERFORM hafbe_indexes.create_hafbe_indexes(); + END IF; + IF __next_block_range.first_block = __next_block_range.last_block AND + (NOW() - (SELECT last_updated_at FROM hafbe_app.witnesses_cache_config LIMIT 1)) >= + (SELECT update_interval FROM hafbe_app.witnesses_cache_config LIMIT 1) THEN CALL hafbe_app.update_witnesses_cache(); - END IF; END IF; -- GitLab From b5cca69c973a3a5e1b7252d520667c3ec28bb23b Mon Sep 17 00:00:00 2001 From: kristupas Date: Mon, 21 Nov 2022 19:00:49 -0500 Subject: [PATCH 78/89] Improved 'get_ops_by_account()' WHERE statement, changed '_limit' type to INT #22 --- api/backend.sql | 36 ++++++++++++++++++++++++++---------- api/endpoints.sql | 6 +++--- 2 files changed, 29 insertions(+), 13 deletions(-) diff --git a/api/backend.sql b/api/backend.sql index e1a36fe..1325579 100644 --- a/api/backend.sql +++ b/api/backend.sql @@ -108,17 +108,32 @@ END $$ ; -CREATE FUNCTION hafbe_backend.get_set_of_ops_by_account(_account_id INT, _top_op_id BIGINT, _limit BIGINT, _filter SMALLINT[], _date_start TIMESTAMP, _date_end TIMESTAMP) -RETURNS SETOF hafbe_types.operations +CREATE FUNCTION hafbe_backend.get_set_of_ops_by_account(_account_id INT, _top_op_id INT, _limit INT, _filter SMALLINT[], _date_start TIMESTAMP, _date_end TIMESTAMP) +RETURNS SETOF hafbe_types.operations AS $function$ DECLARE - __filter_ops BOOLEAN = ((SELECT array_length(_filter, 1)) IS NULL); + __no_ops_filter BOOLEAN = ((SELECT array_length(_filter, 1)) IS NULL); __no_start_date BOOLEAN = (_date_start IS NULL); __no_end_date BOOLEAN = (_date_end IS NULL); + __no_filters BOOLEAN; + __subq_limit INT; + __lastest_account_op_seq_no INT; __block_start INT; __block_end INT; BEGIN + IF __no_ops_filter AND __no_start_date AND __no_end_date THEN + SELECT TRUE INTO __no_filters; + SELECT NULL INTO __subq_limit; + SELECT INTO __lastest_account_op_seq_no + account_op_seq_no FROM hive.account_operations_view WHERE account_id = _account_id ORDER BY account_op_seq_no DESC LIMIT 1; + SELECT INTO _top_op_id + CASE WHEN __lastest_account_op_seq_no < _top_op_id THEN __lastest_account_op_seq_no ELSE _top_op_id END; + ELSE + SELECT FALSE INTO __no_filters; + SELECT _limit INTO __subq_limit; + END IF; + IF __no_start_date IS FALSE THEN SELECT num FROM hive.blocks_view hbv WHERE hbv.created_at >= _date_start ORDER BY created_at ASC LIMIT 1 INTO __block_start; END IF; @@ -140,13 +155,14 @@ BEGIN SELECT haov.operation_id, haov.op_type_id, haov.block_num, haov.account_op_seq_no FROM hive.account_operations_view haov WHERE - haov.account_id = _account_id AND - haov.account_op_seq_no <= _top_op_id AND ( - __filter_ops OR haov.op_type_id = ANY(_filter)) AND + haov.account_id = _account_id AND + haov.account_op_seq_no <= _top_op_id AND + (NOT __no_filters OR haov.account_op_seq_no > _top_op_id - _limit) AND + (__no_ops_filter OR haov.op_type_id = ANY(_filter)) AND (__no_start_date OR haov.block_num >= __block_start) AND (__no_end_date OR haov.block_num < __block_end) ORDER BY haov.operation_id DESC - LIMIT _limit + LIMIT __subq_limit ) ls JOIN hive.operations_view hov ON hov.id = ls.operation_id JOIN hive.operation_types hot ON hot.id = ls.op_type_id @@ -160,12 +176,12 @@ SET join_collapse_limit=16 SET from_collapse_limit=16 ; -CREATE FUNCTION hafbe_backend.get_set_of_ops_by_block(_block_num INT, _top_op_id BIGINT, _limit BIGINT, _filter SMALLINT[]) +CREATE FUNCTION hafbe_backend.get_set_of_ops_by_block(_block_num INT, _top_op_id BIGINT, _limit INT, _filter SMALLINT[]) RETURNS SETOF hafbe_types.operations AS $function$ DECLARE - __filter_ops BOOLEAN = ((SELECT array_length(_filter, 1)) IS NULL); + __no_ops_filter BOOLEAN = ((SELECT array_length(_filter, 1)) IS NULL); BEGIN RETURN QUERY SELECT encode(htv.trx_hash, 'hex'), @@ -183,7 +199,7 @@ BEGIN WHERE hov.block_num = _block_num AND hov.id <= _top_op_id AND - (__filter_ops OR hov.op_type_id = ANY(_filter)) + (__no_ops_filter OR hov.op_type_id = ANY(_filter)) ORDER BY hov.id DESC LIMIT _limit ) ls diff --git a/api/endpoints.sql b/api/endpoints.sql index 70c9b2f..7483ce0 100644 --- a/api/endpoints.sql +++ b/api/endpoints.sql @@ -152,7 +152,7 @@ END $$ ; -CREATE FUNCTION hafbe_endpoints.get_ops_by_account(_account TEXT, _top_op_id BIGINT = 9223372036854775807, _limit BIGINT = 1000, _filter SMALLINT[] = ARRAY[]::SMALLINT[], _date_start TIMESTAMP = NULL, _date_end TIMESTAMP = NULL) +CREATE FUNCTION hafbe_endpoints.get_ops_by_account(_account TEXT, _top_op_id INT = 2147483647, _limit INT = 1000, _filter SMALLINT[] = ARRAY[]::SMALLINT[], _date_start TIMESTAMP = NULL, _date_end TIMESTAMP = NULL) RETURNS JSON LANGUAGE 'plpgsql' AS @@ -161,7 +161,7 @@ DECLARE __account_id INT; BEGIN IF _top_op_id IS NULL OR _top_op_id < 0 THEN - _top_op_id = 9223372036854775807; + _top_op_id = 2147483647; END IF; IF _limit IS NULL OR _limit <= 0 THEN @@ -206,7 +206,7 @@ END $$ ; -CREATE FUNCTION hafbe_endpoints.get_ops_by_block(_block_num INT, _top_op_id BIGINT = 9223372036854775807, _limit BIGINT = 1000, _filter SMALLINT[] = ARRAY[]::SMALLINT[]) +CREATE FUNCTION hafbe_endpoints.get_ops_by_block(_block_num INT, _top_op_id BIGINT = 9223372036854775807, _limit INT = 1000, _filter SMALLINT[] = ARRAY[]::SMALLINT[]) RETURNS JSON LANGUAGE 'plpgsql' AS -- GitLab From 6d363a09a6daa5ada880987decd28fa1b2876ffb Mon Sep 17 00:00:00 2001 From: kristupas Date: Tue, 22 Nov 2022 21:58:48 +0000 Subject: [PATCH 79/89] Added witnesses methods to performance tests #22 --- README.md | 4 +- api/endpoints.sql | 4 +- run.sh | 2 +- tests/performance/endpoints.jmx | 138 +++++++++++++++++++------------ tests/performance/generate_db.py | 12 +-- tests/run_performance_tests.sh | 3 +- 6 files changed, 100 insertions(+), 63 deletions(-) diff --git a/README.md b/README.md index 6b362c7..6000e13 100644 --- a/README.md +++ b/README.md @@ -75,9 +75,9 @@ then run tests with: ./run.sh run-tests ``` -E.g. this will run 20 threads (THREAD_NUM * SUITE_NUM) with 200 loops and with unique params for each request: +E.g. this will run 28 threads (THREAD_NUM * SUITE_NUM) with 200 loops and with unique params for each request: ``` -./run.sh run-tests 2 200 4000 +./run.sh run-tests 2 200 5600 ``` Read test result in Apache JMeter Dashboard, generated at `tests/performance/result/result_report/index,html` diff --git a/api/endpoints.sql b/api/endpoints.sql index 7483ce0..a5c01b0 100644 --- a/api/endpoints.sql +++ b/api/endpoints.sql @@ -363,14 +363,14 @@ END $$ ; -CREATE FUNCTION hafbe_endpoints.get_witnesses(_limit INT = 50, _offset INT = 0, _order_by TEXT = 'votes', _order_is TEXT = 'desc', _to_hp BOOLEAN = TRUE) +CREATE FUNCTION hafbe_endpoints.get_witnesses(_limit INT = 1000, _offset INT = 0, _order_by TEXT = 'votes', _order_is TEXT = 'desc', _to_hp BOOLEAN = TRUE) RETURNS JSON LANGUAGE 'plpgsql' AS $$ BEGIN IF _limit IS NULL OR _limit <= 0 THEN - _limit = 50; + _limit = 1000; END IF; IF _offset IS NULL OR _offset < 0 THEN diff --git a/run.sh b/run.sh index 2adb372..07e0467 100755 --- a/run.sh +++ b/run.sh @@ -44,7 +44,7 @@ DB_NAME=haf_block_log owner_role=hafbe_owner admin_role=haf_admin -if [ "$1" != "start" ]; then +if [[ ! "run-tests start" =~ "$1" ]]; then sudo echo fi; diff --git a/tests/performance/endpoints.jmx b/tests/performance/endpoints.jmx index ac43fe9..a64ced9 100644 --- a/tests/performance/endpoints.jmx +++ b/tests/performance/endpoints.jmx @@ -89,7 +89,41 @@ - + + continue + + false + ${LOOP_COUNT} + + ${THREAD_NUM} + 1 + false + + + true + + + + + + + + + + + rpc/get_op_types + POST + true + false + true + false + + + + + + + continue false @@ -103,14 +137,14 @@ true - + true false { - "_partial_account_name": "${partial_account_name_value}" + "_account": "${account_value}" } = @@ -120,7 +154,7 @@ - rpc/find_matching_accounts + rpc/get_acc_op_types POST true false @@ -132,7 +166,7 @@ - + continue false @@ -146,15 +180,24 @@ true - - - + + true + + + + false + { + "_block_num": "${block_num_value}" +} + = + + - rpc/get_op_types + rpc/get_block_op_types POST true false @@ -166,7 +209,7 @@ - + continue false @@ -180,7 +223,7 @@ true - + true @@ -197,7 +240,7 @@ - rpc/get_acc_op_types + rpc/get_ops_by_account POST true false @@ -209,7 +252,7 @@ - + continue false @@ -223,7 +266,7 @@ true - + true @@ -240,7 +283,7 @@ - rpc/get_block_op_types + rpc/get_block POST true false @@ -252,7 +295,7 @@ - + continue false @@ -266,24 +309,24 @@ true - + + true false { - "_account": "${account_value}" + "_block_num": "${block_num_value}" } = - true - rpc/get_ops_by_account + rpc/get_ops_by_block POST true false @@ -295,7 +338,7 @@ - + continue false @@ -309,14 +352,14 @@ true - + true false { - "_block_num": "${block_num_value}" + "_trx_hash": "${trx_hash_value}" } = @@ -326,7 +369,7 @@ - rpc/get_block + rpc/get_transaction POST true false @@ -338,7 +381,7 @@ - + continue false @@ -352,14 +395,14 @@ true - + true false { - "_block_num": "${block_num_value}" + "_witness": "${account_value}" } = @@ -369,7 +412,7 @@ - rpc/get_ops_by_block + rpc/get_witness_voters POST true false @@ -381,7 +424,7 @@ - + continue false @@ -395,13 +438,15 @@ true - + true false - {} + { + "_witness": "${account_value}" +} = @@ -410,7 +455,7 @@ - rpc/get_top_witnesses + rpc/get_witness_voters_daily_change POST true false @@ -422,7 +467,7 @@ - + continue false @@ -436,24 +481,15 @@ true - - true - - - - false - { - "_account": "${account_value}" -} - = - - + + + - rpc/get_witness_by_account + rpc/get_witnesses POST true false @@ -508,7 +544,7 @@ - + continue false @@ -522,14 +558,14 @@ true - + true false { - "_trx_hash": "${trx_hash_value}" + "_account": "${account_value}" } = @@ -539,7 +575,7 @@ - rpc/get_transaction + rpc/get_account_resource_credits POST true false @@ -653,4 +689,4 @@ - \ No newline at end of file + diff --git a/tests/performance/generate_db.py b/tests/performance/generate_db.py index 4c5e8d3..1d87e37 100644 --- a/tests/performance/generate_db.py +++ b/tests/performance/generate_db.py @@ -15,21 +15,21 @@ def gen_rand_block_range(limit): return [str(random.randint(0, max_block)) for i in range(limit)] def get_acc_names(limit): - return call_sql("SELECT name FROM hive.accounts", limit) + return call_sql("SELECT hav.name FROM hafbe_app.current_witnesses cw JOIN hive.accounts_view hav ON hav.id = cw.witness_id", limit) def generate_input_db(): limit = db_size // 4 data = gen_rand_block_range(limit) rand_block_arr_str = "'{%s}'" % ','.join(gen_rand_block_range(limit)) - data += call_sql("SELECT encode(hash, 'hex') FROM hive.blocks WHERE num = ANY(%s)" % rand_block_arr_str, limit) - data += call_sql("SELECT encode(trx_hash, 'hex') FROM hive.transactions WHERE block_num = ANY(%s)" % rand_block_arr_str, limit) + data += call_sql("SELECT encode(hash, 'hex') FROM hive.blocks_view WHERE num = ANY(%s)" % rand_block_arr_str, limit) + data += call_sql("SELECT encode(trx_hash, 'hex') FROM hive.transactions_view WHERE block_num = ANY(%s)" % rand_block_arr_str, limit) data += get_acc_names(limit) return data def generate_db(): rand_blocks = gen_rand_block_range(db_size) rand_block_arr_str = "'{%s}'" % ','.join(gen_rand_block_range(db_size)) - trx_hashes = call_sql("SELECT '\\x' || encode(trx_hash, 'hex') FROM hive.transactions WHERE block_num = ANY(%s)" % rand_block_arr_str, db_size) + trx_hashes = call_sql("SELECT encode(trx_hash, 'hex') FROM hive.transactions_view WHERE block_num = ANY(%s)" % rand_block_arr_str, db_size) acc_names = get_acc_names(db_size) partial_acc_names = [el[:-1] for el in acc_names] input_data = generate_input_db() @@ -40,7 +40,7 @@ def generate_db(): random.shuffle(partial_acc_names) random.shuffle(input_data) - data = [f'{block},\{trx_hash},{name},{part_name},{input}' for block, trx_hash, name, part_name, input in zip( + data = [f'{block},{trx_hash},{name},{part_name},{input}' for block, trx_hash, name, part_name, input in zip( rand_blocks, trx_hashes, acc_names, partial_acc_names, input_data )] @@ -53,6 +53,6 @@ if __name__ == '__main__': db_dir = os.path.join(os.getcwd(), 'tests', 'performance', 'result') psql_cmd = 'psql -d haf_block_log -c "%s LIMIT %d"' - max_block = int(call_sql("SELECT num FROM hive.blocks ORDER BY num DESC", 1)[0]) + max_block = int(call_sql("SELECT num FROM hive.blocks_view ORDER BY num DESC", 1)[0]) generate_db() \ No newline at end of file diff --git a/tests/run_performance_tests.sh b/tests/run_performance_tests.sh index 2743bb6..50122b2 100755 --- a/tests/run_performance_tests.sh +++ b/tests/run_performance_tests.sh @@ -12,6 +12,7 @@ cleanup() { mkdir $RESULT_DIR mkdir $RESULT_REPORT_DIR } + generate_db() { DB_SIZE=$1 python3 $PWD/tests/performance/generate_db.py --db_size=$DB_SIZE @@ -51,7 +52,7 @@ JTL_PATH=$RESULT_DIR/"report.jtl" JMETER=jmeter-5.4.3 -args=("${@:2}") +args=("${@:2}") cleanup generate_db ${args[3]} -- GitLab From 3e8fae44ae187db13ba31e1042fff8838f622386 Mon Sep 17 00:00:00 2001 From: kristupas Date: Wed, 23 Nov 2022 13:16:36 -0500 Subject: [PATCH 80/89] Changed to dynamic query to avoid reusing same plan #22 --- README.md | 3 ++- api/backend.sql | 67 +++++++++++++++++++++++++++++-------------------- 2 files changed, 42 insertions(+), 28 deletions(-) diff --git a/README.md b/README.md index 6000e13..6969864 100644 --- a/README.md +++ b/README.md @@ -77,7 +77,8 @@ then run tests with: E.g. this will run 28 threads (THREAD_NUM * SUITE_NUM) with 200 loops and with unique params for each request: ``` -./run.sh run-tests 2 200 5600 +./run.sh run-tests 2 200 5600 ``` +Server port must be specified as first arg. Read test result in Apache JMeter Dashboard, generated at `tests/performance/result/result_report/index,html` diff --git a/api/backend.sql b/api/backend.sql index 1325579..14834d4 100644 --- a/api/backend.sql +++ b/api/backend.sql @@ -141,33 +141,46 @@ BEGIN SELECT num FROM hive.blocks_view hbv WHERE hbv.created_at < _date_end ORDER BY created_at DESC LIMIT 1 INTO __block_end; END IF; - RETURN QUERY SELECT - encode(htv.trx_hash, 'hex'), - ls.block_num, - hov.trx_in_block, - hov.op_pos, - hot.is_virtual, - hov.timestamp::TEXT, - hov.body::JSON, - ls.operation_id, - ls.account_op_seq_no - FROM ( - SELECT haov.operation_id, haov.op_type_id, haov.block_num, haov.account_op_seq_no - FROM hive.account_operations_view haov - WHERE - haov.account_id = _account_id AND - haov.account_op_seq_no <= _top_op_id AND - (NOT __no_filters OR haov.account_op_seq_no > _top_op_id - _limit) AND - (__no_ops_filter OR haov.op_type_id = ANY(_filter)) AND - (__no_start_date OR haov.block_num >= __block_start) AND - (__no_end_date OR haov.block_num < __block_end) - ORDER BY haov.operation_id DESC - LIMIT __subq_limit - ) ls - JOIN hive.operations_view hov ON hov.id = ls.operation_id - JOIN hive.operation_types hot ON hot.id = ls.op_type_id - LEFT JOIN hive.transactions_view htv ON htv.block_num = ls.block_num AND htv.trx_in_block = hov.trx_in_block - ORDER BY ls.operation_id DESC; + RETURN QUERY EXECUTE format( + $query$ + + SELECT + encode(htv.trx_hash, 'hex'), + ls.block_num, + hov.trx_in_block, + hov.op_pos, + hot.is_virtual, + hov.timestamp::TEXT, + hov.body::JSON, + ls.operation_id, + ls.account_op_seq_no + FROM ( + SELECT haov.operation_id, haov.op_type_id, haov.block_num, haov.account_op_seq_no + FROM hive.account_operations_view haov + WHERE + haov.account_id = %L::INT AND + haov.account_op_seq_no <= %L::INT AND + (NOT %L OR haov.account_op_seq_no > %L::INT - %L::INT) AND + (%L OR haov.op_type_id = ANY(%L)) AND + (%L OR haov.block_num >= %L::INT) AND + (%L OR haov.block_num < %L::INT) + ORDER BY haov.operation_id DESC + LIMIT %L + ) ls + JOIN hive.operations_view hov ON hov.id = ls.operation_id + JOIN hive.operation_types hot ON hot.id = ls.op_type_id + LEFT JOIN hive.transactions_view htv ON htv.block_num = ls.block_num AND htv.trx_in_block = hov.trx_in_block + ORDER BY ls.operation_id DESC; + + $query$, + _account_id, + _top_op_id, + __no_filters, _top_op_id, _limit, + __no_ops_filter, _filter, + __no_start_date, __block_start, + __no_end_date, __block_end, + __subq_limit + ) res; END $function$ LANGUAGE 'plpgsql' STABLE -- GitLab From c4b3935b0be0e8c604954b24ceaeb83ed7fe49cf Mon Sep 17 00:00:00 2001 From: kristupas Date: Wed, 23 Nov 2022 14:00:27 -0500 Subject: [PATCH 81/89] Updated JMeter version #22 --- scripts/setup_dependancies.sh | 10 +++++++--- tests/run_performance_tests.sh | 2 +- 2 files changed, 8 insertions(+), 4 deletions(-) diff --git a/scripts/setup_dependancies.sh b/scripts/setup_dependancies.sh index cd3666e..7cdb57e 100755 --- a/scripts/setup_dependancies.sh +++ b/scripts/setup_dependancies.sh @@ -1,3 +1,8 @@ +#!/bin/bash + +set -e +set -o pipefail + install_postgrest() { sudo apt-get update -y sudo apt-get install wget -y @@ -33,12 +38,11 @@ install_jmeter() { sudo chmod +x $jmeter sudo mv $jmeter "/usr/local/bin/${jmeter}" - sudo chmod 777 /usr/local/src/apache-jmeter-5.4.3/bin/ - sudo chmod 777 /usr/local/src/apache-jmeter-5.4.3/bin/jmeter.log + sudo chmod 777 /usr/local/src/apache-jmeter-$jmeter_v/bin } postgrest_v=9.0.0 -jmeter_v=5.4.3 +jmeter_v=5.5 if [ "$1" = "all" ]; then install_postgrest diff --git a/tests/run_performance_tests.sh b/tests/run_performance_tests.sh index 50122b2..d60e66b 100755 --- a/tests/run_performance_tests.sh +++ b/tests/run_performance_tests.sh @@ -50,7 +50,7 @@ JMX_OUT=$RESULT_DIR/$JMX_FILE JTL_PATH=$RESULT_DIR/"report.jtl" -JMETER=jmeter-5.4.3 +JMETER=jmeter-5.5 args=("${@:2}") -- GitLab From 336c9063c19eca3004b41b88ec086990479d46ee Mon Sep 17 00:00:00 2001 From: kristupas Date: Wed, 23 Nov 2022 14:07:51 -0500 Subject: [PATCH 82/89] Added 'get_witness_voters_num()' #22 --- api/backend.sql | 11 +++++++++++ api/endpoints.sql | 13 +++++++++++++ 2 files changed, 24 insertions(+) diff --git a/api/backend.sql b/api/backend.sql index 14834d4..670c9e1 100644 --- a/api/backend.sql +++ b/api/backend.sql @@ -261,6 +261,17 @@ SET from_collapse_limit=16 witness voters */ +CREATE FUNCTION hafbe_backend.get_witness_voters_num(_witness_id INT) +RETURNS INT +LANGUAGE 'plpgsql' +AS +$$ +BEGIN + RETURN COUNT(1) FROM hafbe_app.current_witness_votes WHERE witness_id = _witness_id; +END +$$ +; + CREATE FUNCTION hafbe_backend.get_set_of_witness_voters_in_vests(_witness_id INT, _limit INT, _offset INT, _order_by TEXT, _order_is TEXT) RETURNS SETOF hafbe_types.witness_voters_in_vests AS diff --git a/api/endpoints.sql b/api/endpoints.sql index a5c01b0..71118d9 100644 --- a/api/endpoints.sql +++ b/api/endpoints.sql @@ -253,6 +253,19 @@ END $$ ; +CREATE FUNCTION hafbe_endpoints.get_witness_voters_num(_witness TEXT) +RETURNS INT +LANGUAGE 'plpgsql' +AS +$$ +DECLARE + __witness_id INT = hafbe_backend.get_account_id(_witness); +BEGIN + RETURN hafbe_backend.get_witness_voters_num(__witness_id); +END +$$ +; + CREATE FUNCTION hafbe_endpoints.get_witness_voters(_witness TEXT, _limit INT = 1000, _offset INT = 0, _order_by TEXT = 'vests', _order_is TEXT = 'desc', _to_hp BOOLEAN = TRUE) RETURNS JSON LANGUAGE 'plpgsql' -- GitLab From 23cc7bfc9d56956edf2f2a4b6ef6e245e62570ca Mon Sep 17 00:00:00 2001 From: kristupas Date: Wed, 23 Nov 2022 14:43:58 -0500 Subject: [PATCH 83/89] Added 'lower()' to 'get_input_type()' --- api/endpoints.sql | 3 +++ 1 file changed, 3 insertions(+) diff --git a/api/endpoints.sql b/api/endpoints.sql index 71118d9..775afa2 100644 --- a/api/endpoints.sql +++ b/api/endpoints.sql @@ -22,6 +22,9 @@ DECLARE __head_block_num INT; __accounts_array JSON; BEGIN + -- names in db are lowercase, no uppercase is used in hashes + SELECT lower(_input) INTO _input; + -- first, name existance is checked IF (SELECT 1 FROM hive.accounts_view WHERE name = _input LIMIT 1) IS NOT NULL THEN RETURN json_build_object( -- GitLab From 86962252acd21d08999f985049a562a97f53165e Mon Sep 17 00:00:00 2001 From: kristupas Date: Mon, 28 Nov 2022 18:10:30 +0000 Subject: [PATCH 84/89] Added 'json_metadata', keys, 'witness_votes' to 'get_account()' response #22 --- README.md | 6 ++--- api/endpoints.sql | 23 ++++++++++++++++- tests/performance/endpoints.jmx | 45 ++++++++++++++++++++++++++++++++- 3 files changed, 69 insertions(+), 5 deletions(-) diff --git a/README.md b/README.md index 6969864..21c0f31 100644 --- a/README.md +++ b/README.md @@ -75,10 +75,10 @@ then run tests with: ./run.sh run-tests ``` -E.g. this will run 28 threads (THREAD_NUM * SUITE_NUM) with 200 loops and with unique params for each request: +E.g. this will run 30 threads (THREAD_NUM * SUITE_NUM) with 200 loops and with unique params for each request: ``` -./run.sh run-tests 2 200 5600 +./run.sh run-tests 2 200 6000 ``` Server port must be specified as first arg. -Read test result in Apache JMeter Dashboard, generated at `tests/performance/result/result_report/index,html` +Read test result in Apache JMeter Dashboard, generated at `tests/performance/result/result_report/index.html` diff --git a/api/endpoints.sql b/api/endpoints.sql index 775afa2..1de5f3b 100644 --- a/api/endpoints.sql +++ b/api/endpoints.sql @@ -440,6 +440,8 @@ AS $$ DECLARE __response_data JSON; + __json_metadata JSON; + __posting_json_metadata JSON; __profile_image TEXT; BEGIN SELECT INTO __response_data @@ -454,11 +456,29 @@ BEGIN IF __profile_image IS NULL THEN SELECT hafbe_backend.parse_profile_picture(__response_data, 'posting_json_metadata') INTO __profile_image; END IF; + + BEGIN + SELECT TRIM(BOTH '"' FROM __response_data->>'json_metadata')::JSON INTO __json_metadata; + EXCEPTION WHEN others THEN + SELECT NULL INTO __json_metadata; + END; + + BEGIN + SELECT TRIM(BOTH '"' FROM __response_data->>'posting_json_metadata')::JSON INTO __posting_json_metadata; + EXCEPTION WHEN others THEN + SELECT NULL INTO __posting_json_metadata; + END; SELECT json_build_object( 'id', __response_data->>'id', 'name', _account, + 'owner', __response_data->'owner', + 'active', __response_data->'active', + 'posting', __response_data->'posting', + 'memo_key', __response_data->>'memo_key', 'profile_image', __profile_image, + 'json_metadata', __json_metadata, + 'posting_json_metadata', __posting_json_metadata, 'last_owner_update', __response_data->>'last_owner_update', 'last_account_update', __response_data->>'last_account_update', 'created', __response_data->>'created', @@ -490,7 +510,8 @@ BEGIN 'last_root_post', __response_data->>'last_root_post', 'last_vote_time', __response_data->>'last_vote_time', 'vesting_balance', __response_data->>'vesting_balance', - 'reputation', __response_data->>'reputation' + 'reputation', __response_data->>'reputation', + 'witness_votes', __response_data->'witness_votes' ) INTO __response_data; INSERT INTO hafbe_app.hived_account_cache (account, data, last_updated_at) diff --git a/tests/performance/endpoints.jmx b/tests/performance/endpoints.jmx index a64ced9..94be1cf 100644 --- a/tests/performance/endpoints.jmx +++ b/tests/performance/endpoints.jmx @@ -381,6 +381,49 @@ + + continue + + false + ${LOOP_COUNT} + + ${THREAD_NUM} + 1 + false + + + true + + + + true + + + + false + { + "_witness": "${account_value}" +} + = + + + + + + + + rpc/get_witness_voters_num + POST + true + false + true + false + + + + + + continue @@ -396,7 +439,6 @@ - true @@ -408,6 +450,7 @@ + true -- GitLab From dfe74d0751996014fb00ef52b1e5ff66a8b3a9d9 Mon Sep 17 00:00:00 2001 From: kristupas Date: Wed, 30 Nov 2022 21:33:35 +0000 Subject: [PATCH 85/89] Penalized 'get_witnesses()' with higher COST #22 --- api/backend.sql | 2 ++ 1 file changed, 2 insertions(+) diff --git a/api/backend.sql b/api/backend.sql index 670c9e1..406e645 100644 --- a/api/backend.sql +++ b/api/backend.sql @@ -184,6 +184,7 @@ BEGIN END $function$ LANGUAGE 'plpgsql' STABLE +COST 10000 SET JIT=OFF SET join_collapse_limit=16 SET from_collapse_limit=16 @@ -713,6 +714,7 @@ BEGIN END $function$ LANGUAGE 'plpgsql' STABLE +COST 10000 SET JIT=OFF SET join_collapse_limit=16 SET from_collapse_limit=16 -- GitLab From fba73b1bb4bd788c5c01cba9c4e21692ffeac1f4 Mon Sep 17 00:00:00 2001 From: kristupas Date: Fri, 2 Dec 2022 17:17:58 -0500 Subject: [PATCH 86/89] Added witness node version parsing, forced index use for massive processing #22 --- db/hafbe_app.sql | 34 ++++++++++++++++++++++++++++------ 1 file changed, 28 insertions(+), 6 deletions(-) diff --git a/db/hafbe_app.sql b/db/hafbe_app.sql index e3a75c9..f87787a 100644 --- a/db/hafbe_app.sql +++ b/db/hafbe_app.sql @@ -5,8 +5,6 @@ RETURNS VOID LANGUAGE 'plpgsql' AS $$ -DECLARE - __hardfork_one_op_id INT = 1176568; BEGIN RAISE NOTICE 'Attempting to create an application schema tables...'; @@ -216,12 +214,13 @@ $$ CREATE OR REPLACE FUNCTION hafbe_app.process_block_range_data_c(_from INT, _to INT) RETURNS VOID -LANGUAGE 'plpgsql' AS -$$ +$function$ DECLARE __balance_impacting_ops_ids INT[] = (SELECT op_type_ids_arr FROM hafbe_app.balance_impacting_op_ids LIMIT 1); BEGIN + SET enable_bitmapscan = OFF; + -- process vote ops WITH select_votes_ops AS ( SELECT hav_w.id AS witness_id, hav_v.id AS voter_id, approve, timestamp, operation_id @@ -346,11 +345,31 @@ BEGIN ) INSERT INTO hafbe_app.current_witnesses (witness_id, url, price_feed, bias, feed_updated_at, block_size, signing_key, version) - SELECT hav.id, NULL, NULL, NULL, NULL, NULL, NULL, '1.27.0' + SELECT hav.id, NULL, NULL, NULL, NULL, NULL, NULL, NULL FROM select_witness_names swn JOIN hive.hafbe_app_accounts_view hav ON hav.name = swn.name ON CONFLICT ON CONSTRAINT pk_current_witnesses DO NOTHING; + -- insert witness node version + UPDATE hafbe_app.current_witnesses cw SET version = w_node.version FROM ( + SELECT witness_id, version + FROM ( + SELECT + cw.witness_id, + CASE WHEN extensions->0->>'type' = 'version' THEN + extensions->0->>'value' + ELSE + extensions->1->>'value' + END AS version, + ROW_NUMBER() OVER (PARTITION BY cw.witness_id ORDER BY num DESC) AS row_n + FROM hive.hafbe_app_blocks_view hbv + JOIN hafbe_app.current_witnesses cw ON cw.witness_id = hbv.producer_account_id + WHERE num BETWEEN _from AND _to AND extensions IS NOT NULL + ) row_count + WHERE row_n = 1 AND version IS NOT NULL + ) w_node + WHERE cw.witness_id = w_node.witness_id; + -- parse witness url WITH select_ops_with_url AS ( SELECT witness, value, op_type_id, operation_id @@ -579,8 +598,11 @@ BEGIN ON CONFLICT ON CONSTRAINT pk_account_vests DO UPDATE SET vests = hafbe_app.account_vests.vests + EXCLUDED.vests ; + + SET enable_bitmapscan = ON; END -$$ +$function$ +LANGUAGE 'plpgsql' VOLATILE SET from_collapse_limit = 16 SET join_collapse_limit = 16 SET jit = OFF -- GitLab From c411096b8a31996fe90a4af82cdb2a402a1d53c9 Mon Sep 17 00:00:00 2001 From: kristupas Date: Sun, 18 Dec 2022 17:20:13 -0500 Subject: [PATCH 87/89] Added 'age' for 'operations' and 'transactions' #22 --- api/backend.sql | 6 ++++-- api/endpoints.sql | 5 ++++- api/types.sql | 3 ++- 3 files changed, 10 insertions(+), 4 deletions(-) diff --git a/api/backend.sql b/api/backend.sql index 406e645..30bbbb2 100644 --- a/api/backend.sql +++ b/api/backend.sql @@ -150,7 +150,8 @@ BEGIN hov.trx_in_block, hov.op_pos, hot.is_virtual, - hov.timestamp::TEXT, + hov.timestamp, + NOW() - hov.timestamp, hov.body::JSON, ls.operation_id, ls.account_op_seq_no @@ -203,7 +204,8 @@ BEGIN ls.trx_in_block, ls.op_pos, hot.is_virtual, - ls.timestamp::TEXT, + ls.timestamp, + NOW() - ls.timestamp, ls.body::JSON, ls.id, NULL::INT diff --git a/api/endpoints.sql b/api/endpoints.sql index 1de5f3b..070673f 100644 --- a/api/endpoints.sql +++ b/api/endpoints.sql @@ -249,9 +249,12 @@ RETURNS JSON LANGUAGE 'plpgsql' AS $$ +DECLARE + __result JSONB; BEGIN -- _trx_hash TEXT -> BYTEA, __include_reversible = TRUE, __is_legacy_style = FALSE - RETURN hafah_python.get_transaction_json(('\x' || _trx_hash)::BYTEA, TRUE, FALSE); + SELECT hafah_python.get_transaction_json(('\x' || _trx_hash)::BYTEA, TRUE, FALSE) INTO __result; + RETURN __result || jsonb_build_object('age', NOW() - (__result->>'expiration')::TIMESTAMP); END $$ ; diff --git a/api/types.sql b/api/types.sql index e187783..24cce5e 100644 --- a/api/types.sql +++ b/api/types.sql @@ -14,7 +14,8 @@ CREATE TYPE hafbe_types.operations AS ( trx_in_block SMALLINT, op_in_trx INT, virtual_op BOOLEAN, - timestamp TEXT, + timestamp TIMESTAMP, + age INTERVAL, operations JSON, operation_id BIGINT, acc_operation_id INT -- GitLab From 12b2093413e7cc160dc890bb503e7e0bd6afe51d Mon Sep 17 00:00:00 2001 From: kristupas Date: Sat, 7 Jan 2023 00:52:55 +0000 Subject: [PATCH 88/89] Used dgp from hive.blocks table for steem to hp #22 --- api/backend.sql | 16 +++++----------- db/hafbe_app.sql | 23 +---------------------- 2 files changed, 6 insertions(+), 33 deletions(-) diff --git a/api/backend.sql b/api/backend.sql index 30bbbb2..fedb067 100644 --- a/api/backend.sql +++ b/api/backend.sql @@ -752,17 +752,11 @@ LANGUAGE 'plpgsql' AS $$ BEGIN - RETURN QUERY SELECT ( - unnest(vests_value) - * - (SELECT value FROM hafbe_app.dynamic_global_properties_cache WHERE property = 'vesting_fund') - * - 10 ^ (SELECT precision FROM hafbe_app.dynamic_global_properties_cache WHERE property = 'vesting_fund') - ) / ( - (SELECT value FROM hafbe_app.dynamic_global_properties_cache WHERE property = 'vesting_shares') - * - 10 ^ (SELECT precision FROM hafbe_app.dynamic_global_properties_cache WHERE property = 'vesting_shares') - )::FLOAT; + RETURN QUERY SELECT + (unnest(vests_value) * total_vesting_fund_hive / total_vesting_shares)::FLOAT + FROM hive.blocks + ORDER BY num DESC + LIMIT 1; END $$ ; diff --git a/db/hafbe_app.sql b/db/hafbe_app.sql index f87787a..07a5b08 100644 --- a/db/hafbe_app.sql +++ b/db/hafbe_app.sql @@ -103,7 +103,7 @@ BEGIN ); INSERT INTO hafbe_app.witnesses_cache_config (update_interval, last_updated_at) - VALUES ('1 hour', to_timestamp(0)); + VALUES ('30 minutes', to_timestamp(0)); CREATE TABLE IF NOT EXISTS hafbe_app.witness_voters_stats_cache ( witness_id INT NOT NULL, @@ -142,14 +142,6 @@ BEGIN CONSTRAINT pk_witness_votes_change_cache PRIMARY KEY (witness_id) ); - - CREATE TABLE hafbe_app.dynamic_global_properties_cache ( - property TEXT NOT NULL, - value NUMERIC NOT NULL, - precision SMALLINT NOT NULL, - - CONSTRAINT pk_dynamic_global_properties_cache PRIMARY KEY (property) - ); END $$ ; @@ -771,19 +763,6 @@ BEGIN RAISE NOTICE 'Updated witness change cache'; - INSERT INTO hafbe_app.dynamic_global_properties_cache(property, value, precision) - SELECT - unnest(array['vesting_fund', 'vesting_shares']), - unnest(array[(props->'total_vesting_fund_hive'->>'amount'), (props->'total_vesting_shares'->>'amount')])::NUMERIC, - unnest(array[(props->'total_vesting_fund_hive'->>'precision'), (props->'total_vesting_shares'->>'precision')])::SMALLINT - FROM hafbe_app.get_dynamic_global_properties() props - ON CONFLICT ON CONSTRAINT pk_dynamic_global_properties_cache DO UPDATE SET - value = EXCLUDED.value, - precision = EXCLUDED.precision - ; - - RAISE NOTICE 'Updated global properties cache'; - UPDATE hafbe_app.witnesses_cache_config SET last_updated_at = NOW(); END $function$ -- GitLab From 0f403dd7add630c91d63b51f12836e9af75b1869 Mon Sep 17 00:00:00 2001 From: kristupas Date: Mon, 16 Jan 2023 14:35:47 +0000 Subject: [PATCH 89/89] Added 'validate_profile_picture_link()' #22 --- api/backend.sql | 39 ++++++++++-- api/endpoints.sql | 148 +++++++++++++++++++++++----------------------- db/hafbe_app.sql | 2 +- 3 files changed, 110 insertions(+), 79 deletions(-) diff --git a/api/backend.sql b/api/backend.sql index fedb067..891a2ac 100644 --- a/api/backend.sql +++ b/api/backend.sql @@ -768,7 +768,7 @@ account data CREATE FUNCTION hafbe_backend.get_account(_account TEXT) RETURNS JSON LANGUAGE 'plpython3u' -AS +AS $$ import subprocess import json @@ -793,20 +793,49 @@ LANGUAGE 'plpgsql' AS $$ DECLARE - __profile_image TEXT; + __profile_image_url TEXT; + __response_code INT; BEGIN BEGIN - SELECT INTO __profile_image ( ( + SELECT INTO __profile_image_url ( ( ((_account_data->>_key)::JSON)->>'profile' )::JSON )->>'profile_image'; EXCEPTION WHEN invalid_text_representation THEN - SELECT NULL INTO __profile_image; + SELECT NULL INTO __profile_image_url; END; - RETURN __profile_image; + + IF __profile_image_url IS NOT NULL AND LENGTH(__profile_image_url) != 0 THEN + SELECT hafbe_backend.validate_profile_picture_link(__profile_image_url) INTO __response_code; + END IF; + + IF __profile_image_url IS NOT NULL AND LENGTH(__profile_image_url) != 0 AND __response_code > 299 THEN + SELECT NULL INTO __profile_image_url; + END IF; + + RETURN __profile_image_url; END $$ ; +CREATE FUNCTION hafbe_backend.validate_profile_picture_link(__profile_image_url TEXT) +RETURNS INT +LANGUAGE 'plpython3u' +AS +$$ + import subprocess + + try: + res = int( + subprocess.check_output([ + f'curl -s -o /dev/null -I -w "%{{http_code}}" "{__profile_image_url}"' + ], shell=True).decode('utf-8') + ) + except: + res = 500 + return res +$$ +; + CREATE FUNCTION hafbe_backend.get_account_resource_credits(_account TEXT) RETURNS JSON LANGUAGE 'plpython3u' diff --git a/api/endpoints.sql b/api/endpoints.sql index 070673f..7540550 100644 --- a/api/endpoints.sql +++ b/api/endpoints.sql @@ -452,79 +452,81 @@ BEGIN FROM hafbe_app.hived_account_cache WHERE account = _account AND (NOW() - last_updated_at)::INTERVAL >= '1 hour'::INTERVAL; - IF __response_data IS NULL THEN - SELECT hafbe_backend.get_account(_account) INTO __response_data; - - SELECT hafbe_backend.parse_profile_picture(__response_data, 'json_metadata') INTO __profile_image; - IF __profile_image IS NULL THEN - SELECT hafbe_backend.parse_profile_picture(__response_data, 'posting_json_metadata') INTO __profile_image; - END IF; - - BEGIN - SELECT TRIM(BOTH '"' FROM __response_data->>'json_metadata')::JSON INTO __json_metadata; - EXCEPTION WHEN others THEN - SELECT NULL INTO __json_metadata; - END; - - BEGIN - SELECT TRIM(BOTH '"' FROM __response_data->>'posting_json_metadata')::JSON INTO __posting_json_metadata; - EXCEPTION WHEN others THEN - SELECT NULL INTO __posting_json_metadata; - END; - - SELECT json_build_object( - 'id', __response_data->>'id', - 'name', _account, - 'owner', __response_data->'owner', - 'active', __response_data->'active', - 'posting', __response_data->'posting', - 'memo_key', __response_data->>'memo_key', - 'profile_image', __profile_image, - 'json_metadata', __json_metadata, - 'posting_json_metadata', __posting_json_metadata, - 'last_owner_update', __response_data->>'last_owner_update', - 'last_account_update', __response_data->>'last_account_update', - 'created', __response_data->>'created', - 'mined', __response_data->>'mined', - 'recovery_account', __response_data->>'recovery_account', - 'comment_count', __response_data->>'comment_count', - 'post_count', __response_data->>'post_count', - 'can_vote', __response_data->>'can_vote', - 'voting_manabar', __response_data->'voting_manabar', - 'downvote_manabar', __response_data->'downvote_manabar', - 'voting_power', __response_data->>'voting_power', - 'balance', __response_data->>'balance', - 'savings_balance', __response_data->>'savings_balance', - 'hbd_balance', __response_data->>'hbd_balance', - 'savings_withdraw_requests', __response_data->>'savings_withdraw_requests', - 'reward_hbd_balance', __response_data->>'reward_hbd_balance', - 'reward_hive_balance', __response_data->>'reward_hive_balance', - 'reward_vesting_balance', __response_data->>'reward_vesting_balance', - 'reward_vesting_hive', __response_data->>'reward_vesting_hive', - 'vesting_shares', __response_data->>'vesting_shares', - 'delegated_vesting_shares', __response_data->>'delegated_vesting_shares', - 'received_vesting_shares', __response_data->>'received_vesting_shares', - 'vesting_withdraw_rate', __response_data->>'vesting_withdraw_rate', - 'post_voting_power', __response_data->>'post_voting_power', - 'posting_rewards', __response_data->>'posting_rewards', - 'proxied_vsf_votes', __response_data->'proxied_vsf_votes', - 'witnesses_voted_for', __response_data->>'witnesses_voted_for', - 'last_post', __response_data->>'last_post', - 'last_root_post', __response_data->>'last_root_post', - 'last_vote_time', __response_data->>'last_vote_time', - 'vesting_balance', __response_data->>'vesting_balance', - 'reputation', __response_data->>'reputation', - 'witness_votes', __response_data->'witness_votes' - ) INTO __response_data; - - INSERT INTO hafbe_app.hived_account_cache (account, data, last_updated_at) - SELECT _account, __response_data, NOW() - ON CONFLICT ON CONSTRAINT pk_hived_account_cache DO - UPDATE SET - data = EXCLUDED.data, - last_updated_at = EXCLUDED.last_updated_at - ; - END IF; + IF __response_data IS NOT NULL THEN + RETURN __response_data; + END IF; + + SELECT hafbe_backend.get_account(_account) INTO __response_data; + + SELECT hafbe_backend.parse_profile_picture(__response_data, 'json_metadata') INTO __profile_image; + IF __profile_image IS NULL THEN + SELECT hafbe_backend.parse_profile_picture(__response_data, 'posting_json_metadata') INTO __profile_image; + END IF; + + BEGIN + SELECT TRIM(BOTH '"' FROM __response_data->>'json_metadata')::JSON INTO __json_metadata; + EXCEPTION WHEN others THEN + SELECT NULL INTO __json_metadata; + END; + + BEGIN + SELECT TRIM(BOTH '"' FROM __response_data->>'posting_json_metadata')::JSON INTO __posting_json_metadata; + EXCEPTION WHEN others THEN + SELECT NULL INTO __posting_json_metadata; + END; + + SELECT json_build_object( + 'id', __response_data->>'id', + 'name', _account, + 'owner', __response_data->'owner', + 'active', __response_data->'active', + 'posting', __response_data->'posting', + 'memo_key', __response_data->>'memo_key', + 'profile_image', __profile_image, + 'json_metadata', __json_metadata, + 'posting_json_metadata', __posting_json_metadata, + 'last_owner_update', __response_data->>'last_owner_update', + 'last_account_update', __response_data->>'last_account_update', + 'created', __response_data->>'created', + 'mined', __response_data->>'mined', + 'recovery_account', __response_data->>'recovery_account', + 'comment_count', __response_data->>'comment_count', + 'post_count', __response_data->>'post_count', + 'can_vote', __response_data->>'can_vote', + 'voting_manabar', __response_data->'voting_manabar', + 'downvote_manabar', __response_data->'downvote_manabar', + 'voting_power', __response_data->>'voting_power', + 'balance', __response_data->>'balance', + 'savings_balance', __response_data->>'savings_balance', + 'hbd_balance', __response_data->>'hbd_balance', + 'savings_withdraw_requests', __response_data->>'savings_withdraw_requests', + 'reward_hbd_balance', __response_data->>'reward_hbd_balance', + 'reward_hive_balance', __response_data->>'reward_hive_balance', + 'reward_vesting_balance', __response_data->>'reward_vesting_balance', + 'reward_vesting_hive', __response_data->>'reward_vesting_hive', + 'vesting_shares', __response_data->>'vesting_shares', + 'delegated_vesting_shares', __response_data->>'delegated_vesting_shares', + 'received_vesting_shares', __response_data->>'received_vesting_shares', + 'vesting_withdraw_rate', __response_data->>'vesting_withdraw_rate', + 'post_voting_power', __response_data->>'post_voting_power', + 'posting_rewards', __response_data->>'posting_rewards', + 'proxied_vsf_votes', __response_data->'proxied_vsf_votes', + 'witnesses_voted_for', __response_data->>'witnesses_voted_for', + 'last_post', __response_data->>'last_post', + 'last_root_post', __response_data->>'last_root_post', + 'last_vote_time', __response_data->>'last_vote_time', + 'vesting_balance', __response_data->>'vesting_balance', + 'reputation', __response_data->>'reputation', + 'witness_votes', __response_data->'witness_votes' + ) INTO __response_data; + + INSERT INTO hafbe_app.hived_account_cache (account, data, last_updated_at) + SELECT _account, __response_data, NOW() + ON CONFLICT ON CONSTRAINT pk_hived_account_cache DO + UPDATE SET + data = EXCLUDED.data, + last_updated_at = EXCLUDED.last_updated_at + ; RETURN __response_data; END diff --git a/db/hafbe_app.sql b/db/hafbe_app.sql index 07a5b08..2c770da 100644 --- a/db/hafbe_app.sql +++ b/db/hafbe_app.sql @@ -820,7 +820,7 @@ BEGIN END IF; RAISE NOTICE 'Attempting to process block range: <%,%>', __next_block_range.first_block, __next_block_range.last_block; - + IF __next_block_range.first_block != __next_block_range.last_block THEN CALL hafbe_app.do_massive_processing(_appContext, __next_block_range.first_block, __next_block_range.last_block, 100, __last_block); ELSE -- GitLab