@@ -305,7 +305,8 @@ impl<'a, 'b> QueryFromConnection<'a, 'b> {
305
305
ON CONFLICT (nft_id, block_height) DO UPDATE
306
306
SET
307
307
ticker = EXCLUDED.ticker,
308
- owner = EXCLUDED.owner;"# ,
308
+ owner = EXCLUDED.owner;
309
+ "# ,
309
310
& [ & token_id. encode ( ) , & height, & owner. map ( |o| o. as_object ( ) . encode ( ) ) ] ,
310
311
)
311
312
. await
@@ -553,10 +554,10 @@ impl<'a, 'b> QueryFromConnection<'a, 'b> {
553
554
. await ?;
554
555
555
556
// 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 ;" )
557
558
. await ?;
558
559
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 ;" ,
560
561
)
561
562
. await ?;
562
563
@@ -575,7 +576,7 @@ impl<'a, 'b> QueryFromConnection<'a, 'b> {
575
576
block_height bigint NOT NULL,
576
577
coin_or_token_id bytea NOT NULL,
577
578
amount bytea NOT NULL,
578
- PRIMARY KEY (address, block_height, coin_or_token_id )
579
+ PRIMARY KEY (address, coin_or_token_id, block_height )
579
580
);" ,
580
581
)
581
582
. await ?;
@@ -586,7 +587,7 @@ impl<'a, 'b> QueryFromConnection<'a, 'b> {
586
587
block_height bigint NOT NULL,
587
588
coin_or_token_id bytea NOT NULL,
588
589
amount bytea NOT NULL,
589
- PRIMARY KEY (address, block_height, coin_or_token_id )
590
+ PRIMARY KEY (address, coin_or_token_id, block_height )
590
591
);" ,
591
592
)
592
593
. await ?;
@@ -613,6 +614,10 @@ impl<'a, 'b> QueryFromConnection<'a, 'b> {
613
614
)
614
615
. await ?;
615
616
617
+ // index for reorgs
618
+ self . just_execute ( "CREATE INDEX utxo_block_height ON ml.utxo (block_height DESC);" )
619
+ . await ?;
620
+
616
621
self . just_execute (
617
622
"CREATE TABLE ml.locked_utxo (
618
623
outpoint bytea NOT NULL,
@@ -645,6 +650,12 @@ impl<'a, 'b> QueryFromConnection<'a, 'b> {
645
650
)
646
651
. await ?;
647
652
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
+
648
659
self . just_execute (
649
660
"CREATE TABLE ml.delegations (
650
661
delegation_id TEXT NOT NULL,
@@ -661,7 +672,13 @@ impl<'a, 'b> QueryFromConnection<'a, 'b> {
661
672
662
673
// index when searching for delegations by address
663
674
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);"
665
682
)
666
683
. await ?;
667
684
@@ -711,6 +728,12 @@ impl<'a, 'b> QueryFromConnection<'a, 'b> {
711
728
)
712
729
. await ?;
713
730
731
+ // index for reorgs
732
+ self . just_execute (
733
+ "CREATE INDEX statistics_block_height ON ml.statistics (block_height DESC);" ,
734
+ )
735
+ . await ?;
736
+
714
737
self . just_execute (
715
738
"CREATE TABLE ml.orders (
716
739
order_id TEXT NOT NULL,
@@ -957,10 +980,12 @@ impl<'a, 'b> QueryFromConnection<'a, 'b> {
957
980
let row = self
958
981
. tx
959
982
. 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
961
985
FROM ml.delegations
962
986
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;
964
989
"# ,
965
990
& [ & delegation_id. as_str ( ) ] ,
966
991
)
@@ -1020,13 +1045,16 @@ impl<'a, 'b> QueryFromConnection<'a, 'b> {
1020
1045
let rows = self
1021
1046
. tx
1022
1047
. 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
1026
1051
FROM ml.delegations
1027
1052
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;
1030
1058
"# ,
1031
1059
& [ & address. encode ( ) ] ,
1032
1060
)
@@ -1096,6 +1124,33 @@ impl<'a, 'b> QueryFromConnection<'a, 'b> {
1096
1124
let delegation_id = Address :: new ( chain_config, delegation_id)
1097
1125
. map_err ( |_| ApiServerStorageError :: AddressableError ) ?;
1098
1126
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
+
1099
1154
self . tx
1100
1155
. execute (
1101
1156
r#"
@@ -1167,7 +1222,8 @@ impl<'a, 'b> QueryFromConnection<'a, 'b> {
1167
1222
let row = self
1168
1223
. tx
1169
1224
. query_one (
1170
- r#"SELECT COUNT(*)
1225
+ r#"
1226
+ SELECT COUNT(*)
1171
1227
FROM ml.pool_data
1172
1228
WHERE pool_id = $1 AND block_height BETWEEN $2 AND $3
1173
1229
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> {
1193
1249
. map_err ( |_| ApiServerStorageError :: AddressableError ) ?;
1194
1250
self . tx
1195
1251
. 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
1197
1255
FROM ml.delegations
1198
1256
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;
1203
1262
"# ,
1204
1263
& [ & pool_id_str. as_str ( ) ] ,
1205
1264
)
@@ -2247,10 +2306,12 @@ impl<'a, 'b> QueryFromConnection<'a, 'b> {
2247
2306
let row = self
2248
2307
. tx
2249
2308
. 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
2251
2311
FROM ml.orders
2252
2312
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;
2254
2315
"# ,
2255
2316
& [ & order_id_addr. as_str ( ) ] ,
2256
2317
)
0 commit comments