From be789ff55ad6f94caf0fe8ee321479dadb98fb47 Mon Sep 17 00:00:00 2001 From: Dusan Stanivukovic Date: Wed, 11 Sep 2024 13:48:09 +0200 Subject: [PATCH] Improve performance of fee policies and fees (#2970) # Description Apparently, Postgresql optimal way of matching data against large input is using INNER JOIN: https://stackoverflow.com/questions/24647503/performance-issue-in-update-query So, the benchmark for the problematic [order](https://aws-es.cow.fi/_dashboards/app/data-explorer/discover#?_a=(discover:(columns:!(log,log_level),isDirty:!f,sort:!()),metadata:(indexPattern:'86e4a5a0-4e4b-11ef-85c5-3946a99ed1a7',view:discover))&_g=(filters:!(),refreshInterval:(pause:!t,value:0),time:(from:'2024-09-10T11:46:17.292Z',to:'2024-09-10T13:48:25.292Z'))&_q=(filters:!(),query:(language:kuery,query:'log:%20%229649c7739ced0ea0fb0ecd8c41c81100%22'))) on arbitrum is: 1. Current implementation: ~1.5s - 3s 2. WHERE .. IN: same as (1) 3. INNER JOIN: 100ms-300ms 4. grouping by order_uid: same as (3) That said, I chose INNER JOIN as the cleanest solution in terms of code. Total time spent to get trades should be at most 500ms after this change (150ms on average). ## How to test Tested locally against arbitrum read replica. Also tested with a regular order that has only one trade and this code does not degrade performance for that case. --- crates/database/src/fee_policies.rs | 14 +++++++------- crates/database/src/order_execution.rs | 13 ++++++++----- 2 files changed, 15 insertions(+), 12 deletions(-) diff --git a/crates/database/src/fee_policies.rs b/crates/database/src/fee_policies.rs index 9679a6c3f0..2dc2b796ba 100644 --- a/crates/database/src/fee_policies.rs +++ b/crates/database/src/fee_policies.rs @@ -63,22 +63,22 @@ pub async fn fetch_all( return Ok(HashMap::new()); } - let mut query_builder = QueryBuilder::new("SELECT * FROM fee_policies WHERE "); + let mut query_builder = QueryBuilder::new("SELECT * FROM fee_policies fp INNER JOIN (VALUES "); for (i, (auction_id, order_uid)) in keys_filter.iter().enumerate() { if i > 0 { - query_builder.push(" OR "); + query_builder.push(", "); } query_builder .push("(") - .push("auction_id = ") - .push_bind(auction_id) - .push(" AND ") - .push("order_uid = ") .push_bind(order_uid) + .push(", ") + .push_bind(auction_id) .push(")"); } + query_builder.push(") AS vals(order_uid, auction_id) "); + query_builder.push("ON (fp.order_uid, fp.auction_id) = (vals.order_uid, vals.auction_id) "); - query_builder.push(" ORDER BY application_order"); + query_builder.push("ORDER BY fp.application_order"); let query = query_builder.build_query_as::(); let rows = query.fetch_all(ex).await?; diff --git a/crates/database/src/order_execution.rs b/crates/database/src/order_execution.rs index 11eb9f5ba1..18d81a7cbc 100644 --- a/crates/database/src/order_execution.rs +++ b/crates/database/src/order_execution.rs @@ -55,22 +55,25 @@ pub async fn executed_protocol_fees( } let mut query_builder = QueryBuilder::new( - "SELECT order_uid, auction_id, protocol_fee_tokens, protocol_fee_amounts FROM \ - order_execution WHERE ", + "SELECT oe.order_uid, oe.auction_id, oe.protocol_fee_tokens, oe.protocol_fee_amounts FROM \ + order_execution oe INNER JOIN (VALUES ", ); for (i, (auction_id, order_uid)) in keys_filter.iter().enumerate() { if i > 0 { - query_builder.push(" OR "); + query_builder.push(", "); } query_builder - .push("(order_uid = ") + .push("(") .push_bind(order_uid) - .push(" AND auction_id = ") + .push(", ") .push_bind(auction_id) .push(")"); } + query_builder.push(") AS vals(order_uid, auction_id) "); + query_builder.push("ON (oe.order_uid, oe.auction_id) = (vals.order_uid, vals.auction_id)"); + #[derive(Clone, Debug, Eq, PartialEq, sqlx::Type, sqlx::FromRow)] struct ProtocolFees { pub order_uid: OrderUid,