From 88e12d532a44417e8e9084c3f3812cb0019d885d Mon Sep 17 00:00:00 2001 From: Juan Gutierrez de Rojas Date: Fri, 7 Mar 2025 18:19:46 +0100 Subject: [PATCH 1/4] Improve query performance when filtering on code in nbxv1_keypath_info view --- NBXplorer.Tests/DatabaseTests.cs | 2 +- NBXplorer/Backend/Repository.cs | 6 +-- .../DBScripts/025.GetKeyPathInfoFunction.sql | 39 +++++++++++++++++++ NBXplorer/DBScripts/FullSchema.sql | 1 + NBXplorer/NBXplorer.csproj | 1 + 5 files changed, 45 insertions(+), 4 deletions(-) create mode 100644 NBXplorer/DBScripts/025.GetKeyPathInfoFunction.sql diff --git a/NBXplorer.Tests/DatabaseTests.cs b/NBXplorer.Tests/DatabaseTests.cs index 40380dc38..7debf636e 100644 --- a/NBXplorer.Tests/DatabaseTests.cs +++ b/NBXplorer.Tests/DatabaseTests.cs @@ -46,7 +46,7 @@ await Benchmark(conn, "SELECT ts.script, ts.addr, ts.derivation, ts.keypath, ts.redeem FROM ( VALUES ('BTC', 'blah'), ('BTC', 'blah'), ('BTC', 'blah'), ('BTC', 'blah')) r (code, script), " + " LATERAL(" + " SELECT script, addr, descriptor_metadata->>'derivation' derivation, keypath, descriptors_scripts_metadata->>'redeem' redeem, descriptor_metadata->>'blindedAddress' blinded_addr " + - " FROM nbxv1_keypath_info ki " + + " FROM get_nbxv1_keypath_info(@code, r.script) ki " + " WHERE ki.code=r.code AND ki.script=r.script) ts;", 50); await Benchmark(conn, "SELECT o.tx_id, o.idx, o.value, o.script FROM (VALUES ('BTC', 'hash', 5), ('BTC', 'hash', 5), ('BTC', 'hash', 5)) r (code, tx_id, idx) JOIN outs o USING (code, tx_id, idx);", 50); await Benchmark(conn, "SELECT blk_height, tx_id, wu.idx, value, script, nbxv1_get_keypath(d.metadata, ds.idx) AS keypath, d.metadata->>'feature' feature, mempool, input_mempool, seen_at FROM wallets_utxos wu JOIN descriptors_scripts ds USING (code, script) JOIN descriptors d USING (code, descriptor) WHERE code='BTC' AND wallet_id='WHALE' AND immature IS FALSE ", 50); diff --git a/NBXplorer/Backend/Repository.cs b/NBXplorer/Backend/Repository.cs index 70097eedf..8a36b15ce 100644 --- a/NBXplorer/Backend/Repository.cs +++ b/NBXplorer/Backend/Repository.cs @@ -402,7 +402,7 @@ ORDER BY idx LIMIT 1 OFFSET @skip) AS r (script) "; } - public override string GetKeyPathInfoPredicate() => "AND ki.descriptor=@descriptor"; + public override string GetKeyPathInfoPredicate() => "ki.descriptor=@descriptor"; } class ByScriptsQuery : GetKeyInformationsQuery { @@ -451,8 +451,8 @@ w.metadata AS wallet_metadata descriptors_scripts_metadata->>'blindedAddress' blinded_addr, descriptors_scripts_metadata->>'blindingKey' blindingKey, descriptor_metadata->>'feature' feature - FROM nbxv1_keypath_info ki - WHERE ki.code=@code AND ki.script=r.script {query.GetKeyPathInfoPredicate()} + FROM get_nbxv1_keypath_info(@code, r.script) ki + WHERE {query.GetKeyPathInfoPredicate()} ) ts JOIN wallets w USING(wallet_id)", parameters); foreach (var r in rows) diff --git a/NBXplorer/DBScripts/025.GetKeyPathInfoFunction.sql b/NBXplorer/DBScripts/025.GetKeyPathInfoFunction.sql new file mode 100644 index 000000000..eefb21341 --- /dev/null +++ b/NBXplorer/DBScripts/025.GetKeyPathInfoFunction.sql @@ -0,0 +1,39 @@ + +CREATE OR REPLACE FUNCTION get_nbxv1_keypath_info( + input_code TEXT, + input_script TEXT +) +RETURNS TABLE ( + code TEXT, + script TEXT, + addr TEXT, + descriptor_metadata JSONB, + keypath TEXT, + descriptors_scripts_metadata JSONB, + wallet_id TEXT, + idx BIGINT, + used BOOLEAN, + descriptor TEXT +) AS $$ +BEGIN + RETURN QUERY + WITH filtered_wallets AS MATERIALIZED ( + SELECT * FROM wallets_scripts WHERE wallets_scripts.code = input_code AND wallets_scripts.script = input_script + ) + SELECT ws.code, + ws.script, + s.addr, + d.metadata AS descriptor_metadata, + nbxv1_get_keypath(d.metadata, ds.idx) AS keypath, + ds.metadata AS descriptors_scripts_metadata, + ws.wallet_id, + ds.idx, + ds.used, + d.descriptor + FROM ((filtered_wallets ws + JOIN scripts s ON (((s.code = ws.code) AND (s.script = ws.script)))) + LEFT JOIN ((wallets_descriptors wd + JOIN descriptors_scripts ds ON (((ds.code = wd.code) AND (ds.descriptor = wd.descriptor)))) + JOIN descriptors d ON (((d.code = ds.code) AND (d.descriptor = ds.descriptor)))) ON (((wd.wallet_id = ws.wallet_id) AND (wd.code = ws.code) AND (ds.script = ws.script)))); +END; +$$ LANGUAGE plpgsql; \ No newline at end of file diff --git a/NBXplorer/DBScripts/FullSchema.sql b/NBXplorer/DBScripts/FullSchema.sql index 34ced97e0..c355ab102 100644 --- a/NBXplorer/DBScripts/FullSchema.sql +++ b/NBXplorer/DBScripts/FullSchema.sql @@ -1391,6 +1391,7 @@ INSERT INTO nbxv1_migrations VALUES ('021.KeyPathInfoReturnsWalletId'); INSERT INTO nbxv1_migrations VALUES ('022.WalletsWalletsParentIdIndex'); INSERT INTO nbxv1_migrations VALUES ('023.KeyPathInfoReturnsIndex'); INSERT INTO nbxv1_migrations VALUES ('024.TrackedTxsReturnsFeature'); +INSERT INTO nbxv1_migrations VALUES ('025.GetKeyPathInfoFunction'); ALTER TABLE ONLY nbxv1_migrations ADD CONSTRAINT nbxv1_migrations_pkey PRIMARY KEY (script_name); \ No newline at end of file diff --git a/NBXplorer/NBXplorer.csproj b/NBXplorer/NBXplorer.csproj index fda4312a8..2b2d40abe 100644 --- a/NBXplorer/NBXplorer.csproj +++ b/NBXplorer/NBXplorer.csproj @@ -29,6 +29,7 @@ + From 67af014c0d4b6bda8088959d25d58088ceafa07d Mon Sep 17 00:00:00 2001 From: Juan Gutierrez de Rojas Date: Tue, 11 Mar 2025 10:40:14 +0100 Subject: [PATCH 2/4] Simplifiedget_nbxv1_keypath_info function --- NBXplorer/DBScripts/025.GetKeyPathInfoFunction.sql | 5 +---- 1 file changed, 1 insertion(+), 4 deletions(-) diff --git a/NBXplorer/DBScripts/025.GetKeyPathInfoFunction.sql b/NBXplorer/DBScripts/025.GetKeyPathInfoFunction.sql index eefb21341..609273b72 100644 --- a/NBXplorer/DBScripts/025.GetKeyPathInfoFunction.sql +++ b/NBXplorer/DBScripts/025.GetKeyPathInfoFunction.sql @@ -17,9 +17,6 @@ RETURNS TABLE ( ) AS $$ BEGIN RETURN QUERY - WITH filtered_wallets AS MATERIALIZED ( - SELECT * FROM wallets_scripts WHERE wallets_scripts.code = input_code AND wallets_scripts.script = input_script - ) SELECT ws.code, ws.script, s.addr, @@ -30,7 +27,7 @@ BEGIN ds.idx, ds.used, d.descriptor - FROM ((filtered_wallets ws + FROM (((SELECT * FROM wallets_scripts WHERE wallets_scripts.code = input_code AND wallets_scripts.script = input_script) ws JOIN scripts s ON (((s.code = ws.code) AND (s.script = ws.script)))) LEFT JOIN ((wallets_descriptors wd JOIN descriptors_scripts ds ON (((ds.code = wd.code) AND (ds.descriptor = wd.descriptor)))) From a7c8db05975cd8c477e3528a9d35f337b3a98919 Mon Sep 17 00:00:00 2001 From: Juan Gutierrez de Rojas Date: Tue, 11 Mar 2025 11:04:24 +0100 Subject: [PATCH 3/4] minor change to handle GetKeyPathInfoPredicate correctly --- NBXplorer/Backend/Repository.cs | 4 ++-- 1 file changed, 2 insertions(+), 2 deletions(-) diff --git a/NBXplorer/Backend/Repository.cs b/NBXplorer/Backend/Repository.cs index 8a36b15ce..8300ffa5c 100644 --- a/NBXplorer/Backend/Repository.cs +++ b/NBXplorer/Backend/Repository.cs @@ -402,7 +402,7 @@ ORDER BY idx LIMIT 1 OFFSET @skip) AS r (script) "; } - public override string GetKeyPathInfoPredicate() => "ki.descriptor=@descriptor"; + public override string GetKeyPathInfoPredicate() => "WHERE ki.descriptor=@descriptor"; } class ByScriptsQuery : GetKeyInformationsQuery { @@ -452,7 +452,7 @@ w.metadata AS wallet_metadata descriptors_scripts_metadata->>'blindingKey' blindingKey, descriptor_metadata->>'feature' feature FROM get_nbxv1_keypath_info(@code, r.script) ki - WHERE {query.GetKeyPathInfoPredicate()} + {query.GetKeyPathInfoPredicate()} ) ts JOIN wallets w USING(wallet_id)", parameters); foreach (var r in rows) From ea1899f4958788283307f12362adfd79511dd3af Mon Sep 17 00:00:00 2001 From: Juan Gutierrez de Rojas Date: Tue, 11 Mar 2025 11:39:16 +0100 Subject: [PATCH 4/4] minor ammendment on tests (remove where clause) --- NBXplorer.Tests/DatabaseTests.cs | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/NBXplorer.Tests/DatabaseTests.cs b/NBXplorer.Tests/DatabaseTests.cs index 7debf636e..971c48aef 100644 --- a/NBXplorer.Tests/DatabaseTests.cs +++ b/NBXplorer.Tests/DatabaseTests.cs @@ -47,7 +47,7 @@ await Benchmark(conn, " LATERAL(" + " SELECT script, addr, descriptor_metadata->>'derivation' derivation, keypath, descriptors_scripts_metadata->>'redeem' redeem, descriptor_metadata->>'blindedAddress' blinded_addr " + " FROM get_nbxv1_keypath_info(@code, r.script) ki " + - " WHERE ki.code=r.code AND ki.script=r.script) ts;", 50); + " ) ts;", 50); await Benchmark(conn, "SELECT o.tx_id, o.idx, o.value, o.script FROM (VALUES ('BTC', 'hash', 5), ('BTC', 'hash', 5), ('BTC', 'hash', 5)) r (code, tx_id, idx) JOIN outs o USING (code, tx_id, idx);", 50); await Benchmark(conn, "SELECT blk_height, tx_id, wu.idx, value, script, nbxv1_get_keypath(d.metadata, ds.idx) AS keypath, d.metadata->>'feature' feature, mempool, input_mempool, seen_at FROM wallets_utxos wu JOIN descriptors_scripts ds USING (code, script) JOIN descriptors d USING (code, descriptor) WHERE code='BTC' AND wallet_id='WHALE' AND immature IS FALSE ", 50); await Benchmark(conn, "SELECT * FROM get_wallets_histogram('WHALE', 'BTC', '', '2022-01-01'::timestamptz, '2022-02-01'::timestamptz, interval '1 day');", 50);