"Distinct" results in complex query
In your first query you have this clause:
GROUP BY me.id, me.merchant_num, me.merchant_nm, me.status
In your second query you have this clause:
GROUP BY me.id, me.merchant_num, me.merchant_nm, me.status, tt.bank_txt
You are getting different number of rows in the second query because your GROUP BY
is different. You need to keep it the same.
Here is one way to do it. I used CTE to make the query readable.
As you can see in the comments in the query, it returns the value of the trans_live
column for the merchant's most recent transaction. Most recent transaction of the merchant across all dates, regardless of the filter in the CTE. Same with the date of the last transaction that uses IBank (IBA). It returns the last transaction of the merchant across all dates, regardless of the filter in the CTE.
It is not clear from the question if this is what you want, though. Please clarify.
WITH
CTE_Merchants
AS
(
SELECT -- distinct
-- you don't need distinct here, because GROUP BY does it
-- try to comment out distinct, you should get exactly the same result
me.id, me.merchant_num, me.merchant_nm
,count(tt.id) as num_transactions
-- return 0 count for merchants that don't have any transactions
-- within the given range of dates
,CASE WHEN me.status = 'A' THEN 'Yes' ELSE 'No' END as production_mode
FROM
merchant_t me
LEFT OUTER JOIN transaction_t tt
ON tt.merchant_id = me.id
AND tt.transaction_dt BETWEEN '2020-04-01' and '2020-04-30'
WHERE me.status = 'T'
GROUP BY me.id, me.merchant_num, me.merchant_nm, me.status
)
SELECT
CTE_Merchants.id
,CTE_Merchants.merchant_num
,CTE_Merchants.merchant_nm
,CTE_Merchants.num_transactions
,CTE_Merchants.production_mode
,A1.is_live
,A2.last_IBA_transaction_dt
FROM
CTE_Merchants
OUTER APPLY
(
-- use OUTER APPLY (not CROSS APPLY) in case there are merchants with no transactions
-- The value of the "trans_live" column for the merchant's most recent transaction.
-- Most recent across all dates, regardless of the filter in the CTE
select top 1
transaction_t.trans_live AS is_live
from transaction_t
where
transaction_t.merchant_id = CTE_Merchants.id
order by transaction_dt desc
) AS A1
OUTER APPLY
(
-- use OUTER APPLY (not CROSS APPLY) in case there are merchants with no transactions
-- The date of the last transaction that uses IBank (IBA).
-- The last transaction across all dates, regardless of the filter in the CTE
select top 1
transaction_t.transaction_dt AS last_IBA_transaction_dt
from transaction_t
where
transaction_t.merchant_id = CTE_Merchants.id
and transaction_t.bank_txt = 'IBA'
order by transaction_dt desc
) AS A2
;
For this query to work efficiently, I would recommend to create certain indexes. You already have an index IX_status
on the merchant_t
table. This is good.
Those indexes that you have on the transaction_t
table are not the best for this kind of query. You existing indexes IX_transaction_dt
, IX_trans_live
, IX_bank_txt
are not useful for this query. Even IX_merchant_id
by itself is not really useful, especially if you replace it with a composite index on (merchant_id, transaction_dt)
, as I've shown below.
I hope you do have a clustered primary key on id
in transaction_t
table. Similar to the primary key in the merchant_t
table. If not, I'd create it.
Then, for efficient join between merchant_t
and transaction_t
tables and for efficient retrieval of the latest trans_live
we need the following index:
CREATE NONCLUSTERED INDEX [IX_merchant_id_transaction_dt] ON [dbo].[transaction_t]
(
merchant_id,
transaction_dt -- you can put DESC here, but it should not matter
) INCLUDE (trans_live)
The order of columns in this index is important.
You have an index on just transaction_dt
. This query might use it, but it would be not as efficient as on (merchant_id, transaction_dt)
. Your current index is useful if you have queries that filter by transaction date without looking at the merchant_id
. If you don't have such queries, you'd better drop it. Having too many indexes "just in case" may be a problem for optimizer, and it slows down updates and inserts.
For efficient retrieval of the last last_IBA_transaction_dt
we'll need this index:
CREATE NONCLUSTERED INDEX [IX_merchant_id_bank_txt_transaction_dt] ON [dbo].[transaction_t]
(
merchant_id,
bank_txt,
transaction_dt -- you can put DESC here, but it should not matter
)
Again, the order of columns in this index is important.
If you don't want to create two indexes specifically for this query, you can try just one index, which is great for getting trans_live
and should somewhat help with last_IBA_transaction_dt
.
CREATE NONCLUSTERED INDEX [IX3] ON [dbo].[transaction_t]
(
merchant_id,
transaction_dt DESC
) INCLUDE (trans_live, bank_txt)
You can try and measure performance with the first two indexes and then just with the third one and compare.
By the way, if there are merchants that don't have any transactions within the given range of dates, then the query will return a row for these merchants. The COUNT
in your original query will return 1
for these merchants. Probably this is not what you want.
To return 0
count for these merchants, the COUNT
function should be COUNT(tt.id)
. I have made these changes in the code above.
This tries to get rid of the two Scalar Subqueries/Outer Apply. It runs a single aggregation on the transaction table using a conditional aggregate and the old piggyback trick to get the latest trans_live
.
SELECT
me.id
,me.merchant_num
,me.merchant_nm
-- return 0 count for merchants that don't have any transactions
-- within the given range of dates
,Count(CASE WHEN tt.transaction_dt BETWEEN '2020-04-01' AND '2020-04-30' THEN tt.id end) AS num_transactions
-- the date of the last transaction that uses IBank (IBA)
,CASE WHEN me.status = 'A' THEN 'Yes' ELSE 'No' END AS production_mode
,Max(CASE WHEN bank_txt = 'IBA' THEN tt.transaction_dt END) AS last_IBA_transaction_dt
-- the value of the "trans_live" column for the merchant's most recent transaction
-- piggybacks the trans_live on the max transaction_dt
-- similar to FIRST_VALUE
,convert(bit, Substring(Max(convert(CHAR(8), tt.transaction_dt, 112) + convert(CHAR(1), trans_live)), 9, 1)) AS is_live
FROM merchant_t AS me
LEFT JOIN transaction_t AS tt
ON tt.merchant_id = me.id
WHERE me.status = 'T'
GROUP BY
me.id
,me.merchant_num
,me.merchant_nm
,me.status
Don't ask me about adding indexes for improving performance, I don't work with SQL Server anymore and my main DBMS Teradata usually runs fast without adding indexes for specific queries :-)