From b0702f899e743fced0450f8b64500d6c9fb422ad Mon Sep 17 00:00:00 2001 From: Enzo Cioppettini Date: Thu, 29 Feb 2024 02:02:31 -0300 Subject: [PATCH] optimize slot filter tx filter query --- indexer/entity/src/block.rs | 1 + indexer/migration/src/lib.rs | 2 + ...240229_000019_add_block_tx_count_column.rs | 36 ++++++++ indexer/tasks/src/multiera/multiera_block.rs | 1 + .../models/block/sqlBlockLatest.queries.ts | 1 + .../slotBoundsPagination.queries.ts | 82 ++++++++++++------- .../pagination/slotBoundsPagination.sql | 82 ++++++++++++------- 7 files changed, 147 insertions(+), 58 deletions(-) create mode 100644 indexer/migration/src/m20240229_000019_add_block_tx_count_column.rs diff --git a/indexer/entity/src/block.rs b/indexer/entity/src/block.rs index 000219a8..3516c0c8 100644 --- a/indexer/entity/src/block.rs +++ b/indexer/entity/src/block.rs @@ -12,6 +12,7 @@ pub struct Model { pub epoch: i32, pub slot: i32, pub payload: Option>, + pub tx_count: i32, } #[derive(Copy, Clone, Debug, DeriveRelation, EnumIter)] diff --git a/indexer/migration/src/lib.rs b/indexer/migration/src/lib.rs index 11f27ea8..fa57a67c 100644 --- a/indexer/migration/src/lib.rs +++ b/indexer/migration/src/lib.rs @@ -20,6 +20,7 @@ mod m20230223_000015_modify_block_table; mod m20230927_000016_create_stake_delegation_table; mod m20231025_000017_projected_nft; mod m20231220_000018_asset_utxo_table; +mod m20240229_000019_add_block_tx_count_column; pub struct Migrator; @@ -47,6 +48,7 @@ impl MigratorTrait for Migrator { Box::new(m20230927_000016_create_stake_delegation_table::Migration), Box::new(m20231025_000017_projected_nft::Migration), Box::new(m20231220_000018_asset_utxo_table::Migration), + Box::new(m20240229_000019_add_block_tx_count_column::Migration), ] } } diff --git a/indexer/migration/src/m20240229_000019_add_block_tx_count_column.rs b/indexer/migration/src/m20240229_000019_add_block_tx_count_column.rs new file mode 100644 index 00000000..eeae529f --- /dev/null +++ b/indexer/migration/src/m20240229_000019_add_block_tx_count_column.rs @@ -0,0 +1,36 @@ +use sea_schema::migration::prelude::*; + +use entity::block::*; + +pub struct Migration; + +impl MigrationName for Migration { + fn name(&self) -> &str { + "m20240229_000019_add_block_tx_count_column" + } +} + +#[async_trait::async_trait] +impl MigrationTrait for Migration { + async fn up(&self, manager: &SchemaManager) -> Result<(), DbErr> { + manager + .alter_table( + Table::alter() + .table(Entity) + .add_column(ColumnDef::new(Column::TxCount).integer()) + .to_owned(), + ) + .await + } + + async fn down(&self, manager: &SchemaManager) -> Result<(), DbErr> { + manager + .alter_table( + Table::alter() + .table(Entity) + .drop_column(Column::TxCount) + .to_owned(), + ) + .await + } +} diff --git a/indexer/tasks/src/multiera/multiera_block.rs b/indexer/tasks/src/multiera/multiera_block.rs index 5f74d611..b5c390ff 100644 --- a/indexer/tasks/src/multiera/multiera_block.rs +++ b/indexer/tasks/src/multiera/multiera_block.rs @@ -49,6 +49,7 @@ async fn handle_block( epoch: Set(block.2.epoch.unwrap() as i32), slot: Set(block.1.header().slot() as i32), payload: Set(Some(block_payload)), + tx_count: Set(block.1.txs().len() as i32), ..Default::default() }; block.insert(db_tx).await diff --git a/webserver/server/app/models/block/sqlBlockLatest.queries.ts b/webserver/server/app/models/block/sqlBlockLatest.queries.ts index b072f9b9..163271c6 100644 --- a/webserver/server/app/models/block/sqlBlockLatest.queries.ts +++ b/webserver/server/app/models/block/sqlBlockLatest.queries.ts @@ -17,6 +17,7 @@ export interface ISqlBlockLatestResult { id: number; payload: Buffer | null; slot: number; + tx_count: number | null; } /** 'SqlBlockLatest' query type */ diff --git a/webserver/server/app/models/pagination/slotBoundsPagination.queries.ts b/webserver/server/app/models/pagination/slotBoundsPagination.queries.ts index eade5b78..0d903eaa 100644 --- a/webserver/server/app/models/pagination/slotBoundsPagination.queries.ts +++ b/webserver/server/app/models/pagination/slotBoundsPagination.queries.ts @@ -21,40 +21,64 @@ export interface ISlotBoundsPaginationQuery { result: ISlotBoundsPaginationResult; } -const slotBoundsPaginationIR: any = {"usedParamSet":{"low":true,"high":true},"params":[{"name":"low","required":true,"transform":{"type":"scalar"},"locs":[{"a":281,"b":285}]},{"name":"high","required":true,"transform":{"type":"scalar"},"locs":[{"a":668,"b":673}]}],"statement":"WITH\nmin_hash AS\n(\n SELECT COALESCE(\"Transaction\".id, -1) AS min_tx_id,\n slot AS min_slot\n FROM \"Transaction\"\n JOIN \"Block\"\n ON \"Block\".id = \"Transaction\".block_id\n WHERE slot <= :low!\n ORDER BY \"Block\".id DESC,\n \"Transaction\".id DESC\n LIMIT 1\n),\nmax_hash AS\n(\n SELECT slot AS max_slot,\n COALESCE(Max(\"Transaction\".id), -2) AS max_tx_id\n FROM \"Transaction\"\n JOIN \"Block\"\n ON \"Transaction\".block_id = \"Block\".id\n WHERE slot <= :high!\n GROUP BY \"Block\".id\n ORDER BY \"Block\".id DESC\n LIMIT 1\n)\nSELECT *\nFROM min_hash\nLEFT JOIN max_hash\nON 1 = 1"}; +const slotBoundsPaginationIR: any = {"usedParamSet":{"low":true,"high":true},"params":[{"name":"low","required":true,"transform":{"type":"scalar"},"locs":[{"a":155,"b":159}]},{"name":"high","required":true,"transform":{"type":"scalar"},"locs":[{"a":409,"b":414}]}],"statement":"WITH\n low_block AS (\n SELECT\n \"Block\".id,\n \"Block\".slot\n FROM\n \"Block\"\n WHERE\n slot <= :low! AND tx_count > 0\n ORDER BY\n \"Block\".id DESC\n LIMIT\n 1\n ),\n high_block AS (\n SELECT\n \"Block\".id,\n \"Block\".slot\n FROM\n \"Block\"\n WHERE\n slot <= :high! AND tx_count > 0\n ORDER BY\n \"Block\".id DESC\n LIMIT\n 1\n ),\n min_hash AS (\n SELECT\n COALESCE(MAX(\"Transaction\".id), -1) AS min_tx_id,\n slot AS min_slot\n FROM\n \"Transaction\"\n JOIN low_block ON \"Transaction\".block_id = low_block.id\n GROUP BY\n low_block.slot\n LIMIT\n 1\n ),\n max_hash AS (\n SELECT\n COALESCE(MAX(\"Transaction\".id), -2) AS max_tx_id,\n slot AS max_slot\n FROM\n \"Transaction\"\n JOIN high_block ON \"Transaction\".block_id = high_block.id\n GROUP BY\n high_block.slot\n )\nSELECT\n *\nFROM min_hash\nLEFT JOIN max_hash ON 1 = 1"}; /** * Query generated from SQL: * ``` * WITH - * min_hash AS - * ( - * SELECT COALESCE("Transaction".id, -1) AS min_tx_id, - * slot AS min_slot - * FROM "Transaction" - * JOIN "Block" - * ON "Block".id = "Transaction".block_id - * WHERE slot <= :low! - * ORDER BY "Block".id DESC, - * "Transaction".id DESC - * LIMIT 1 - * ), - * max_hash AS - * ( - * SELECT slot AS max_slot, - * COALESCE(Max("Transaction".id), -2) AS max_tx_id - * FROM "Transaction" - * JOIN "Block" - * ON "Transaction".block_id = "Block".id - * WHERE slot <= :high! - * GROUP BY "Block".id - * ORDER BY "Block".id DESC - * LIMIT 1 - * ) - * SELECT * - * FROM min_hash - * LEFT JOIN max_hash - * ON 1 = 1 + * low_block AS ( + * SELECT + * "Block".id, + * "Block".slot + * FROM + * "Block" + * WHERE + * slot <= :low! AND tx_count > 0 + * ORDER BY + * "Block".id DESC + * LIMIT + * 1 + * ), + * high_block AS ( + * SELECT + * "Block".id, + * "Block".slot + * FROM + * "Block" + * WHERE + * slot <= :high! AND tx_count > 0 + * ORDER BY + * "Block".id DESC + * LIMIT + * 1 + * ), + * min_hash AS ( + * SELECT + * COALESCE(MAX("Transaction".id), -1) AS min_tx_id, + * slot AS min_slot + * FROM + * "Transaction" + * JOIN low_block ON "Transaction".block_id = low_block.id + * GROUP BY + * low_block.slot + * LIMIT + * 1 + * ), + * max_hash AS ( + * SELECT + * COALESCE(MAX("Transaction".id), -2) AS max_tx_id, + * slot AS max_slot + * FROM + * "Transaction" + * JOIN high_block ON "Transaction".block_id = high_block.id + * GROUP BY + * high_block.slot + * ) + * SELECT + * * + * FROM min_hash + * LEFT JOIN max_hash ON 1 = 1 * ``` */ export const slotBoundsPagination = new PreparedQuery(slotBoundsPaginationIR); diff --git a/webserver/server/app/models/pagination/slotBoundsPagination.sql b/webserver/server/app/models/pagination/slotBoundsPagination.sql index e4a795bb..a8c3a69b 100644 --- a/webserver/server/app/models/pagination/slotBoundsPagination.sql +++ b/webserver/server/app/models/pagination/slotBoundsPagination.sql @@ -1,30 +1,54 @@ - /* @name slotBoundsPagination */ +/* @name slotBoundsPagination */ WITH -min_hash AS -( - SELECT COALESCE("Transaction".id, -1) AS min_tx_id, - slot AS min_slot - FROM "Transaction" - JOIN "Block" - ON "Block".id = "Transaction".block_id - WHERE slot <= :low! - ORDER BY "Block".id DESC, - "Transaction".id DESC - LIMIT 1 -), -max_hash AS -( - SELECT slot AS max_slot, - COALESCE(Max("Transaction".id), -2) AS max_tx_id - FROM "Transaction" - JOIN "Block" - ON "Transaction".block_id = "Block".id - WHERE slot <= :high! - GROUP BY "Block".id - ORDER BY "Block".id DESC - LIMIT 1 -) -SELECT * -FROM min_hash -LEFT JOIN max_hash -ON 1 = 1; \ No newline at end of file + low_block AS ( + SELECT + "Block".id, + "Block".slot + FROM + "Block" + WHERE + slot <= :low! AND tx_count > 0 + ORDER BY + "Block".id DESC + LIMIT + 1 + ), + high_block AS ( + SELECT + "Block".id, + "Block".slot + FROM + "Block" + WHERE + slot <= :high! AND tx_count > 0 + ORDER BY + "Block".id DESC + LIMIT + 1 + ), + min_hash AS ( + SELECT + COALESCE(MAX("Transaction".id), -1) AS min_tx_id, + slot AS min_slot + FROM + "Transaction" + JOIN low_block ON "Transaction".block_id = low_block.id + GROUP BY + low_block.slot + LIMIT + 1 + ), + max_hash AS ( + SELECT + COALESCE(MAX("Transaction".id), -2) AS max_tx_id, + slot AS max_slot + FROM + "Transaction" + JOIN high_block ON "Transaction".block_id = high_block.id + GROUP BY + high_block.slot + ) +SELECT + * +FROM min_hash +LEFT JOIN max_hash ON 1 = 1; \ No newline at end of file