From 777dbb5826279b21915218e59c0800e3f6628c3b Mon Sep 17 00:00:00 2001 From: CJ Cobb Date: Mon, 19 Apr 2021 20:07:55 +0000 Subject: [PATCH] account_tx stored procedure --- reporting/Pg.cpp | 110 ++++++++++++++++++++++++++++++++++ reporting/PostgresBackend.cpp | 98 +++++++++++++----------------- 2 files changed, 153 insertions(+), 55 deletions(-) diff --git a/reporting/Pg.cpp b/reporting/Pg.cpp index 6d7ab33f..e6df563a 100644 --- a/reporting/Pg.cpp +++ b/reporting/Pg.cpp @@ -811,6 +811,116 @@ CREATE TABLE IF NOT EXISTS books ( PRIMARY KEY(book, offer_key, deleted) ); +-- account_tx() RPC helper. From the rippled reporting process, only the +-- parameters without defaults are required. For the parameters with +-- defaults, validation should be done by rippled, such as: +-- _in_account_id should be a valid xrp base58 address. +-- _in_forward either true or false according to the published api +-- _in_limit should be validated and not simply passed through from +-- client. +-- +-- For _in_ledger_index_min and _in_ledger_index_max, if passed in the +-- request, verify that their type is int and pass through as is. +-- For _ledger_hash, verify and convert from hex length 32 bytes and +-- prepend with \x (\\x C++). +-- +-- For _in_ledger_index, if the input type is integer, then pass through +-- as is. If the type is string and contents = validated, then do not +-- set _in_ledger_index. Instead set _in_invalidated to TRUE. +-- +-- There is no need for rippled to do any type of lookup on max/min +-- ledger range, lookup of hash, or the like. This functions does those +-- things, including error responses if bad input. Only the above must +-- be done to set the correct search range. +-- +-- If a marker is present in the request, verify the members 'ledger' +-- and 'seq' are integers and they correspond to _in_marker_seq +-- _in_marker_index. +-- To reiterate: +-- JSON input field 'ledger' corresponds to _in_marker_seq +-- JSON input field 'seq' corresponds to _in_marker_index +CREATE OR REPLACE FUNCTION account_tx(_in_account_id bytea, _in_limit bigint, _in_marker_seq bigint DEFAULT NULL::bigint, _in_marker_index bigint DEFAULT NULL::bigint) + RETURNS jsonb + LANGUAGE plpgsql +AS $function$ +DECLARE + _min bigint; + _max bigint; + _marker bool; + _between_min bigint; + _between_max bigint; + _sql text; + _cursor refcursor; + _result jsonb; + _record record; + _tally bigint := 0; + _ret_marker jsonb; + _transactions jsonb[] := '{}'; +BEGIN + _min := min_ledger(); + _max := max_ledger(); + IF _in_marker_seq IS NOT NULL OR _in_marker_index IS NOT NULL THEN + _marker := TRUE; + IF _in_marker_seq IS NULL OR _in_marker_index IS NULL THEN + -- The rippled implementation returns no transaction results + -- if either of these values are missing. + _between_min := 0; + _between_max := 0; + ELSE + _between_min := _min; + _between_max := _in_marker_seq; + END IF; + ELSE + _marker := FALSE; + _between_min := _min; + _between_max := _max; + END IF; + + + _sql := format('SELECT hash, ledger_seq, transaction_index FROM account_transactions WHERE account = $1 + AND ledger_seq BETWEEN $2 AND $3 ORDER BY ledger_seq, transaction_index'); + + OPEN _cursor FOR EXECUTE _sql USING _in_account_id, _between_min, _between_max; + LOOP + FETCH _cursor INTO _record; + IF _record IS NULL THEN EXIT; END IF; + IF _marker IS TRUE THEN + IF _in_marker_seq = _record.ledger_seq THEN + IF _in_forward IS TRUE THEN + IF _in_marker_index > _record.transaction_index THEN + CONTINUE; + END IF; + ELSE + IF _in_marker_index < _record.transaction_index THEN + CONTINUE; + END IF; + END IF; + END IF; + _marker := FALSE; + END IF; + _tally := _tally + 1; + IF _tally > _in_limit THEN + _ret_marker := jsonb_build_object( + 'ledger', _record.ledger_seq, + 'seq', _record.transaction_index); + EXIT; + END IF; + + -- Is the transaction index in the tx object? + _transactions := _transactions || jsonb_build_object('hash',_record.hash); + END LOOP; + CLOSE _cursor; + + _result := jsonb_build_object('ledger_index_min', _min, + 'ledger_index_max', _max, + 'transactions', _transactions); + IF _ret_marker IS NOT NULL THEN + _result := _result || jsonb_build_object('cursor', _ret_marker); + END IF; + RETURN _result; +END; +$$ LANGUAGE plpgsql; + -- Avoid inadvertent administrative tampering with committed data. CREATE OR REPLACE RULE ledgers_update_protect AS ON UPDATE TO ledgers DO INSTEAD NOTHING; diff --git a/reporting/PostgresBackend.cpp b/reporting/PostgresBackend.cpp index fbf14f07..705d83c4 100644 --- a/reporting/PostgresBackend.cpp +++ b/reporting/PostgresBackend.cpp @@ -520,73 +520,61 @@ PostgresBackend::fetchAccountTransactions( { PgQuery pgQuery(pgPool_); pgQuery("SET statement_timeout TO 10000"); - std::stringstream sql; - sql << "SELECT hash, ledger_seq, transaction_index FROM " - "account_transactions WHERE account = " - << "\'\\x" << ripple::strHex(account) << "\'"; + pg_params dbParams; + + char const*& command = dbParams.first; + std::vector>& values = dbParams.second; + command = + "SELECT account_tx($1::bytea, $2::bigint, " + "$3::bigint, $4::bigint)"; + values.resize(4); + values[0] = "\\x" + strHex(account); + + values[1] = std::to_string(limit); + if (cursor) - sql << " AND ledger_seq = " << cursor->ledgerSequence - << " AND transaction_index < " << cursor->transactionIndex; - sql << " ORDER BY ledger_seq DESC, transaction_index DESC"; - sql << " LIMIT " << std::to_string(limit); + { + values[2] = std::to_string(cursor->ledgerSequence); + values[3] = std::to_string(cursor->transactionIndex); + } + for (size_t i = 0; i < values.size(); ++i) + { + BOOST_LOG_TRIVIAL(debug) << "value " << std::to_string(i) << " = " + << (values[i] ? values[i].value() : "null"); + } + auto start = std::chrono::system_clock::now(); - auto res = pgQuery(sql.str().data()); + auto res = pgQuery(dbParams); auto end = std::chrono::system_clock::now(); auto duration = ((end - start).count()) / 1000000000.0; BOOST_LOG_TRIVIAL(info) - << __func__ << " : executed first query in " << std::to_string(duration) - << " num records = " << std::to_string(checkResult(res, 3)) - << " query = " << sql.str(); - size_t numRows = checkResult(res, 3); + << __func__ << " : executed stored_procedure in " + << std::to_string(duration) + << " num records = " << std::to_string(checkResult(res, 1)); + checkResult(res, 1); - std::vector hashes; - for (size_t i = 0; i < numRows; ++i) + char const* resultStr = res.c_str(); + BOOST_LOG_TRIVIAL(debug) << __func__ << " : " + << "postgres result = " << resultStr + << " : account = " << strHex(account); + + boost::json::value raw = boost::json::parse(resultStr); + boost::json::object responseObj = raw.as_object(); + BOOST_LOG_TRIVIAL(debug) << " parsed = " << responseObj; + if (responseObj.contains("transactions")) { - hashes.push_back(res.asUInt256(i, 0)); - } - - uint32_t newLimit = limit - numRows; - if (newLimit > 0) - { - std::stringstream sql2; - sql2 << "SELECT hash, ledger_seq, transaction_index FROM " - "account_transactions WHERE account = " - << "\'\\x" << ripple::strHex(account) << "\'"; - if (cursor) - sql2 << " AND ledger_seq < " << cursor->ledgerSequence - << " ORDER BY ledger_seq DESC, transaction_index DESC"; - sql2 << " LIMIT " << std::to_string(newLimit); - start = std::chrono::system_clock::now(); - res = pgQuery(sql2.str().data()); - end = std::chrono::system_clock::now(); - - duration = ((end - start).count()) / 1000000000.0; - BOOST_LOG_TRIVIAL(info) - << __func__ << " : executed second query in " - << std::to_string(duration) - << " num records = " << std::to_string(checkResult(res, 3)) - << " query = " << sql2.str(); - if (numRows = checkResult(res, 3)) + auto txns = responseObj.at("transactions").as_array(); + std::vector hashes; + for (auto& hashHex : txns) { - for (size_t i = 0; i < numRows; ++i) - { - hashes.push_back(res.asUInt256(i, 0)); - } + ripple::uint256 hash; + if (hash.parseHex(hashHex.at("hash").as_string().c_str() + 2)) + hashes.push_back(hash); } - } - if (hashes.size() == limit) - { - AccountTransactionsCursor retCursor{ - res.asBigInt(numRows - 1, 1), res.asBigInt(numRows - 1, 2)}; - return {fetchTransactions(hashes), {retCursor}}; - } - else - { return {fetchTransactions(hashes), {}}; } - - return {}; + return {{}, {}}; } void