Join us at FabCon Atlanta from March 16 - 20, 2026, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.
Register now!Vote for your favorite vizzies from the Power BI Dataviz World Championship submissions. Vote now!
Hello guys,
I have this query in sql which I am trying to make a measure in powerbi but having issues,
SQL query:
SELECT COUNT (DISTINCT(ID)) -
COUNT( DISTINCT (case when MONTH(ISNULL(ConvertedDate,Date_of_Last_Status_Change__c)) <> MONTH(TransactionDate) and Year(ISNULL(ConvertedDate,Date_of_Last_Status_Change__c)) <> YEAR(TransactionDate) then DocumentNumber end))
TABLE STRUCTURE
| ID | TransactionDate | ConvertedDate | Date_of_Last_Status_Change__c | DocumentNumber |
| 123 | 12/1/2021 | 12/1/2021 | 12/15/2021 | 001 |
145 | 11/1/2021 | 12/1/2021 | 12/15/2021 | 002 |
| 234 | 10/1/2021 | 9/1/2021 | 10/21/2021 | 003 |
| 265 | NULL | 10/1/2021 | 10/15/2021 | NULL |
| NULL | 2/1/2021 | NULL | NULL | 005 |
correct answer:
4 - 2 = 2
Thanks for your help!
Solved! Go to Solution.
@sun-sboyanapall can you try this measure
Measure =
CALCULATE (
DISTINCTCOUNT ( tbl[ID] ),
VAR _base =
FILTER (
tbl,
tbl[TransactionDate] <> BLANK ()
&& tbl[ConvertedDate] <> BLANK ()
&& tbl[Date_of_Last_Status_Change__c] <> BLANK ()
)
VAR _left =
FILTER ( tbl, tbl[ID] <> BLANK () )
VAR _join =
EXCEPT (
_left,
FILTER (
_base,
MONTH ( COALESCE ( tbl[ConvertedDate], tbl[Date_of_Last_Status_Change__c] ) )
<> MONTH ( tbl[TransactionDate] )
&& YEAR ( COALESCE ( tbl[ConvertedDate], tbl[Date_of_Last_Status_Change__c] ) )
<> YEAR ( tbl[TransactionDate] )
)
)
RETURN
_join
)
Thank you, another way I did was created a calculated column, is consumed that is taking care of my case statement.
IsConsumed =
var yearTranDate = YEAR(Tbl[TransactionDate])
var monthTranDate = MONTH(Tbl[TransactionDate])
var yearConvDate = YEAR(Tbl[ConvertedDate]))
var monthConvDate = MONTH(Tbl[ConvertedDate]))
var yeardateLastSC = YEAR(Tbl[Date_of_Last_Status_Change__c]))
var monthdateLastSC = MONTH(Tbl[Date_of_Last_Status_Change__c]))
RETURN IF(ISBLANK(vLeadConsumedWithSales[ID]), FALSE(), IF(ISBLANK(yearConvDate), yearDateLastSC <> yearTranDate && monthDateLastSC <> monthTranDate, yearConvDate <> yearTranDate && monthConvDate <> monthTranDate))
@sun-sboyanapall well done.
One rule of thumb to always remember with DAX; if you can create a measure, don't create a column.
can you explain your measure too please, in its current form it is hard to understand. @smpa01
Measure =
VAR _base =
FILTER ( //#1- returns a table that has no tbl[ID]or tbl[ConvertedDate]or tbl[Date_of_Last_Status_Change__c] as BLANK
tbl,
tbl[TransactionDate] <> BLANK ()
&& tbl[ConvertedDate] <> BLANK ()
&& tbl[Date_of_Last_Status_Change__c] <> BLANK ()
)
VAR _left =
FILTER ( tbl, tbl[ID] <> BLANK () ) //#2- returns a table that has no tbl[ID] as BLANK
VAR _join =
EXCEPT ( // #4 - this returns a left anti joined tables between 2 and 3, i.e. return everything from 2 that are not in 3
_left,
FILTER ( // #3- previously created base table is further filteres with SQL IS NULL conditions
_base,
MONTH ( COALESCE ( tbl[ConvertedDate], tbl[Date_of_Last_Status_Change__c] ) )
<> MONTH ( tbl[TransactionDate] )
&& YEAR ( COALESCE ( tbl[ConvertedDate], tbl[Date_of_Last_Status_Change__c] ) )
<> YEAR ( tbl[TransactionDate] )
)
)
RETURN CALCULATE ( //5. DISTINCTCOUNT is performed on the above derived table
DISTINCTCOUNT ( tbl[ID] ),_join)
That's clear, Thank you Sir
@sun-sboyanapall I don't think the above SQL query returns 2 for the data provided, it returns 4, cause the following part returns 0
COUNT( DISTINCT (case when MONTH(ISNULL(ConvertedDate,Date_of_Last_Status_Change_c)) <> MONTH(TransactionDate) and Year(ISNULL(ConvertedDate,Date_of_Last_Status_Change_c)) <> YEAR(TransactionDate) then DocumentNumber end))
breakdown
MONTH(ISNULL(ConvertedDate,Date_of_Last_Status_Change_c)) <> MONTH(TransactionDate)
has two matches row 2 and row 3 as {12,11}, {9,10}
Year(ISNULL(ConvertedDate,Date_of_Last_Status_Change_c)) <> YEAR(TransactionDate)
has no match as all of them are {2021,2021}
That's correct the correct answer would be 4, I thought I have changed year.
Looking forward to how you would do this with dax.
@sun-sboyanapall can you try this measure
Measure =
CALCULATE (
DISTINCTCOUNT ( tbl[ID] ),
VAR _base =
FILTER (
tbl,
tbl[TransactionDate] <> BLANK ()
&& tbl[ConvertedDate] <> BLANK ()
&& tbl[Date_of_Last_Status_Change__c] <> BLANK ()
)
VAR _left =
FILTER ( tbl, tbl[ID] <> BLANK () )
VAR _join =
EXCEPT (
_left,
FILTER (
_base,
MONTH ( COALESCE ( tbl[ConvertedDate], tbl[Date_of_Last_Status_Change__c] ) )
<> MONTH ( tbl[TransactionDate] )
&& YEAR ( COALESCE ( tbl[ConvertedDate], tbl[Date_of_Last_Status_Change__c] ) )
<> YEAR ( tbl[TransactionDate] )
)
)
RETURN
_join
)
Vote for your favorite vizzies from the Power BI World Championship submissions!
If you love stickers, then you will definitely want to check out our Community Sticker Challenge!
Check out the January 2026 Power BI update to learn about new features.
| User | Count |
|---|---|
| 64 | |
| 53 | |
| 42 | |
| 20 | |
| 17 |
| User | Count |
|---|---|
| 124 | |
| 105 | |
| 44 | |
| 32 | |
| 24 |