Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Support efficient query for related account with method filter #897

Open
wants to merge 2 commits into
base: main
Choose a base branch
from
Open
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
6 changes: 6 additions & 0 deletions .changelog/809.feature.md
Original file line number Diff line number Diff line change
@@ -0,0 +1,6 @@
Support efficient query for related account with method filter

- Promote 'likely_native_transfer' to a first-class database field.

- Denormalize 'method' and 'likely_native_transfer' to create
efficient indexes for account filtering
11 changes: 11 additions & 0 deletions analyzer/consensus/consensus.go
Original file line number Diff line number Diff line change
Expand Up @@ -596,6 +596,16 @@ func (m *processor) queueTransactionInserts(batch *storage.QueryBatch, data *con
// Enqueue DB statements to store events that were generated as the result of a TX execution.
func (m *processor) queueTxEventInserts(batch *storage.QueryBatch, data *allData) error {
for i, txr := range data.BlockData.TransactionsWithResults {
tx, err := OpenSignedTxNoVerify(&txr.Transaction)
if err != nil {
m.logger.Info("couldn't parse transaction",
"err", err,
"height", data.BlockData.Height,
"tx_index", i,
)
continue
}

txAccounts := []staking.Address{
// Always insert sender as a related address, some transactions (e.g. failed ones) might not have
// any events associated.
Expand Down Expand Up @@ -664,6 +674,7 @@ func (m *processor) queueTxEventInserts(batch *storage.QueryBatch, data *allData
for _, addr := range uniqueTxAccounts {
batch.Queue(queries.ConsensusAccountRelatedTransactionInsert,
addr,
tx.Method,
data.BlockData.Height,
i,
)
Expand Down
12 changes: 6 additions & 6 deletions analyzer/queries/queries.go
Original file line number Diff line number Diff line change
Expand Up @@ -304,8 +304,8 @@ var (
result = excluded.result`

ConsensusAccountRelatedTransactionInsert = `
INSERT INTO chain.accounts_related_transactions (account_address, tx_block, tx_index)
VALUES ($1, $2, $3)`
INSERT INTO chain.accounts_related_transactions (account_address, method, tx_block, tx_index)
VALUES ($1, $2, $3, $4)`

ConsensusAccountRelatedEventInsert = `
INSERT INTO chain.accounts_related_events (account_address, event_block, tx_index, tx_hash, type, body)
Expand Down Expand Up @@ -563,8 +563,8 @@ var (
VALUES ($1, $2, $3, $4, $5, $6)`

RuntimeRelatedTransactionInsert = `
INSERT INTO chain.runtime_related_transactions (runtime, account_address, tx_round, tx_index)
VALUES ($1, $2, $3, $4)`
INSERT INTO chain.runtime_related_transactions (runtime, account_address, tx_round, tx_index, method, likely_native_transfer)
VALUES ($1, $2, $3, $4, $5, $6)`

RuntimeAccountNumTxsUpsert = `
INSERT INTO chain.runtime_accounts as accounts (runtime, address, num_txs)
Expand Down Expand Up @@ -624,8 +624,8 @@ var (
SET total_received = EXCLUDED.total_received`

RuntimeTransactionInsert = `
INSERT INTO chain.runtime_transactions (runtime, round, tx_index, tx_hash, tx_eth_hash, fee, fee_symbol, fee_proxy_module, fee_proxy_id, gas_limit, gas_used, size, timestamp, oasis_encrypted_format, oasis_encrypted_public_key, oasis_encrypted_data_nonce, oasis_encrypted_data_data, oasis_encrypted_result_nonce, oasis_encrypted_result_data, method, body, "to", amount, amount_symbol, evm_encrypted_format, evm_encrypted_public_key, evm_encrypted_data_nonce, evm_encrypted_data_data, evm_encrypted_result_nonce, evm_encrypted_result_data, success, error_module, error_code, error_message_raw, error_message)
VALUES ($1, $2, $3, $4, $5, $6, $7, $8, $9, $10, $11, $12, $13, $14, $15, $16, $17, $18, $19, $20, $21, $22, $23, $24, $25, $26, $27, $28, $29, $30, $31, $32, $33, $34, $35)`
INSERT INTO chain.runtime_transactions (runtime, round, tx_index, tx_hash, tx_eth_hash, fee, fee_symbol, fee_proxy_module, fee_proxy_id, gas_limit, gas_used, size, timestamp, oasis_encrypted_format, oasis_encrypted_public_key, oasis_encrypted_data_nonce, oasis_encrypted_data_data, oasis_encrypted_result_nonce, oasis_encrypted_result_data, method, body, "to", amount, amount_symbol, evm_encrypted_format, evm_encrypted_public_key, evm_encrypted_data_nonce, evm_encrypted_data_data, evm_encrypted_result_nonce, evm_encrypted_result_data, success, error_module, error_code, error_message_raw, error_message, likely_native_transfer)
VALUES ($1, $2, $3, $4, $5, $6, $7, $8, $9, $10, $11, $12, $13, $14, $15, $16, $17, $18, $19, $20, $21, $22, $23, $24, $25, $26, $27, $28, $29, $30, $31, $32, $33, $34, $35, $36)`

// We use COALESCE here to avoid overwriting existing data with null values.
RuntimeTransactionEvmParsedFieldsUpdate = `
Expand Down
3 changes: 3 additions & 0 deletions analyzer/runtime/extract.go
Original file line number Diff line number Diff line change
Expand Up @@ -76,6 +76,7 @@ type BlockTransactionData struct {
EVMContract *evm.EVMContractData
Success *bool
Error *TxError
IsLikelyTokenTransfer bool
}

type TxError struct {
Expand Down Expand Up @@ -317,6 +318,7 @@ func ExtractRound(blockHeader nodeapi.RuntimeBlockHeader, txrs []nodeapi.Runtime
var amount quantity.Quantity
if err = VisitCall(&tx.Call, &txr.Result, &CallHandler{
AccountsTransfer: func(body *accounts.Transfer) error {
blockTransactionData.IsLikelyTokenTransfer = true
blockTransactionData.Body = body
amount = body.Amount.Amount
blockTransactionData.AmountSymbol = common.Ptr(stringifyDenomination(sdkPT, body.Amount.Denomination))
Expand Down Expand Up @@ -469,6 +471,7 @@ func ExtractRound(blockHeader nodeapi.RuntimeBlockHeader, txrs []nodeapi.Runtime
return nil
},
EVMCall: func(body *sdkEVM.Call, ok *[]byte) error {
blockTransactionData.IsLikelyTokenTransfer = len(body.Data) == 0 // Calls with empty body are likely native token transfers.
blockTransactionData.Body = body
amount = uncategorized.QuantityFromBytes(body.Value)
if to, err = addresses.RegisterEthAddress(blockData.AddressPreimages, body.Address); err != nil {
Expand Down
3 changes: 2 additions & 1 deletion analyzer/runtime/runtime.go
Original file line number Diff line number Diff line change
Expand Up @@ -325,6 +325,7 @@ func (m *processor) queueTransactionInsert(batch *storage.QueryBatch, round uint
errorCode,
errorMessageRaw,
errorMessage,
transactionData.IsLikelyTokenTransfer,
)
}

Expand Down Expand Up @@ -362,7 +363,7 @@ func (m *processor) queueDbUpdates(batch *storage.QueryBatch, data *BlockData) {
)
}
for addr := range transactionData.RelatedAccountAddresses {
batch.Queue(queries.RuntimeRelatedTransactionInsert, m.runtime, addr, data.Header.Round, transactionData.Index)
batch.Queue(queries.RuntimeRelatedTransactionInsert, m.runtime, addr, data.Header.Round, transactionData.Index, transactionData.Method, transactionData.IsLikelyTokenTransfer)
if m.mode != analyzer.FastSyncMode {
// We do not dead-reckon the number of transactions for accounts in fast sync mode because there are some
// "heavy hitter" accounts (system, etc) that are involved in a large fraction of transactions, resulting in
Expand Down
2 changes: 1 addition & 1 deletion api/spec/v1.yaml
Original file line number Diff line number Diff line change
Expand Up @@ -2897,7 +2897,7 @@ components:
RuntimeTransaction:
type: object
# NOTE: Not guaranteed to be present: eth_hash, to, amount.
required: [round, index, timestamp, hash, signers, sender_0, nonce_0, fee, fee_symbol, charged_fee, gas_limit, gas_used, size]
required: [round, index, timestamp, hash, signers, sender_0, nonce_0, fee, fee_symbol, charged_fee, gas_limit, gas_used, size, is_likely_native_token_transfer]
properties:
round:
type: integer
Expand Down
14 changes: 1 addition & 13 deletions storage/client/client.go
Original file line number Diff line number Diff line change
Expand Up @@ -1616,6 +1616,7 @@ func (c *StorageClient) RuntimeTransactions(ctx context.Context, p apiTypes.GetR
&oasisEncryptionEnvelope.ResultNonce,
&oasisEncryptionEnvelope.Result,
&t.Method,
&t.IsLikelyNativeTokenTransfer,
&t.Body,
&t.To,
&toPreimageContextIdentifier,
Expand Down Expand Up @@ -1680,19 +1681,6 @@ func (c *StorageClient) RuntimeTransactions(ctx context.Context, p apiTypes.GetR
t.ToEth = EthChecksumAddrFromPreimage(*toPreimageContextIdentifier, *toPreimageContextVersion, toPreimageData)
}

// Heuristically decide if this is a native runtime token transfer.
// TODO: Similarly to above, this application logic doesn't belong here (= the DB layer);
// move it out if we establish a separate app/logic layer.
if t.Method != nil {
if *t.Method == "accounts.Transfer" && t.AmountSymbol != nil && *t.AmountSymbol == c.nativeTokenSymbol(runtimeFromCtx(ctx)) {
t.IsLikelyNativeTokenTransfer = common.Ptr(true)
} else if *t.Method == "evm.Call" && t.Body != nil && (*t.Body)["data"] == "" {
// Note: This demands that the body.data key does exist (as we expect from evm.Call tx bodies),
// but has an empty value.
t.IsLikelyNativeTokenTransfer = common.Ptr(true)
}
}

// Try extracting parsed PCS quote from rofl.Register transaction body.
if t.Method != nil && *t.Method == "rofl.Register" {
nb, err := extractPCSQuote(t.Body)
Expand Down
67 changes: 37 additions & 30 deletions storage/client/queries/queries.go
Original file line number Diff line number Diff line change
Expand Up @@ -81,34 +81,38 @@ const (

Transactions = `
SELECT
chain.transactions.block as block,
chain.transactions.tx_index as tx_index,
chain.transactions.tx_hash as tx_hash,
chain.transactions.sender as sender,
chain.transactions.nonce as nonce,
chain.transactions.fee_amount as fee_amount,
chain.transactions.max_gas as gas_limit,
chain.transactions.method as method,
chain.transactions.body as body,
chain.transactions.code as code,
chain.transactions.module as module,
chain.transactions.message as message,
chain.blocks.time as time
FROM chain.transactions
JOIN chain.blocks ON chain.transactions.block = chain.blocks.height
LEFT JOIN chain.accounts_related_transactions ON chain.transactions.block = chain.accounts_related_transactions.tx_block
AND chain.transactions.tx_index = chain.accounts_related_transactions.tx_index
t.block as block,
t.tx_index as tx_index,
t.tx_hash as tx_hash,
t.sender as sender,
t.nonce as nonce,
t.fee_amount as fee_amount,
t.max_gas as gas_limit,
t.method as method,
t.body as body,
t.code as code,
t.module as module,
t.message as message,
b.time as time
FROM chain.transactions AS t
JOIN chain.blocks AS b ON
t.block = b.height
LEFT JOIN chain.accounts_related_transactions AS art ON
(t.block = art.tx_block) AND
(t.tx_index = art.tx_index) AND
($3::text IS NULL OR t.method = art.method) AND
-- When related_address ($5) is NULL and hence we do no filtering on it, avoid the join altogether.
-- Otherwise, every tx will be returned as many times as there are related addresses for it.
AND $5::text IS NOT NULL
WHERE ($1::text IS NULL OR chain.transactions.tx_hash = $1::text) AND
($2::bigint IS NULL OR chain.transactions.block = $2::bigint) AND
($3::text IS NULL OR chain.transactions.method = $3::text) AND
($4::text IS NULL OR chain.transactions.sender = $4::text) AND
($5::text IS NULL OR chain.accounts_related_transactions.account_address = $5::text) AND
($6::timestamptz IS NULL OR chain.blocks.time >= $6::timestamptz) AND
($7::timestamptz IS NULL OR chain.blocks.time < $7::timestamptz)
ORDER BY chain.transactions.block DESC, chain.transactions.tx_index
($5::text IS NOT NULL)
WHERE
($1::text IS NULL OR t.tx_hash = $1::text) AND
($2::bigint IS NULL OR t.block = $2::bigint) AND
($3::text IS NULL OR t.method = $3::text) AND
($4::text IS NULL OR t.sender = $4::text) AND
($5::text IS NULL OR art.account_address = $5::text) AND
($6::timestamptz IS NULL OR b.time >= $6::timestamptz) AND
($7::timestamptz IS NULL OR b.time < $7::timestamptz)
ORDER BY t.block DESC, t.tx_index
LIMIT $8::bigint
OFFSET $9::bigint`

Expand Down Expand Up @@ -518,6 +522,7 @@ const (
txs.oasis_encrypted_result_nonce,
txs.oasis_encrypted_result_data,
txs.method,
txs.likely_native_transfer,
txs.body,
txs.to,
to_preimage.context_identifier AS to_preimage_context_identifier,
Expand All @@ -539,7 +544,7 @@ const (
txs.error_message,
txs.error_params
FROM chain.runtime_transactions AS txs
LEFT JOIN chain.runtime_transaction_signers AS signers ON
JOIN chain.runtime_transaction_signers AS signers ON
(signers.runtime = txs.runtime) AND
(signers.round = txs.round) AND
(signers.tx_index = txs.tx_index)
Expand All @@ -558,9 +563,10 @@ const (
(to_preimage.context_identifier = 'oasis-runtime-sdk/address: secp256k1eth') AND
(to_preimage.context_version = 0)
LEFT JOIN chain.runtime_related_transactions AS rel ON
(txs.runtime = rel.runtime) AND
(txs.round = rel.tx_round) AND
(txs.tx_index = rel.tx_index) AND
(txs.runtime = rel.runtime) AND
($5::text IS NULL OR txs.method = rel.method AND txs.likely_native_transfer = rel.likely_native_transfer) AND
-- When related_address ($4) is NULL and hence we do no filtering on it, avoid the join altogether.
-- Otherwise, every tx will be returned as many times as there are related addresses for it.
($4::text IS NOT NULL)
Expand All @@ -576,10 +582,10 @@ const (
TRUE
-- Special case to return are 'likely to be native transfers'.
WHEN $5::text = 'native_transfers' THEN
(txs.method = 'accounts.Transfer' OR (txs.method = 'evm.Call' AND (txs.body ->> 'data') = ''))
txs.likely_native_transfer
-- Special case to return all evm.Calls that are likely not native transfers.
WHEN $5::text = 'evm.Call_no_native' THEN
(txs.method = 'evm.Call' AND (txs.body ->> 'data') != '')
(txs.method = 'evm.Call' AND NOT txs.likely_native_transfer)
-- Regular case.
ELSE
(txs.method = $5::text)
Expand Down Expand Up @@ -607,6 +613,7 @@ const (
txs.oasis_encrypted_result_nonce,
txs.oasis_encrypted_result_data,
txs.method,
txs.likely_native_transfer,
txs.body,
txs.to,
to_preimage.context_identifier,
Expand Down
5 changes: 5 additions & 0 deletions storage/migrations/00_consensus.up.sql
Original file line number Diff line number Diff line change
Expand Up @@ -368,12 +368,17 @@ CREATE TABLE chain.accounts_related_transactions
account_address oasis_addr NOT NULL,
tx_block UINT63 NOT NULL,
tx_index UINT31 NOT NULL,

-- method TEXT NOT NULL, -- Added in 15_related_transactions_method_denorm.up.sql.

FOREIGN KEY (tx_block, tx_index) REFERENCES chain.transactions(block, tx_index) DEFERRABLE INITIALLY DEFERRED
);
CREATE INDEX ix_accounts_related_transactions_block ON chain.accounts_related_transactions (tx_block);
CREATE INDEX ix_accounts_related_transactions_address_block ON chain.accounts_related_transactions(account_address, tx_block); -- Removed in 12_related_transactions_method_idx.up.sql.
-- Added in 12_related_transactions_method_idx.up.sql.
-- CREATE INDEX ix_accounts_related_transactions_address_block_desc_tx_index ON chain.accounts_related_transactions (account_address, tx_block DESC, tx_index);
-- Added in 15_related_transactions_method_denorm.up.sql.
-- CREATE INDEX ix_accounts_related_transactions_address_method_block_tx_index ON chain.accounts_related_transactions (account_address, method, tx_block DESC, tx_index);

-- Tracks the current (consensus) height of the node.
CREATE TABLE chain.latest_node_heights
Expand Down
21 changes: 15 additions & 6 deletions storage/migrations/01_runtimes.up.sql
Original file line number Diff line number Diff line change
Expand Up @@ -95,6 +95,8 @@ CREATE TABLE chain.runtime_transactions
-- Internal tracking for parsing evm.Call transactions using the contract
-- abi when available.
abi_parsed_at TIMESTAMP WITH TIME ZONE

-- likely_native_transfer BOOLEAN NOT NULL DEFAULT FALSE -- Added in 18_related_runtime_transactions_method_denorm.up.sql.
);
CREATE INDEX ix_runtime_transactions_tx_hash ON chain.runtime_transactions USING hash (tx_hash);
CREATE INDEX ix_runtime_transactions_tx_eth_hash ON chain.runtime_transactions USING hash (tx_eth_hash);
Expand All @@ -103,12 +105,9 @@ CREATE INDEX ix_runtime_transactions_to ON chain.runtime_transactions(runtime, "
CREATE INDEX ix_runtime_transactions_to_abi_parsed_at ON chain.runtime_transactions (runtime, "to", abi_parsed_at);
-- CREATE INDEX ix_runtime_transactions_method_round ON chain.runtime_transactions (runtime, method, round, tx_index); -- Added in 08_runtime_transactions_method_idx.up.sql

-- Added in 12_related_transactions_method_idx.up.sql.
-- Indexes for efficient query of 'likely native transfers':
-- EVM Calls, where the body is an empty data field (likely native transfers)
-- CREATE INDEX ix_runtime_transactions_evm_call_empty_data ON chain.runtime_transactions (runtime, round, tx_index) WHERE method = 'evm.Call' AND (body ->> 'data') = '';
-- EVM Calls, where the body is non-empty data field (likely not native transfers).
-- CREATE INDEX ix_runtime_transactions_evm_call_non_empty_data ON chain.runtime_transactions (runtime, round, tx_index) WHERE method = 'evm.Call' AND (body ->> 'data') != '';
-- Added in 18_related_runtime_transactions_method_denorm.up.sql.
-- CREATE INDEX ix_runtime_transactions_native_transfer_round ON chain.runtime_transactions (runtime, likely_native_transfer, round, tx_index);
-- CREATE INDEX ix_runtime_transactions_method_native_transfer_round ON chain.runtime_transactions (runtime, method, likely_native_transfer, round, tx_index);

CREATE TABLE chain.runtime_transaction_signers
(
Expand All @@ -133,11 +132,21 @@ CREATE TABLE chain.runtime_related_transactions
account_address oasis_addr NOT NULL,
tx_round UINT63 NOT NULL,
tx_index UINT31 NOT NULL,

-- method TEXT, -- Added in 18_related_runtime_transactions_method_denorm.up.sql.
-- likely_native_transfer BOOLEAN NOT NULL DEFAULT FALSE -- Added in 18_related_runtime_transactions_method_denorm.up.sql.

FOREIGN KEY (runtime, tx_round, tx_index) REFERENCES chain.runtime_transactions(runtime, round, tx_index) DEFERRABLE INITIALLY DEFERRED
);
CREATE INDEX ix_runtime_related_transactions_round_index ON chain.runtime_related_transactions (runtime, tx_round, tx_index);
CREATE INDEX ix_runtime_related_transactions_address_round_index ON chain.runtime_related_transactions (runtime, account_address, tx_round, tx_index);

-- Added in 18_related_runtime_transactions_method_denorm.up.sql.
-- CREATE INDEX ix_runtime_related_transactions_address_method_round ON chain.runtime_related_transactions (runtime, account_address, method, tx_round, tx_index);
-- CREATE INDEX ix_runtime_related_transactions_address_native_transfer_round ON chain.runtime_related_transactions (runtime, account_address, likely_native_transfer, tx_round, tx_index);
-- -- This combination is needed, since explorer needs to obtain evm.Call's which are not native transfers.
-- CREATE INDEX ix_runtime_related_transactions_address_method_native_transfer_round ON chain.runtime_related_transactions (runtime, account_address, method, likely_native_transfer, tx_round, tx_index);

-- Events emitted from the runtimes. Includes deeply-parsed EVM events from EVM runtimes.
CREATE TABLE chain.runtime_events
(
Expand Down
55 changes: 55 additions & 0 deletions storage/migrations/17_related_transactions_method_denorm.up.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,55 @@
BEGIN;

-- Update consensus account related transactions to include the method field.
ALTER TABLE chain.accounts_related_transactions
ADD COLUMN method TEXT;

DO $$
DECLARE
block_batch_size INT := 50000;
start_block INT;
end_block INT;
max_block INT;
affected_rows INT;
BEGIN
-- Determine the block boundaries from the table to be updated.
SELECT MIN(tx_block), MAX(tx_block)
INTO start_block, max_block
FROM chain.accounts_related_transactions;

IF start_block IS NULL THEN
RAISE NOTICE 'No records found in chain.accounts_related_transactions. Exiting.';
RETURN;
END IF;

-- Process blocks in batches.
WHILE start_block <= max_block LOOP
end_block := start_block + block_batch_size - 1;

UPDATE chain.accounts_related_transactions AS art
SET method = t.method
FROM chain.transactions AS t
WHERE art.tx_block = t.block
AND art.tx_index = t.tx_index
AND art.tx_block BETWEEN start_block AND end_block;

GET DIAGNOSTICS affected_rows = ROW_COUNT;
RAISE NOTICE 'Updated % rows for blocks % to %', affected_rows, start_block, end_block;

-- Move to the next batch.
start_block := end_block + 1;
END LOOP;

RAISE NOTICE 'Batch update completed.';
END $$;

-- We commit here, to ensure index creation below works.
COMMIT;

BEGIN;

ALTER TABLE chain.accounts_related_transactions ALTER COLUMN method SET NOT NULL;

CREATE INDEX ix_accounts_related_transactions_address_method_block_tx_index ON chain.accounts_related_transactions (account_address, method, tx_block DESC, tx_index);

COMMIT;
Loading
Loading