-
Notifications
You must be signed in to change notification settings - Fork 8
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
Search related continuations in tx search #66
Conversation
@sirlensalot thanks a lot for this PR. I've just merged master into this branch and adapted your changes to work with the new bounded-scans. This way of searching involves an index lookup through Search random string on masterSearching for a random string means we let the database scan through 50000 transactions before giving up with a continuation token.
Search random string on this branch
So it seems like this branch is only slightly slower. When I run this test with different Testing the featureI've manually tested to see whether this branch is able to find transaction 6nN3D_yO8uwDuoyRnD44eeEGOz8W5UCBVr2GYRrVSKI which is a continuation of J-N2mC4lMffEbbphD9R0gjfDmKBu1GlHsEQr5pWC2nQ with code: (coin.transfer-crosschain "k:49cea5ac09a05fb58f0ba609d6b746595d627064125958291973b4d14419aeab" "k:49cea5ac09a05fb58f0ba609d6b746595d627064125958291973b4d14419aeab" (read-keyset "receiver-guard") "0" 897.94089) On master
On this branch
|
Here's the query that the current EXPLAIN ANALYZE
SELECT "t0"."res1" AS "res0", "t0"."res2" AS "res1", "t0"."res3" AS "res2", "t0"."res4" AS "res3", "t0"."res5" AS "res4", "t0"."res6" AS "res5", "t0"."res7" AS "res6", "t0"."res8" AS "res7", "t0"."res9" AS "res8", "t0"."res10" AS "res9", "t0"."res0" AS "res10"
FROM (
SELECT (COALESCE("t0"."code", '')) LIKE ('%897.94089%') AS "res0"
, "t0"."chainid" AS "res1", "t0"."height" AS "res2", "t0"."block" AS "res3", "t0"."creationtime" AS "res4", "t0"."requestkey" AS "res5", "t0"."sender" AS "res6", "t0"."code" AS "res7", "t0"."continuation" AS "res8", "t0"."goodresult" AS "res9"
, ROW_NUMBER() OVER ( ORDER BY "t0"."height" DESC, "t0"."requestkey" DESC) AS "res10"
FROM "transactions" AS "t0"
WHERE ("t0"."height") <= (2991665)
LIMIT 50000
) AS "t0"
WHERE (("t0"."res10") = (50000))
OR ("t0"."res0")
ORDER BY "t0"."res2" DESC, "t0"."res5" DESC LIMIT 10
;
QUERY PLAN
------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
Limit (cost=158.26..183.69 rows=10 width=1136) (actual time=38.135..124.848 rows=2 loops=1)
-> Subquery Scan on t0 (cost=158.26..64036.18 rows=25125 width=1136) (actual time=38.133..124.846 rows=2 loops=1)
Filter: ((t0.res10 = 50000) OR t0.res0)
Rows Removed by Filter: 49998
-> Limit (cost=158.26..63411.18 rows=50000 width=1136) (actual time=0.275..122.083 rows=50000 loops=1)
-> WindowAgg (cost=158.26..9111863.77 rows=7202597 width=1136) (actual time=0.274..119.112 rows=50000 loops=1)
-> Incremental Sort (cost=158.26..8967811.83 rows=7202597 width=1127) (actual time=0.254..72.205 rows=50001 loops=1)
Sort Key: t0_1.height DESC, t0_1.requestkey DESC
Presorted Key: t0_1.height
Full-sort Groups: 1145 Sort Method: quicksort Average Memory: 60kB Peak Memory: 85kB
Pre-sorted Groups: 212 Sort Method: quicksort Average Memory: 64kB Peak Memory: 105kB
-> Index Scan Backward using transactions_height_idx on transactions t0_1 (cost=0.43..8457798.50 rows=7202597 width=1127) (actual time=0.049..24.042 rows=50014 loops=1)
Index Cond: (height <= 2991665)
Planning Time: 0.365 ms
Execution Time: 124.923 ms
(15 rows) Here's the query performed by this PR as of writing this comment: EXPLAIN ANALYZE
SELECT "t0"."res1" AS "res0", "t0"."res2" AS "res1", "t0"."res3" AS "res2", "t0"."res4" AS "res3", "t0"."res5" AS "res4", "t0"."res6" AS "res5", "t0"."res7" AS "res6", "t0"."res8" AS "res7", "t0"."res9" AS "res8", "t0"."res10" AS "res9", "t0"."res0" AS "res10"
FROM (
SELECT (COALESCE(COALESCE("t0"."code", "t1"."code", null), '')) LIKE ('%897.94089%') AS "res0"
, "t0"."chainid" AS "res1", "t0"."height" AS "res2", "t0"."block" AS "res3", "t0"."creationtime" AS "res4", "t0"."requestkey" AS "res5", "t0"."sender" AS "res6", COALESCE("t0"."code", "t1"."code", null) AS "res7", "t0"."continuation" AS "res8", "t0"."goodresult" AS "res9"
, ROW_NUMBER() OVER ( ORDER BY "t0"."height" DESC, "t0"."requestkey" DESC) AS "res10"
FROM "transactions" AS "t0"
LEFT JOIN "transactions" AS "t1"
ON ("t1"."requestkey") = ("t0"."pactid")
WHERE ("t0"."height") <= (2991665)
LIMIT 50000
) AS "t0"
WHERE (("t0"."res10") = (50000))
OR ("t0"."res0")
ORDER BY "t0"."res2" DESC
, "t0"."res5" DESC
LIMIT 10
;
QUERY PLAN
-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
Limit (cost=208.75..241.93 rows=10 width=967) (actual time=1.062..127.704 rows=4 loops=1)
-> Subquery Scan on t0 (cost=208.75..83556.68 rows=25125 width=967) (actual time=1.059..127.701 rows=4 loops=1)
Filter: ((t0.res10 = 50000) OR t0.res0)
Rows Removed by Filter: 49996
-> Limit (cost=208.75..82931.68 rows=50000 width=967) (actual time=0.580..125.474 rows=50000 loops=1)
-> WindowAgg (cost=208.75..11916635.12 rows=7202614 width=967) (actual time=0.579..123.098 rows=50000 loops=1)
-> Incremental Sort (cost=208.75..11772582.84 rows=7202614 width=1328) (actual time=0.558..83.273 rows=50001 loops=1)
Sort Key: t0_1.height DESC, t0_1.requestkey DESC
Presorted Key: t0_1.height
Full-sort Groups: 1145 Sort Method: quicksort Average Memory: 61kB Peak Memory: 86kB
Pre-sorted Groups: 209 Sort Method: quicksort Average Memory: 64kB Peak Memory: 105kB
-> Nested Loop Left Join (cost=1.01..11262568.12 rows=7202614 width=1328) (actual time=0.096..46.655 rows=50015 loops=1)
-> Index Scan Backward using transactions_height_idx on transactions t0_1 (cost=0.43..11009320.87 rows=7202614 width=1170) (actual time=0.072..11.219 rows=49976 loops=1)
Index Cond: (height <= 2991665)
-> Memoize (cost=0.57..7.00 rows=1 width=245) (actual time=0.000..0.000 rows=0 loops=49976)
Cache Key: t0_1.pactid
Cache Mode: logical
Hits: 47913 Misses: 2063 Evictions: 0 Overflows: 0 Memory Usage: 796kB
-> Index Scan using transactions_requestkey_idx on transactions t1 (cost=0.56..6.99 rows=1 width=245) (actual time=0.006..0.006 rows=1 loops=2063)
Index Cond: ((requestkey)::text = (t0_1.pactid)::text)
Planning Time: 0.895 ms
Execution Time: 127.973 ms
(22 rows) The main difference is: FROM "transactions" AS "t0"
LEFT JOIN "transactions" AS "t1"
ON ("t1"."requestkey") = ("t0"."pactid") Where we chase the SELECT requestkey, pactid, code
FROM transactions
WHERE requestkey IN
( 'OSfVmNMwYh8uoMOKi_-aBZA92Zx7im9cgiMT0muSNBM'
, 'EvwZxXKWWmNogmDjdIB1TPIibdlAPhnQ2wI_gvsMx6s'
, 'xLaJY7Egz2idKqPKSh5fE30dfxfU2tGIz-m2y2Z2KeA'
)
ORDER BY height DESC;
-[ RECORD 1 ]-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
requestkey | OSfVmNMwYh8uoMOKi_-aBZA92Zx7im9cgiMT0muSNBM
pactid | EvwZxXKWWmNogmDjdIB1TPIibdlAPhnQ2wI_gvsMx6s
code |
-[ RECORD 2 ]-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
requestkey | EvwZxXKWWmNogmDjdIB1TPIibdlAPhnQ2wI_gvsMx6s
pactid | xLaJY7Egz2idKqPKSh5fE30dfxfU2tGIz-m2y2Z2KeA
code |
-[ RECORD 3 ]-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
requestkey | xLaJY7Egz2idKqPKSh5fE30dfxfU2tGIz-m2y2Z2KeA
pactid |
code | (free.backalley.transfer-crosschain "k:b711fc8a826edd7f3358b6e95d4ee2f90af9f3d3e17b7a920679d3710eb173b2" "k:b711fc8a826edd7f3358b6e95d4ee2f90af9f3d3e17b7a920679d3710eb173b2" (read-keyset "receiver-guard") "1" 14000.0) We can actually enhance the SQL of this branch with a recursive CTE to chase an arbitrarily long chain of transactions: EXPLAIN ANALYZE
SELECT "t0"."res1" AS "res0", "t0"."res2" AS "res1", "t0"."res3" AS "res2", "t0"."res4" AS "res3", "t0"."res5" AS "res4", "t0"."res6" AS "res5", "t0"."res7" AS "res6", "t0"."res8" AS "res7", "t0"."res9" AS "res8", "t0"."res10" AS "res9", "t0"."res0" AS "res10"
FROM (
SELECT (COALESCE(COALESCE("t0"."code", "t1"."code", null), '')) LIKE ('%897.94089%') AS "res0"
, "t0"."chainid" AS "res1", "t0"."height" AS "res2", "t0"."block" AS "res3", "t0"."creationtime" AS "res4", "t0"."requestkey" AS "res5", "t0"."sender" AS "res6", COALESCE("t0"."code", "t1"."code", null) AS "res7", "t0"."continuation" AS "res8", "t0"."goodresult" AS "res9"
, ROW_NUMBER() OVER ( ORDER BY "t0"."height" DESC, "t0"."requestkey" DESC) AS "res10"
FROM "transactions" AS "t0"
LEFT JOIN LATERAL (
WITH RECURSIVE codeOfInitialTransaction AS (
SELECT "t1"."code", "t1"."pactid"
FROM "transactions" AS "t1"
WHERE ("t1"."requestkey") = ("t0"."pactid")
UNION ALL
SELECT "t2"."code", "t2"."pactid"
FROM "transactions" AS "t2"
INNER JOIN codeOfInitialTransaction AS "t3" ON ("t3"."pactid") = ("t2"."requestkey")
)
SELECT "t4"."code"
FROM codeOfInitialTransaction AS "t4"
WHERE "t4"."code" IS NOT NULL
LIMIT 1
) t1 ON true
WHERE ("t0"."height") <= (2991665)
LIMIT 50000
) AS "t0"
WHERE (("t0"."res10") = (50000))
OR ("t0"."res0")
ORDER BY "t0"."res2" DESC
, "t0"."res5" DESC
LIMIT 10;
QUERY PLAN
-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
Limit (cost=1195.40..1246.53 rows=10 width=967) (actual time=1.014..124.340 rows=4 loops=1)
-> Subquery Scan on t0 (cost=1195.40..129652.00 rows=25125 width=967) (actual time=1.012..124.337 rows=4 loops=1)
Filter: ((t0.res10 = 50000) OR t0.res0)
Rows Removed by Filter: 49996
-> Limit (cost=1195.40..129027.00 rows=50000 width=967) (actual time=0.525..122.023 rows=50000 loops=1)
-> WindowAgg (cost=1195.40..18415659.66 rows=7202626 width=967) (actual time=0.524..119.696 rows=50000 loops=1)
-> Incremental Sort (cost=1195.40..18271607.14 rows=7202626 width=1159) (actual time=0.504..80.946 rows=50001 loops=1)
Sort Key: t0_1.height DESC, t0_1.requestkey DESC
Presorted Key: t0_1.height
Full-sort Groups: 1145 Sort Method: quicksort Average Memory: 61kB Peak Memory: 86kB
Pre-sorted Groups: 212 Sort Method: quicksort Average Memory: 64kB Peak Memory: 105kB
-> Nested Loop Left Join (cost=871.99..17761591.44 rows=7202626 width=1159) (actual time=0.070..45.480 rows=50014 loops=1)
-> Index Scan Backward using transactions_height_idx on transactions t0_1 (cost=0.43..8457851.89 rows=7202626 width=1170) (actual time=0.044..10.755 rows=50014 loops=1)
Index Cond: (height <= 2991665)
-> Memoize (cost=871.56..871.59 rows=1 width=32) (actual time=0.000..0.000 rows=0 loops=50014)
Cache Key: t0_1.pactid
Cache Mode: binary
Hits: 47946 Misses: 2068 Evictions: 0 Overflows: 0 Memory Usage: 705kB
-> Limit (cost=871.55..871.57 rows=1 width=32) (actual time=0.006..0.006 rows=1 loops=2068)
CTE codeofinitialtransaction
-> Recursive Union (cost=0.56..871.55 rows=111 width=244) (actual time=0.006..0.006 rows=1 loops=2068)
-> Index Scan using transactions_requestkey_idx on transactions t1 (cost=0.56..8.58 rows=1 width=244) (actual time=0.006..0.006 rows=1 loops=2068)
Index Cond: ((requestkey)::text = ($1)::text)
-> Nested Loop (cost=0.56..86.07 rows=11 width=244) (actual time=0.005..0.006 rows=0 loops=2)
-> WorkTable Scan on codeofinitialtransaction t3 (cost=0.00..0.20 rows=10 width=32) (actual time=0.001..0.001 rows=0 loops=2)
-> Index Scan using transactions_requestkey_idx on transactions t2 (cost=0.56..8.58 rows=1 width=288) (actual time=0.006..0.006 rows=1 loops=1)
Index Cond: ((requestkey)::text = (t3.pactid)::text)
-> CTE Scan on codeofinitialtransaction t4 (cost=0.00..2.22 rows=110 width=32) (actual time=0.006..0.006 rows=1 loops=2068)
Filter: (code IS NOT NULL)
Rows Removed by Filter: 0
Planning Time: 0.925 ms
Execution Time: 124.526 ms
(32 rows) We can actually confirm that this version finds all three of the records returned aboveSELECT "t0"."res1" AS "res0", "t0"."res2" AS "res1", "t0"."res3" AS "res2", "t0"."res4" AS "res3", "t0"."res5" AS "res4", "t0"."res6" AS "res5", "t0"."res7" AS "res6", "t0"."res8" AS "res7", "t0"."res9" AS "res8", "t0"."res10" AS "res9", "t0"."res0" AS "res10"
FROM (
SELECT (COALESCE(COALESCE("t0"."code", "t1"."code", null), '')) LIKE ('%free.backalley.transfer-crosschain%') AS "res0"
, "t0"."chainid" AS "res1", "t0"."height" AS "res2", "t0"."block" AS "res3", "t0"."creationtime" AS "res4", "t0"."requestkey" AS "res5", "t0"."sender" AS "res6", COALESCE("t0"."code", "t1"."code", null) AS "res7", "t0"."continuation" AS "res8", "t0"."goodresult" AS "res9"
, ROW_NUMBER() OVER ( ORDER BY "t0"."height" DESC, "t0"."requestkey" DESC) AS "res10"
FROM "transactions" AS "t0"
LEFT JOIN LATERAL (
WITH RECURSIVE codeOfInitialTransaction AS (
SELECT "t1"."code", "t1"."pactid"
FROM "transactions" AS "t1"
WHERE ("t1"."requestkey") = ("t0"."pactid")
UNION ALL
SELECT "t2"."code", "t2"."pactid"
FROM "transactions" AS "t2"
INNER JOIN codeOfInitialTransaction AS "t3" ON ("t3"."pactid") = ("t2"."requestkey")
)
SELECT "t4"."code"
FROM codeOfInitialTransaction AS "t4"
WHERE "t4"."code" IS NOT NULL
LIMIT 1
) t1 ON true
WHERE ("t0"."height") <= (2849467)
LIMIT 50000
) AS "t0"
WHERE (("t0"."res10") = (50000))
OR ("t0"."res0")
ORDER BY "t0"."res2" DESC
, "t0"."res5" DESC
LIMIT 10;
-[ RECORD 1 ]------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
res0 | 1
res1 | 2849467
res2 | MBKEJvC9b7SuRP34Q5HzK1iYK0XcORrYRWrMvwiKDSo
res3 | 2022-07-15 20:32:10+02
res4 | OSfVmNMwYh8uoMOKi_-aBZA92Zx7im9cgiMT0muSNBM
res5 | kadena-xchain-gas
res6 | (free.backalley.transfer-crosschain "k:b711fc8a826edd7f3358b6e95d4ee2f90af9f3d3e17b7a920679d3710eb173b2" "k:b711fc8a826edd7f3358b6e95d4ee2f90af9f3d3e17b7a920679d3710eb173b2" (read-keyset "receiver-guard") "1" 14000.0)
res7 |
res8 |
res9 | 3
res10 | t
-[ RECORD 2 ]------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
res0 | 1
res1 | 2849464
res2 | mog7DFXksq-m8gW7kA2Hc3UovMr7XOvxnvH-g8s9QuU
res3 | 2022-07-15 20:30:46+02
res4 | EvwZxXKWWmNogmDjdIB1TPIibdlAPhnQ2wI_gvsMx6s
res5 | free-x-chain-gas
res6 | (free.backalley.transfer-crosschain "k:b711fc8a826edd7f3358b6e95d4ee2f90af9f3d3e17b7a920679d3710eb173b2" "k:b711fc8a826edd7f3358b6e95d4ee2f90af9f3d3e17b7a920679d3710eb173b2" (read-keyset "receiver-guard") "1" 14000.0)
res7 | {"step": 1, "yield": null, "pactId": "xLaJY7Egz2idKqPKSh5fE30dfxfU2tGIz-m2y2Z2KeA", "executed": null, "stepCount": 2, "continuation": {"def": "free.backalley.transfer-crosschain", "args": ["k:b711fc8a826edd7f3358b6e95d4ee2f90af9f3d3e17b7a920679d3710eb173b2", "k:b711fc8a826edd7f3358b6e95d4ee2f90af9f3d3e17b7a920679d3710eb173b2", {"keys": ["b711fc8a826edd7f3358b6e95d4ee2f90af9f3d3e17b7a920679d3710eb173b2"], "pred": "keys-all"}, "1", 14000]}, "stepHasRollback": false}
res8 | "Write succeeded"
res9 | 32
res10 | t
-[ RECORD 3 ]------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
res0 | 3
res1 | 2849459
res2 | vD4b5pEBk4db83P1ljcbcLxkpND90Hm45S6dPKOqx70
res3 | 2022-07-15 20:28:22+02
res4 | xLaJY7Egz2idKqPKSh5fE30dfxfU2tGIz-m2y2Z2KeA
res5 | k:b711fc8a826edd7f3358b6e95d4ee2f90af9f3d3e17b7a920679d3710eb173b2
res6 | (free.backalley.transfer-crosschain "k:b711fc8a826edd7f3358b6e95d4ee2f90af9f3d3e17b7a920679d3710eb173b2" "k:b711fc8a826edd7f3358b6e95d4ee2f90af9f3d3e17b7a920679d3710eb173b2" (read-keyset "receiver-guard") "1" 14000.0)
res7 | {"step": 0, "yield": {"data": {"amount": 14000, "receiver": "k:b711fc8a826edd7f3358b6e95d4ee2f90af9f3d3e17b7a920679d3710eb173b2", "receiver-guard": {"keys": ["b711fc8a826edd7f3358b6e95d4ee2f90af9f3d3e17b7a920679d3710eb173b2"], "pred": "keys-all"}}, "source": "3", "provenance": {"moduleHash": "0IttHL1xHV8KpR93UxEgsYixAl06LcHrdRjTA80nuoQ", "targetChainId": "1"}}, "pactId": "xLaJY7Egz2idKqPKSh5fE30dfxfU2tGIz-m2y2Z2KeA", "executed": null, "stepCount": 2, "continuation": {"def": "free.backalley.transfer-crosschain", "args": ["k:b711fc8a826edd7f3358b6e95d4ee2f90af9f3d3e17b7a920679d3710eb173b2", "k:b711fc8a826edd7f3358b6e95d4ee2f90af9f3d3e17b7a920679d3710eb173b2", {"keys": ["b711fc8a826edd7f3358b6e95d4ee2f90af9f3d3e17b7a920679d3710eb173b2"], "pred": "keys-all"}, "1", 14000]}, "stepHasRollback": false}
res8 | {"amount": 14000, "receiver": "k:b711fc8a826edd7f3358b6e95d4ee2f90af9f3d3e17b7a920679d3710eb173b2", "receiver-guard": {"keys": ["b711fc8a826edd7f3358b6e95d4ee2f90af9f3d3e17b7a920679d3710eb173b2"], "pred": "keys-all"}}
res9 | 54
res10 | t
-[ RECORD 4 ]------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
res0 | 1
res1 | 2849275
res2 | Tgp22ChKbU8fok283zjnT88oi62zMK9NCrmjCWJFb1g
res3 | 2022-07-15 18:56:28+02
res4 | jo3rsOzFRRtB7RzPPZrH7AlUtnGvcpHhqjLFkqeps8Y
res5 | free-x-chain-gas
res6 | (free.backalley.transfer-crosschain "k:59779a954441db142c73a363140a2171a1dce0721975af11f8078f72ac70a916" "k:59779a954441db142c73a363140a2171a1dce0721975af11f8078f72ac70a916" (read-keyset "receiver-guard") "1" 250000.0)
res7 | {"step": 1, "yield": null, "pactId": "xyYyp97v3uTneN7BG2PbITQamsRy73YMtbyE0cYaAPE", "executed": null, "stepCount": 2, "continuation": {"def": "free.backalley.transfer-crosschain", "args": ["k:59779a954441db142c73a363140a2171a1dce0721975af11f8078f72ac70a916", "k:59779a954441db142c73a363140a2171a1dce0721975af11f8078f72ac70a916", {"keys": ["59779a954441db142c73a363140a2171a1dce0721975af11f8078f72ac70a916"], "pred": "keys-all"}, "1", 250000]}, "stepHasRollback": false}
res8 | "Write succeeded"
res9 | 826
res10 | t
-[ RECORD 5 ]------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
res0 | 3
res1 | 2849270
res2 | 7NxvqSFmdpi_vbo5RuthCh70O6J4oZna6-H02Cigk4Y
res3 | 2022-07-15 18:53:25+02
res4 | xyYyp97v3uTneN7BG2PbITQamsRy73YMtbyE0cYaAPE
res5 | k:59779a954441db142c73a363140a2171a1dce0721975af11f8078f72ac70a916
res6 | (free.backalley.transfer-crosschain "k:59779a954441db142c73a363140a2171a1dce0721975af11f8078f72ac70a916" "k:59779a954441db142c73a363140a2171a1dce0721975af11f8078f72ac70a916" (read-keyset "receiver-guard") "1" 250000.0)
res7 | {"step": 0, "yield": {"data": {"amount": 250000, "receiver": "k:59779a954441db142c73a363140a2171a1dce0721975af11f8078f72ac70a916", "receiver-guard": {"keys": ["59779a954441db142c73a363140a2171a1dce0721975af11f8078f72ac70a916"], "pred": "keys-all"}}, "source": "3", "provenance": {"moduleHash": "0IttHL1xHV8KpR93UxEgsYixAl06LcHrdRjTA80nuoQ", "targetChainId": "1"}}, "pactId": "xyYyp97v3uTneN7BG2PbITQamsRy73YMtbyE0cYaAPE", "executed": null, "stepCount": 2, "continuation": {"def": "free.backalley.transfer-crosschain", "args": ["k:59779a954441db142c73a363140a2171a1dce0721975af11f8078f72ac70a916", "k:59779a954441db142c73a363140a2171a1dce0721975af11f8078f72ac70a916", {"keys": ["59779a954441db142c73a363140a2171a1dce0721975af11f8078f72ac70a916"], "pred": "keys-all"}, "1", 250000]}, "stepHasRollback": false}
res8 | {"amount": 250000, "receiver": "k:59779a954441db142c73a363140a2171a1dce0721975af11f8078f72ac70a916", "receiver-guard": {"keys": ["59779a954441db142c73a363140a2171a1dce0721975af11f8078f72ac70a916"], "pred": "keys-all"}}
res9 | 835
res10 | t
-[ RECORD 6 ]------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
res0 | 1
res1 | 2849253
res2 | WCVZcd5cF0BradazsNaphOvA0aLxs47pKOMCieDAtwc
res3 | 2022-07-15 18:44:55+02
res4 | OTIRhqr6cjJ3kLrrg8C9cPT6KdUGwR-xEMul-FrM2to
res5 | free-x-chain-gas
res6 | (free.backalley.transfer-crosschain "k:59779a954441db142c73a363140a2171a1dce0721975af11f8078f72ac70a916" "k:59779a954441db142c73a363140a2171a1dce0721975af11f8078f72ac70a916" (read-keyset "receiver-guard") "1" 250000.0)
res7 | {"step": 1, "yield": null, "pactId": "BEm8RC7zTWsMA_RY_g6TUcu3UmBKTgFh8Wh7zmeG4Mo", "executed": null, "stepCount": 2, "continuation": {"def": "free.backalley.transfer-crosschain", "args": ["k:59779a954441db142c73a363140a2171a1dce0721975af11f8078f72ac70a916", "k:59779a954441db142c73a363140a2171a1dce0721975af11f8078f72ac70a916", {"keys": ["59779a954441db142c73a363140a2171a1dce0721975af11f8078f72ac70a916"], "pred": "keys-all"}, "1", 250000]}, "stepHasRollback": false}
res8 | "Write succeeded"
res9 | 893
res10 | t
-[ RECORD 7 ]------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
res0 | 1
res1 | 2849251
res2 | xEMu5DhTaEVLfXh7kUZJpgucxJUXX31FrwttoMjCRuk
res3 | 2022-07-15 18:44:22+02
res4 | kOo4-CvA0zBXfiO2Z1k3hWg6BEzQz7d9qV_LVmGxdNE
res5 | kadena-xchain-gas
res6 | (free.backalley.transfer-crosschain "k:0bdbb556671846fee8545aa002aa41964215710d0fd8c8a4241e8972dca92473" "k:0bdbb556671846fee8545aa002aa41964215710d0fd8c8a4241e8972dca92473" (read-keyset "receiver-guard") "1" 1050000.0)
res7 |
res8 |
res9 | 915
res10 | t
-[ RECORD 8 ]------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
res0 | 1
res1 | 2849248
res2 | Z996kewum4RlkXd4bbTWeEJMvJiYVfH2G3gB29UQZMI
res3 | 2022-07-15 18:43:21+02
res4 | YqQko2jHoHD5qBRbnJSAzozpME_opasntaZXc6QDUxE
res5 | free-x-chain-gas
res6 | (free.backalley.transfer-crosschain "k:0bdbb556671846fee8545aa002aa41964215710d0fd8c8a4241e8972dca92473" "k:0bdbb556671846fee8545aa002aa41964215710d0fd8c8a4241e8972dca92473" (read-keyset "receiver-guard") "1" 1050000.0)
res7 | {"step": 1, "yield": null, "pactId": "W_mF8od5ZqhLBDsnDtB5in77IVL_BuDgcoDZ_NLmBLg", "executed": null, "stepCount": 2, "continuation": {"def": "free.backalley.transfer-crosschain", "args": ["k:0bdbb556671846fee8545aa002aa41964215710d0fd8c8a4241e8972dca92473", "k:0bdbb556671846fee8545aa002aa41964215710d0fd8c8a4241e8972dca92473", {"keys": ["0bdbb556671846fee8545aa002aa41964215710d0fd8c8a4241e8972dca92473"], "pred": "keys-all"}, "1", 1050000]}, "stepHasRollback": false}
res8 | "Write succeeded"
res9 | 922
res10 | t
-[ RECORD 9 ]------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
res0 | 3
res1 | 2849246
res2 | 78-h9zng1DMz13hbAXRyqLQjUJiQu9IETZI-xUgJyUU
res3 | 2022-07-15 18:41:32+02
res4 | BEm8RC7zTWsMA_RY_g6TUcu3UmBKTgFh8Wh7zmeG4Mo
res5 | k:59779a954441db142c73a363140a2171a1dce0721975af11f8078f72ac70a916
res6 | (free.backalley.transfer-crosschain "k:59779a954441db142c73a363140a2171a1dce0721975af11f8078f72ac70a916" "k:59779a954441db142c73a363140a2171a1dce0721975af11f8078f72ac70a916" (read-keyset "receiver-guard") "1" 250000.0)
res7 | {"step": 0, "yield": {"data": {"amount": 250000, "receiver": "k:59779a954441db142c73a363140a2171a1dce0721975af11f8078f72ac70a916", "receiver-guard": {"keys": ["59779a954441db142c73a363140a2171a1dce0721975af11f8078f72ac70a916"], "pred": "keys-all"}}, "source": "3", "provenance": {"moduleHash": "0IttHL1xHV8KpR93UxEgsYixAl06LcHrdRjTA80nuoQ", "targetChainId": "1"}}, "pactId": "BEm8RC7zTWsMA_RY_g6TUcu3UmBKTgFh8Wh7zmeG4Mo", "executed": null, "stepCount": 2, "continuation": {"def": "free.backalley.transfer-crosschain", "args": ["k:59779a954441db142c73a363140a2171a1dce0721975af11f8078f72ac70a916", "k:59779a954441db142c73a363140a2171a1dce0721975af11f8078f72ac70a916", {"keys": ["59779a954441db142c73a363140a2171a1dce0721975af11f8078f72ac70a916"], "pred": "keys-all"}, "1", 250000]}, "stepHasRollback": false}
res8 | {"amount": 250000, "receiver": "k:59779a954441db142c73a363140a2171a1dce0721975af11f8078f72ac70a916", "receiver-guard": {"keys": ["59779a954441db142c73a363140a2171a1dce0721975af11f8078f72ac70a916"], "pred": "keys-all"}}
res9 | 944
res10 | t
-[ RECORD 10 ]-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
res0 | 3
res1 | 2849225
res2 | ebzpBozhrIdQVDJCZ4y2DuUmkrajsg15wsZCwWr9BjE
res3 | 2022-07-15 18:31:17+02
res4 | W_mF8od5ZqhLBDsnDtB5in77IVL_BuDgcoDZ_NLmBLg
res5 | k:0bdbb556671846fee8545aa002aa41964215710d0fd8c8a4241e8972dca92473
res6 | (free.backalley.transfer-crosschain "k:0bdbb556671846fee8545aa002aa41964215710d0fd8c8a4241e8972dca92473" "k:0bdbb556671846fee8545aa002aa41964215710d0fd8c8a4241e8972dca92473" (read-keyset "receiver-guard") "1" 1050000.0)
res7 | {"step": 0, "yield": {"data": {"amount": 1050000, "receiver": "k:0bdbb556671846fee8545aa002aa41964215710d0fd8c8a4241e8972dca92473", "receiver-guard": {"keys": ["0bdbb556671846fee8545aa002aa41964215710d0fd8c8a4241e8972dca92473"], "pred": "keys-all"}}, "source": "3", "provenance": {"moduleHash": "0IttHL1xHV8KpR93UxEgsYixAl06LcHrdRjTA80nuoQ", "targetChainId": "1"}}, "pactId": "W_mF8od5ZqhLBDsnDtB5in77IVL_BuDgcoDZ_NLmBLg", "executed": null, "stepCount": 2, "continuation": {"def": "free.backalley.transfer-crosschain", "args": ["k:0bdbb556671846fee8545aa002aa41964215710d0fd8c8a4241e8972dca92473", "k:0bdbb556671846fee8545aa002aa41964215710d0fd8c8a4241e8972dca92473", {"keys": ["0bdbb556671846fee8545aa002aa41964215710d0fd8c8a4241e8972dca92473"], "pred": "keys-all"}, "1", 1050000]}, "stepHasRollback": false}
res8 | {"amount": 1050000, "receiver": "k:0bdbb556671846fee8545aa002aa41964215710d0fd8c8a4241e8972dca92473", "receiver-guard": {"keys": ["0bdbb556671846fee8545aa002aa41964215710d0fd8c8a4241e8972dca92473"], "pred": "keys-all"}}
res9 | 1075
res10 | t Which doesn't even seem to cause much performance overhead, but the main problem is that it seems impossible to express recursive CTEs in subqueries using |
1ec01fc
to
26c7d82
Compare
I've managed to find a solution to that problem and pushed a commit that applies it. CREATE OR REPLACE FUNCTION continuation_steps(pactid_in text)
RETURNS TABLE (code text, requestkey text, depth integer) AS $$
WITH RECURSIVE transactionSteps AS (
SELECT DISTINCT ON (depth) t1.code, t1.pactid, 1 AS depth, t1.requestkey AS sourcekey
FROM transactions AS t1
WHERE (t1.requestkey) = pactid_in
UNION ALL
SELECT DISTINCT ON (depth) t2.code, t2.pactid, t3.depth + 1 AS depth, t2.requestkey AS sourcekey
FROM transactions AS t2
INNER JOIN transactionSteps AS t3 ON t3.pactid = t2.requestkey
)
SELECT code, sourcekey, depth
FROM transactionSteps
$$ LANGUAGE sql IMMUTABLE;
CREATE OR REPLACE FUNCTION continuation_history(pactid_in text)
RETURNS TABLE (code text, steps text[]) AS $$
SELECT (array_agg(code) FILTER (WHERE code IS NOT NULL))[1] as code
, array_agg(requestkey ORDER BY depth) as steps
FROM continuation_steps(pactid_in)
$$ LANGUAGE sql IMMUTABLE; This way, not only would this complicated subquery be accessible to queries run directly in a DB session, but we'd also be able to get rid of the joinContinuationHistory :: PgExpr s (Maybe (DbHash TxHash)) ->
Q Postgres ChainwebDataDb s (ContinuationHistoryF (PgExpr s))
joinContinuationHistory pactIdExp = pgUnnest $
(customExpr_ $ \pactId ->
"continuation_history(" <> pactId <> "::text )"
) pactIdExp Which is much more pleasant to look at and it uses
|
With this new continuation history code we still get the same results for our original transaction search request:
And that results in the following DB query: EXPLAIN ANALYZE
SELECT "t0"."res1" AS "res0", "t0"."res2" AS "res1", "t0"."res3" AS "res2", "t0"."res4" AS "res3", "t0"."res5" AS "res4", "t0"."res6" AS "res5", "t0"."res7" AS "res6", "t0"."res8" AS "res7", "t0"."res9" AS "res8", "t0"."res10" AS "res9", "t0"."res0" AS "res10"
FROM (
SELECT (COALESCE(COALESCE("t0"."code", "t1"."r0", null), '')) LIKE ('%897.94089%') AS "res0", "t0"."chainid" AS "res1", "t0"."height" AS "res2", "t0"."block" AS "res3", "t0"."creationtime" AS "res4", "t0"."requestkey" AS "res5", "t0"."sender" AS "res6", COALESCE("t0"."code", "t1"."r0", null) AS "res7", "t0"."continuation" AS "res8", "t0"."goodresult" AS "res9", ROW_NUMBER() OVER ( ORDER BY "t0"."height" DESC, "t0"."requestkey" DESC) AS "res10"
FROM "transactions" AS "t0"
CROSS JOIN LATERAL (
WITH RECURSIVE transactionSteps AS (
SELECT DISTINCT ON (depth) tInner.code, tInner.pactid, 1 AS depth, tInner.requestkey
FROM transactions AS tInner
WHERE (tInner.requestkey) = ("t0"."pactid")
UNION ALL
SELECT DISTINCT ON (depth) tInner.code, tInner.pactid, tRec.depth + 1, tInner.requestkey
FROM transactions AS tInner
INNER JOIN transactionSteps AS tRec ON tRec.pactid = tInner.requestkey
)
SELECT (array_agg(code) FILTER (WHERE code IS NOT NULL))[1] as code
, array_agg(requestkey ORDER BY depth) as steps
FROM transactionSteps
) "t1"("r0", "r1")
WHERE ("t0"."height") <= (2991665) LIMIT 50000
) AS "t0"
WHERE (("t0"."res10") = (50000)) OR ("t0"."res0")
ORDER BY "t0"."res2" DESC, "t0"."res5" DESC
LIMIT 10
;
QUERY PLAN
----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
Limit (cost=1202.94..1254.12 rows=10 width=967) (actual time=1.293..136.210 rows=4 loops=1)
-> Subquery Scan on t0 (cost=1202.94..129796.63 rows=25125 width=967) (actual time=1.291..136.207 rows=4 loops=1)
Filter: ((t0.res10 = 50000) OR t0.res0)
Rows Removed by Filter: 49996
-> Limit (cost=1202.94..129171.63 rows=50000 width=967) (actual time=0.736..133.997 rows=50000 loops=1)
-> WindowAgg (cost=1202.94..18571167.56 rows=7255667 width=967) (actual time=0.735..131.625 rows=50000 loops=1)
-> Incremental Sort (cost=1202.94..18426054.22 rows=7255667 width=1159) (actual time=0.715..91.986 rows=50001 loops=1)
Sort Key: t0_1.height DESC, t0_1.requestkey DESC
Presorted Key: t0_1.height
Full-sort Groups: 1145 Sort Method: quicksort Average Memory: 61kB Peak Memory: 86kB
Pre-sorted Groups: 212 Sort Method: quicksort Average Memory: 64kB Peak Memory: 105kB
-> Nested Loop (cost=876.80..17911714.96 rows=7255667 width=1159) (actual time=0.113..55.706 rows=50014 loops=1)
-> Index Scan Backward using transactions_height_idx on transactions t0_1 (cost=0.43..8556481.43 rows=7255667 width=1170) (actual time=0.054..11.144 rows=50014 loops=1)
Index Cond: (height <= 2991665)
-> Memoize (cost=876.36..876.38 rows=1 width=32) (actual time=0.000..0.001 rows=1 loops=50014)
Cache Key: t0_1.pactid
Cache Mode: binary
Hits: 47946 Misses: 2068 Evictions: 0 Overflows: 0 Memory Usage: 705kB
-> Subquery Scan on t1 (cost=876.35..876.37 rows=1 width=32) (actual time=0.010..0.010 rows=1 loops=2068)
-> Aggregate (cost=876.35..876.36 rows=1 width=64) (actual time=0.009..0.009 rows=1 loops=2068)
CTE transactionsteps
-> Recursive Union (cost=0.56..874.08 rows=101 width=292) (actual time=0.007..0.008 rows=1 loops=2068)
-> Unique (cost=0.56..8.58 rows=1 width=292) (actual time=0.006..0.007 rows=1 loops=2068)
-> Index Scan using transactions_requestkey_idx on transactions tinner (cost=0.56..8.58 rows=1 width=292) (actual time=0.006..0.006 rows=1 loops=2068)
Index Cond: ((requestkey)::text = ($1)::text)
-> Subquery Scan on "*SELECT* 2" (cost=86.29..86.45 rows=10 width=292) (actual time=0.001..0.001 rows=0 loops=2069)
-> Unique (cost=86.29..86.35 rows=10 width=296) (actual time=0.001..0.001 rows=0 loops=2069)
-> Sort (cost=86.29..86.32 rows=11 width=296) (actual time=0.001..0.001 rows=0 loops=2069)
Sort Key: trec.depth
Sort Method: quicksort Memory: 25kB
-> Nested Loop (cost=0.56..86.10 rows=11 width=296) (actual time=0.000..0.000 rows=0 loops=2069)
-> WorkTable Scan on transactionsteps trec (cost=0.00..0.20 rows=10 width=36) (actual time=0.000..0.000 rows=1 loops=2069)
-> Index Scan using transactions_requestkey_idx on transactions tinner_1 (cost=0.56..8.58 rows=1 width=288) (actual time=0.000..0.000 rows=0 loops=2068)
Index Cond: ((requestkey)::text = (trec.pactid)::text)
-> CTE Scan on transactionsteps (cost=0.00..2.02 rows=101 width=32) (actual time=0.007..0.009 rows=1 loops=2068)
Planning Time: 1.064 ms
Execution Time: 136.530 ms
(37 rows) We can observe the recursive CTE in action with the following request:
Because transaction
|
I have one concern that I'd like to address before we merge this PR. The So, my suggestion is to:
Once we make these changes and merge this PR to CW-D, we can then improve the @sirlensalot Does this sound to you like a good way forward? |
This PR removes the recentTxs tracking from the CW-D server state and always makes a DB query when recent transactions are needed. With the current indexes that we have in place, the recent txs query is very fast to execute (see #119), so there's no need to complicate the server state for it anymore. Note that, in addition to simplifying the codebase, this PR is also needed for the continuations search improvements mentioned [here](#66 (comment)) as well as for the planned work of decoupling the node listener from the HTTP API server.
Last Friday, I've implemented the extensions I've suggested above with this commit. So the responses for the following endpoints now include the Transaction search
|
There was a problem hiding this comment.
Choose a reason for hiding this comment
The reason will be displayed to describe this comment to others. Learn more.
LGTM
This PR extends the transaction endpoints to gather the history of continuation transactions. It extends the following endpoints and adds the
initialCode
andpreviousSteps
fields to them:/txs/tx
/txs/txs
/txs/search
/txs/recent
In addition to attaching this continuation history to the response, this PR also extends the search logic of
/txs/search
so that if the given search term appears in theinitialCode
of a continuation transaction, the search still finds it.This PR supports kadena-io/block-explorer#64 and kadena-io/block-explorer#63