From 96d3fd500e50bfda321569539d66260e66f93750 Mon Sep 17 00:00:00 2001 From: Michal Zander <mzander@syncad.com> Date: Thu, 27 Feb 2025 15:16:23 +0000 Subject: [PATCH] Add min and max balances for aggregated history --- backend/aggregated_history.sql | 83 +++++++++++++++---- db/btracker_app.sql | 6 ++ db/process_balances.sql | 77 +++++++++++++---- .../get_history_aggregation.sql | 7 +- endpoints/endpoint_schema.sql | 3 +- 5 files changed, 140 insertions(+), 36 deletions(-) diff --git a/backend/aggregated_history.sql b/backend/aggregated_history.sql index b1cbffb..c2c046f 100644 --- a/backend/aggregated_history.sql +++ b/backend/aggregated_history.sql @@ -3,7 +3,9 @@ SET ROLE btracker_owner; DROP TYPE IF EXISTS balance_history_aggregation CASCADE; CREATE TYPE balance_history_aggregation AS ( date TIMESTAMP, - balance BIGINT + balance BIGINT, + min_balance BIGINT, + max_balance BIGINT ); CREATE OR REPLACE VIEW balance_history_by_year AS @@ -12,6 +14,8 @@ WITH get_year AS ( account, nai, balance, + min_balance, + max_balance, source_op_block, date_trunc('year', updated_at) AS by_year, updated_at @@ -26,14 +30,27 @@ get_latest_updates AS ( by_year, ROW_NUMBER() OVER (PARTITION BY account, nai, by_year ORDER BY updated_at DESC) AS rn_by_year FROM get_year bh -) +), +get_min_max_balances_by_year AS ( SELECT account, nai, - balance, - source_op_block, - by_year AS updated_at - FROM get_latest_updates + by_year, + MAX(max_balance) AS max_balance, + MIN(min_balance) AS min_balance + FROM get_year + GROUP BY account, nai, by_year +) + SELECT + gl.account, + gl.nai, + gl.balance, + gm.min_balance, + gm.max_balance, + gl.source_op_block, + gl.by_year AS updated_at + FROM get_latest_updates gl + JOIN get_min_max_balances_by_year gm ON gl.account = gm.account AND gl.nai = gm.nai AND gl.by_year = gm.by_year WHERE rn_by_year = 1; CREATE OR REPLACE FUNCTION get_balance_history_aggregation( @@ -62,7 +79,9 @@ BEGIN RETURN QUERY ( SELECT fb.date, - fb.balance + fb.balance, + fb.min_balance, + fb.max_balance FROM get_balance_history_by_day( _account_id, _coin_type, @@ -75,7 +94,9 @@ BEGIN RETURN QUERY ( SELECT fb.date, - fb.balance + fb.balance, + fb.min_balance, + fb.max_balance FROM get_balance_history_by_month( _account_id, _coin_type, @@ -88,7 +109,9 @@ BEGIN RETURN QUERY ( SELECT fb.date, - fb.balance + fb.balance, + fb.min_balance, + fb.max_balance FROM get_balance_history_by_year( _account_id, _coin_type, @@ -135,6 +158,8 @@ RETURN QUERY ( ds.date, ds.row_num, bh.balance, + bh.min_balance, + bh.max_balance, bh.source_op_block FROM add_row_num_to_series ds LEFT JOIN balance_history_by_day bh ON @@ -148,11 +173,15 @@ RETURN QUERY ( ds.date, ds.row_num, COALESCE(ds.balance, prev_balance.balance, 0) AS balance, + COALESCE(ds.min_balance, prev_balance.min_balance, 0) AS min_balance, + COALESCE(ds.max_balance, prev_balance.max_balance, 0) AS max_balance, COALESCE(ds.source_op_block, prev_balance.source_op_block, NULL) AS source_op_block FROM balance_records ds LEFT JOIN LATERAL ( SELECT - bh.balance, + bh.balance, + bh.min_balance, + bh.max_balance, bh.source_op_block FROM balance_history_by_day bh WHERE @@ -170,6 +199,8 @@ RETURN QUERY ( next_b.date, next_b.row_num, COALESCE(next_b.balance, prev_b.balance, 0) AS balance, + COALESCE(next_b.min_balance, prev_b.min_balance, 0) AS min_balance, + COALESCE(next_b.max_balance, prev_b.max_balance, 0) AS max_balance, COALESCE(next_b.source_op_block, prev_b.source_op_block, NULL) AS source_op_block FROM agg_history prev_b JOIN balance_records next_b ON next_b.row_num = prev_b.row_num + 1 @@ -178,7 +209,9 @@ RETURN QUERY ( ) SELECT LEAST(fb.date + INTERVAL '1 day' - INTERVAL '1 second', CURRENT_TIMESTAMP)::TIMESTAMP AS adjusted_date, - fb.balance + fb.balance, + fb.min_balance, + fb.max_balance FROM filled_balances fb ORDER BY (CASE WHEN _direction = 'desc' THEN fb.date ELSE NULL END) DESC, @@ -218,6 +251,8 @@ RETURN QUERY ( ds.date, ds.row_num, bh.balance, + bh.min_balance, + bh.max_balance, bh.source_op_block FROM add_row_num_to_series ds LEFT JOIN balance_history_by_month bh ON @@ -231,11 +266,15 @@ RETURN QUERY ( ds.date, ds.row_num, COALESCE(ds.balance, prev_balance.balance, 0) AS balance, + COALESCE(ds.min_balance, prev_balance.min_balance, 0) AS min_balance, + COALESCE(ds.max_balance, prev_balance.max_balance, 0) AS max_balance, COALESCE(ds.source_op_block, prev_balance.source_op_block, NULL) AS source_op_block FROM balance_records ds LEFT JOIN LATERAL ( SELECT - bh.balance, + bh.balance, + bh.min_balance, + bh.max_balance, bh.source_op_block FROM balance_history_by_month bh WHERE @@ -253,6 +292,8 @@ RETURN QUERY ( next_b.date, next_b.row_num, COALESCE(next_b.balance, prev_b.balance, 0) AS balance, + COALESCE(next_b.min_balance, prev_b.min_balance, 0) AS min_balance, + COALESCE(next_b.max_balance, prev_b.max_balance, 0) AS max_balance, COALESCE(next_b.source_op_block, prev_b.source_op_block, NULL) AS source_op_block FROM agg_history prev_b JOIN balance_records next_b ON next_b.row_num = prev_b.row_num + 1 @@ -261,7 +302,9 @@ RETURN QUERY ( ) SELECT LEAST(fb.date + INTERVAL '1 month' - INTERVAL '1 second', CURRENT_TIMESTAMP)::TIMESTAMP AS adjusted_date, - fb.balance + fb.balance, + fb.min_balance, + fb.max_balance FROM filled_balances fb ORDER BY (CASE WHEN _direction = 'desc' THEN fb.date ELSE NULL END) DESC, @@ -301,6 +344,8 @@ RETURN QUERY ( ds.date, ds.row_num, bh.balance, + bh.min_balance, + bh.max_balance, bh.source_op_block FROM add_row_num_to_series ds LEFT JOIN balance_history_by_year bh ON @@ -314,11 +359,15 @@ RETURN QUERY ( ds.date, ds.row_num, COALESCE(ds.balance, prev_balance.balance, 0) AS balance, + COALESCE(ds.min_balance, prev_balance.min_balance, 0) AS min_balance, + COALESCE(ds.max_balance, prev_balance.max_balance, 0) AS max_balance, COALESCE(ds.source_op_block, prev_balance.source_op_block, NULL) AS source_op_block FROM balance_records ds LEFT JOIN LATERAL ( SELECT - bh.balance, + bh.balance, + bh.min_balance, + bh.max_balance, bh.source_op_block FROM balance_history_by_year bh WHERE @@ -336,6 +385,8 @@ RETURN QUERY ( next_b.date, next_b.row_num, COALESCE(next_b.balance, prev_b.balance, 0) AS balance, + COALESCE(next_b.min_balance, prev_b.min_balance, 0) AS min_balance, + COALESCE(next_b.max_balance, prev_b.max_balance, 0) AS max_balance, COALESCE(next_b.source_op_block, prev_b.source_op_block, NULL) AS source_op_block FROM agg_history prev_b JOIN balance_records next_b ON next_b.row_num = prev_b.row_num + 1 @@ -344,7 +395,9 @@ RETURN QUERY ( ) SELECT LEAST(fb.date + INTERVAL '1 year' - INTERVAL '1 second', CURRENT_TIMESTAMP)::TIMESTAMP AS adjusted_date, - fb.balance + fb.balance, + fb.min_balance, + fb.max_balance FROM filled_balances fb ORDER BY (CASE WHEN _direction = 'desc' THEN fb.date ELSE NULL END) DESC, diff --git a/db/btracker_app.sql b/db/btracker_app.sql index 6e4bdbd..9827f71 100644 --- a/db/btracker_app.sql +++ b/db/btracker_app.sql @@ -79,6 +79,9 @@ CREATE TABLE IF NOT EXISTS balance_history_by_month account INT NOT NULL, nai INT NOT NULL, balance BIGINT NOT NULL, + min_balance BIGINT NOT NULL, + max_balance BIGINT NOT NULL, + source_op BIGINT NOT NULL, source_op_block INT NOT NULL, updated_at TIMESTAMP NOT NULL, @@ -92,6 +95,9 @@ CREATE TABLE IF NOT EXISTS balance_history_by_day account INT NOT NULL, nai INT NOT NULL, balance BIGINT NOT NULL, + min_balance BIGINT NOT NULL, + max_balance BIGINT NOT NULL, + source_op BIGINT NOT NULL, source_op_block INT NOT NULL, updated_at TIMESTAMP NOT NULL, diff --git a/db/process_balances.sql b/db/process_balances.sql index 6542076..c7818d2 100644 --- a/db/process_balances.sql +++ b/db/process_balances.sql @@ -151,7 +151,7 @@ insert_account_balance_history AS ( FROM remove_latest_stored_balance_record pbh RETURNING (xmax = 0) as is_new_entry, acc_history.account ), -join_created_at_to_balance_history AS ( +join_created_at_to_balance_history AS MATERIALIZED ( SELECT rls.account_id, rls.nai, @@ -167,6 +167,7 @@ get_latest_updates AS MATERIALIZED ( SELECT account_id, nai, + source_op, source_op_block, balance, by_day, @@ -175,38 +176,78 @@ get_latest_updates AS MATERIALIZED ( ROW_NUMBER() OVER (PARTITION BY account_id, nai, by_month ORDER BY source_op DESC) AS rn_by_month FROM join_created_at_to_balance_history ), -insert_account_balance_history_by_day AS ( - INSERT INTO balance_history_by_day AS acc_history - (account, nai, source_op_block, updated_at, balance) +get_min_max_balances_by_day AS ( SELECT account_id, nai, - source_op_block, by_day, - balance - FROM get_latest_updates - WHERE rn_by_day = 1 + MAX(balance) AS max_balance, + MIN(balance) AS min_balance + FROM join_created_at_to_balance_history + GROUP BY account_id, nai, by_day +), +get_min_max_balances_by_month AS ( + SELECT + account_id, + nai, + by_month, + MAX(balance) AS max_balance, + MIN(balance) AS min_balance + FROM join_created_at_to_balance_history + GROUP BY account_id, nai, by_month +), +insert_account_balance_history_by_day AS ( + INSERT INTO balance_history_by_day AS acc_history + (account, nai, source_op, source_op_block, updated_at, balance, min_balance, max_balance) + SELECT + gl.account_id, + gl.nai, + gl.source_op, + gl.source_op_block, + gl.by_day, + gl.balance, + gm.min_balance, + gm.max_balance + FROM get_latest_updates gl + JOIN get_min_max_balances_by_day gm ON + gm.account_id = gl.account_id AND + gm.nai = gl.nai AND + gm.by_day = gl.by_day + WHERE gl.rn_by_day = 1 ON CONFLICT ON CONSTRAINT pk_balance_history_by_day DO UPDATE SET + source_op = EXCLUDED.source_op, source_op_block = EXCLUDED.source_op_block, - balance = EXCLUDED.balance + balance = EXCLUDED.balance, + min_balance = LEAST(EXCLUDED.min_balance, acc_history.min_balance), + max_balance = GREATEST(EXCLUDED.max_balance, acc_history.max_balance) RETURNING (xmax = 0) as is_new_entry, acc_history.account ), insert_account_balance_history_by_month AS ( INSERT INTO balance_history_by_month AS acc_history - (account, nai, source_op_block, updated_at, balance) + (account, nai, source_op, source_op_block, updated_at, balance, min_balance, max_balance) SELECT - account_id, - nai, - source_op_block, - by_month, - balance - FROM get_latest_updates + gl.account_id, + gl.nai, + gl.source_op, + gl.source_op_block, + gl.by_month, + gl.balance, + gm.min_balance, + gm.max_balance + FROM get_latest_updates gl + JOIN get_min_max_balances_by_month gm ON + gm.account_id = gl.account_id AND + gm.nai = gl.nai AND + gm.by_month = gl.by_month WHERE rn_by_month = 1 ON CONFLICT ON CONSTRAINT pk_balance_history_by_month DO - UPDATE SET + UPDATE SET + source_op = EXCLUDED.source_op, source_op_block = EXCLUDED.source_op_block, - balance = EXCLUDED.balance + balance = EXCLUDED.balance, + min_balance = LEAST(EXCLUDED.min_balance, acc_history.min_balance), + max_balance = GREATEST(EXCLUDED.max_balance, acc_history.max_balance) RETURNING (xmax = 0) as is_new_entry, acc_history.account ) diff --git a/endpoints/account-balances/get_history_aggregation.sql b/endpoints/account-balances/get_history_aggregation.sql index c2331ed..38fe8c5 100644 --- a/endpoints/account-balances/get_history_aggregation.sql +++ b/endpoints/account-balances/get_history_aggregation.sql @@ -108,7 +108,8 @@ SET ROLE btracker_owner; - { "date":"2016-12-31T23:59:59", "balance":"8172549681941451", - "block":4999992 + "min_balance":"1000000000000", + "max_balance":"8436182707535769" } '404': @@ -146,7 +147,9 @@ BEGIN SELECT to_json(array_agg(row)) FROM ( SELECT fb.date, - fb.balance::TEXT + fb.balance::TEXT, + fb.min_balance::TEXT, + fb.max_balance::TEXT FROM get_balance_history_aggregation( _account_id, _coin_type, diff --git a/endpoints/endpoint_schema.sql b/endpoints/endpoint_schema.sql index a906559..f31fcae 100644 --- a/endpoints/endpoint_schema.sql +++ b/endpoints/endpoint_schema.sql @@ -453,7 +453,8 @@ declare { "date": "2016-12-31T23:59:59", "balance": "8172549681941451", - "block": 4999992 + "min_balance": "1000000000000", + "max_balance": "8436182707535769" } ] } -- GitLab