Skip to content

Commit 6e25173

Browse files
committed
optimize postgresql queries for API Server scanner
- copy/reinsert all delegations for a common pool each time any one of them changes (stake/withdraw) so that we can efficiently retrieve all the latest data for each delegation of a pool
1 parent 6f96a0c commit 6e25173

File tree

2 files changed

+83
-22
lines changed

2 files changed

+83
-22
lines changed

Diff for: api-server/api-server-common/src/storage/impls/mod.rs

+1-1
Original file line numberDiff line numberDiff line change
@@ -13,7 +13,7 @@
1313
// See the License for the specific language governing permissions and
1414
// limitations under the License.
1515

16-
pub const CURRENT_STORAGE_VERSION: u32 = 19;
16+
pub const CURRENT_STORAGE_VERSION: u32 = 20;
1717

1818
pub mod in_memory;
1919
pub mod postgres;

Diff for: api-server/api-server-common/src/storage/impls/postgres/queries.rs

+82-21
Original file line numberDiff line numberDiff line change
@@ -305,7 +305,8 @@ impl<'a, 'b> QueryFromConnection<'a, 'b> {
305305
ON CONFLICT (nft_id, block_height) DO UPDATE
306306
SET
307307
ticker = EXCLUDED.ticker,
308-
owner = EXCLUDED.owner;"#,
308+
owner = EXCLUDED.owner;
309+
"#,
309310
&[&token_id.encode(), &height, &owner.map(|o| o.as_object().encode())],
310311
)
311312
.await
@@ -553,10 +554,10 @@ impl<'a, 'b> QueryFromConnection<'a, 'b> {
553554
.await?;
554555

555556
// Add ml.blocks indexes on height and timestamp
556-
self.just_execute("CREATE INDEX blocks_block_height_index ON ml.blocks (block_height);")
557+
self.just_execute("CREATE INDEX blocks_block_height_index ON ml.blocks (block_height) WHERE block_height IS NOT NULL;")
557558
.await?;
558559
self.just_execute(
559-
"CREATE INDEX blocks_block_timestamp_index ON ml.blocks (block_timestamp);",
560+
"CREATE INDEX blocks_block_timestamp_index ON ml.blocks (block_timestamp) WHERE block_height IS NOT NULL;",
560561
)
561562
.await?;
562563

@@ -575,7 +576,7 @@ impl<'a, 'b> QueryFromConnection<'a, 'b> {
575576
block_height bigint NOT NULL,
576577
coin_or_token_id bytea NOT NULL,
577578
amount bytea NOT NULL,
578-
PRIMARY KEY (address, block_height, coin_or_token_id)
579+
PRIMARY KEY (address, coin_or_token_id, block_height)
579580
);",
580581
)
581582
.await?;
@@ -586,7 +587,7 @@ impl<'a, 'b> QueryFromConnection<'a, 'b> {
586587
block_height bigint NOT NULL,
587588
coin_or_token_id bytea NOT NULL,
588589
amount bytea NOT NULL,
589-
PRIMARY KEY (address, block_height, coin_or_token_id)
590+
PRIMARY KEY (address, coin_or_token_id, block_height)
590591
);",
591592
)
592593
.await?;
@@ -613,6 +614,10 @@ impl<'a, 'b> QueryFromConnection<'a, 'b> {
613614
)
614615
.await?;
615616

