From 87f6ae86fc97f95c84f6253baa5e857db4d76f9f Mon Sep 17 00:00:00 2001 From: Stamates Date: Fri, 10 Aug 2018 17:12:03 -0400 Subject: [PATCH] Use CTE for optimized address transactions query Co-authored-by: Timothy Mecklem --- apps/explorer/lib/explorer/chain.ex | 9 +- .../lib/explorer/chain/transaction.ex | 110 ++++++++++-------- 2 files changed, 65 insertions(+), 54 deletions(-) diff --git a/apps/explorer/lib/explorer/chain.ex b/apps/explorer/lib/explorer/chain.ex index 41fc47b714..7a75ab0a8e 100644 --- a/apps/explorer/lib/explorer/chain.ex +++ b/apps/explorer/lib/explorer/chain.ex @@ -179,13 +179,10 @@ defmodule Explorer.Chain do when is_list(options) do direction = Keyword.get(options, :direction) necessity_by_association = Keyword.get(options, :necessity_by_association, %{}) - paging_options = Keyword.get(options, :paging_options, @default_paging_options) - # Added transaction.hash to order_by to force postgres to not use `transactions_recent_collated_index` for an - # index_scan before filtering based on the WHERE clauses (i.e. to speed up the query) - Transaction - |> order_by([transaction], desc: transaction.block_number, desc: transaction.index, asc: transaction.hash) - |> handle_paging_options(paging_options) + options + |> Keyword.get(:paging_options, @default_paging_options) + |> fetch_transactions() |> Transaction.where_address_fields_match(address_hash, direction) |> join_associations(necessity_by_association) |> Transaction.preload_token_transfers(address_hash) diff --git a/apps/explorer/lib/explorer/chain/transaction.ex b/apps/explorer/lib/explorer/chain/transaction.ex index d8e328ecd0..49ccd3ed68 100644 --- a/apps/explorer/lib/explorer/chain/transaction.ex +++ b/apps/explorer/lib/explorer/chain/transaction.ex @@ -3,6 +3,8 @@ defmodule Explorer.Chain.Transaction do use Explorer.Schema + import Ecto.Query, only: [from: 2, join: 5, preload: 3] + alias Ecto.Changeset alias Explorer.Chain.{ @@ -334,78 +336,90 @@ defmodule Explorer.Chain.Transaction do to token_contract_address_hash, to_address_hash or from_address_hash from Token Transfers's table. """ def where_address_fields_match(query, address_hash, :to) do - query - |> where( - [t], - t.hash in fragment( + join( + query, + :inner, + [transaction], + matches in fragment( """ - ( - SELECT t0.hash AS hash - FROM transactions AS t0 - WHERE t0.to_address_hash = ? OR t0.created_contract_address_hash = ? - ) - UNION - ( - SELECT tt.transaction_hash AS hash - FROM token_transfers AS tt - WHERE tt.to_address_hash = ? - ) + WITH hashes AS ( + ( + SELECT t0.hash AS hash + FROM transactions AS t0 + WHERE t0.to_address_hash = ? OR t0.created_contract_address_hash = ? + ) + UNION ALL + ( + SELECT tt.transaction_hash AS hash + FROM token_transfers AS tt + WHERE tt.to_address_hash = ? + ) + ) SELECT * from hashes """, ^address_hash.bytes, ^address_hash.bytes, ^address_hash.bytes - ) + ), + transaction.hash == matches.hash ) end def where_address_fields_match(query, address_hash, :from) do - query - |> where( - [t], - t.hash in fragment( + join( + query, + :inner, + [transaction], + matches in fragment( """ - ( - SELECT t0.hash AS hash - FROM transactions AS t0 - WHERE t0.from_address_hash = ? - ) - UNION - ( - SELECT tt.transaction_hash AS hash - FROM token_transfers AS tt - WHERE tt.from_address_hash = ? - ) + WITH hashes AS ( + ( + SELECT t0.hash AS hash + FROM transactions AS t0 + WHERE t0.from_address_hash = ? + ) + UNION ALL + ( + SELECT tt.transaction_hash AS hash + FROM token_transfers AS tt + WHERE tt.from_address_hash = ? + ) + ) SELECT * from hashes """, ^address_hash.bytes, ^address_hash.bytes - ) + ), + transaction.hash == matches.hash ) end def where_address_fields_match(query, address_hash, nil) do - query - |> where( - [t], - t.hash in fragment( + join( + query, + :inner, + [transaction], + matches in fragment( """ - ( - SELECT t0.hash AS hash - FROM transactions AS t0 - WHERE t0.to_address_hash = ? OR t0.from_address_hash = ? OR t0.created_contract_address_hash = ? - ) - UNION - ( - SELECT tt.transaction_hash AS hash - FROM token_transfers AS tt - WHERE tt.to_address_hash = ? OR tt.from_address_hash = ? - ) + WITH hashes AS ( + ( + SELECT t0.hash AS hash + FROM transactions AS t0 + WHERE t0.to_address_hash = ? OR t0.from_address_hash = ? OR t0.created_contract_address_hash = ? + ) + UNION ALL + ( + SELECT tt.transaction_hash AS hash + FROM token_transfers AS tt + WHERE tt.to_address_hash = ? OR tt.from_address_hash = ? + ) + ) SELECT * from hashes """, ^address_hash.bytes, ^address_hash.bytes, ^address_hash.bytes, ^address_hash.bytes, ^address_hash.bytes - ) + ), + transaction.hash == matches.hash ) end