617+
// index for reorgs
618+
self.just_execute("CREATE INDEX utxo_block_height ON ml.utxo (block_height DESC);")
619+
.await?;
620+
616621
self.just_execute(
617622
"CREATE TABLE ml.locked_utxo (
618623
outpoint bytea NOT NULL,
@@ -645,6 +650,12 @@ impl<'a, 'b> QueryFromConnection<'a, 'b> {
645650
)
646651
.await?;
647652

653+
// index when searching for number of minted blocks
654+
self.just_execute(
655+
"CREATE INDEX pool_data_block_height ON ml.pool_data (pool_id, block_height DESC) WHERE (staker_balance::NUMERIC != 0);",
656+
)
657+
.await?;
658+
648659
self.just_execute(
649660
"CREATE TABLE ml.delegations (
650661
delegation_id TEXT NOT NULL,
@@ -661,7 +672,13 @@ impl<'a, 'b> QueryFromConnection<'a, 'b> {
661672

662673
// index when searching for delegations by address
663674
self.just_execute(
664-
"CREATE INDEX delegations_spend_destination_index ON ml.delegations (spend_destination);",
675+
"CREATE INDEX delegations_spend_destination_index ON ml.delegations (spend_destination, block_height DESC);",
676+
)
677+
.await?;
678+
679+
// index when searching for a specific pool's latest delegations
680+
self.just_execute(
681+
"CREATE INDEX latest_pool_delegations_index ON ml.delegations (pool_id, block_height DESC);"
665682
)
666683
.await?;
667684

@@ -711,6 +728,12 @@ impl<'a, 'b> QueryFromConnection<'a, 'b> {
711728
)
712729
.await?;
713730

731+
// index for reorgs
732+
self.just_execute(
733+
"CREATE INDEX statistics_block_height ON ml.statistics (block_height DESC);",
734+
)
735+
.await?;
736+
714737
self.just_execute(
715738
"CREATE TABLE ml.orders (
716739
order_id TEXT NOT NULL,
@@ -957,10 +980,12 @@ impl<'a, 'b> QueryFromConnection<'a, 'b> {
957980
let row = self
958981
.tx
959982
.query_opt(
960-
r#"SELECT pool_id, balance, spend_destination, next_nonce, creation_block_height
983+
r#"
984+
SELECT pool_id, balance, spend_destination, next_nonce, creation_block_height
961985
FROM ml.delegations
962986
WHERE delegation_id = $1
963-
AND block_height = (SELECT MAX(block_height) FROM ml.delegations WHERE delegation_id = $1);
987+
ORDER BY block_height DESC
988+
LIMIT 1;
964989
"#,
965990
&[&delegation_id.as_str()],
966991
)
@@ -1020,13 +1045,16 @@ impl<'a, 'b> QueryFromConnection<'a, 'b> {
10201045
let rows = self
10211046
.tx
10221047
.query(
1023-
r#"SELECT delegation_id, pool_id, balance, spend_destination, next_nonce, creation_block_height
1024-
FROM (
1025-
SELECT delegation_id, pool_id, balance, spend_destination, next_nonce, creation_block_height, ROW_NUMBER() OVER(PARTITION BY delegation_id ORDER BY block_height DESC) as newest
1048+
r#"
1049+
WITH latest_block_height AS (
1050+
SELECT MAX(block_height) AS max_block_height
10261051
FROM ml.delegations
10271052
WHERE spend_destination = $1
1028-
) AS sub
1029-
WHERE newest = 1;
1053+
)
1054+
SELECT delegation_id, pool_id, balance, spend_destination, next_nonce, creation_block_height
1055+
FROM ml.delegations
1056+
JOIN latest_block_height lb ON block_height = lb.max_block_height
1057+
WHERE spend_destination = $1;
10301058
"#,
10311059
&[&address.encode()],
10321060
)
@@ -1096,6 +1124,33 @@ impl<'a, 'b> QueryFromConnection<'a, 'b> {
10961124
let delegation_id = Address::new(chain_config, delegation_id)
10971125
.map_err(|_| ApiServerStorageError::AddressableError)?;
10981126

1127+
// copy all delegations for the same pool_id as the new delegation with the new
1128+
// block_height, and ignore duplicates
1129+
self.tx.execute(
1130+
r#"
1131+
WITH latest_block_height AS (
1132+
SELECT MAX(block_height) AS max_block_height
1133+
FROM ml.delegations
1134+
WHERE pool_id = $2
1135+
)
1136+
INSERT INTO ml.delegations (delegation_id, block_height, creation_block_height, pool_id, balance, next_nonce, spend_destination)
1137+
SELECT delegation_id,
1138+
$1,
1139+
creation_block_height,
1140+
pool_id,
1141+
balance,
1142+
next_nonce,
1143+
spend_destination
1144+
FROM ml.delegations
1145+
WHERE pool_id = $2
1146+
AND block_height = (SELECT max_block_height FROM latest_block_height)
1147+
ON CONFLICT DO NOTHING;
1148+
"#,
1149+
&[&height, &pool_id.as_str()]
1150+
)
1151+
.await
1152+
.map_err(|e| ApiServerStorageError::LowLevelStorageError(e.to_string()))?;
1153+
10991154
self.tx
11001155
.execute(
11011156
r#"
@@ -1167,7 +1222,8 @@ impl<'a, 'b> QueryFromConnection<'a, 'b> {
11671222
let row = self
11681223
.tx
11691224
.query_one(
1170-
r#"SELECT COUNT(*)
1225+
r#"
1226+
SELECT COUNT(*)
11711227
FROM ml.pool_data
11721228
WHERE pool_id = $1 AND block_height BETWEEN $2 AND $3
11731229
AND block_height != (SELECT COALESCE(MIN(block_height), 0) FROM ml.pool_data WHERE pool_id = $1)
@@ -1193,13 +1249,16 @@ impl<'a, 'b> QueryFromConnection<'a, 'b> {
11931249
.map_err(|_| ApiServerStorageError::AddressableError)?;
11941250
self.tx
11951251
.query(
1196-
r#"SELECT delegation_id, balance, spend_destination, next_nonce, creation_block_height
1252+
r#"
1253+
WITH latest_block_height AS (
1254+
SELECT MAX(block_height) AS max_block_height
11971255
FROM ml.delegations
11981256
WHERE pool_id = $1
1199-
AND (delegation_id, block_height) in (SELECT delegation_id, MAX(block_height)
1200-
FROM ml.delegations
1201-
WHERE pool_id = $1
1202-
GROUP BY delegation_id)
1257+
)
1258+
SELECT d.delegation_id, d.balance, d.spend_destination, d.next_nonce, d.creation_block_height
1259+
FROM ml.delegations d
1260+
JOIN latest_block_height lb ON d.block_height = lb.max_block_height
1261+
WHERE d.pool_id = $1;
12031262
"#,
12041263
&[&pool_id_str.as_str()],
12051264
)
@@ -2247,10 +2306,12 @@ impl<'a, 'b> QueryFromConnection<'a, 'b> {
22472306
let row = self
22482307
.tx
22492308
.query_opt(
2250-
r#"SELECT order_id, initially_asked, ask_balance, ask_currency, initially_given, give_balance, give_currency, conclude_destination, next_nonce, creation_block_height
2309+
r#"
2310+
SELECT order_id, initially_asked, ask_balance, ask_currency, initially_given, give_balance, give_currency, conclude_destination, next_nonce, creation_block_height
22512311
FROM ml.orders
22522312
WHERE order_id = $1
2253-
AND block_height = (SELECT MAX(block_height) FROM ml.orders WHERE order_id = $1);
2313+
ORDER BY block_height DESC
2314+
LIMIT 1;
22542315
"#,
22552316
&[&order_id_addr.as_str()],
22562317
)

0 commit comments

Comments
 (0)