cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
NaderSaeed
Helper I
Helper I

Calculated Column that returns Distinct Count with a date slicer

Hi All,

 

This is a calculated column in Sheet (Mails) that returns 1 if someone in Sheet (Test) submitted twice (by distinct-counting the submitted on dates), 0.5, if someone submitted once, and 0 if someone didn't submitt at all.

 

Column =
VAR M = Mails[Mail]
RETURN
IF(
CALCULATE(
DISTINCTCOUNT(Test[SubmittedOn]),
FILTER(ALLSELECTED(Test),
Test[Submittedby] = M && Test[SubmittedOn] >= SELECTEDVALUE('Start Date'[Start Date]) && Test[SubmittedOn] <= SELECTEDVALUE('End Date'[End Date]))
)>=2,1,
IF(
CALCULATE(
DISTINCTCOUNT(Test[SubmittedOn]),
FILTER(ALLSELECTED(Test),
Test[Submittedby] = M && Test[SubmittedOn] >= SELECTEDVALUE('Start Date'[Start Date]) && Test[SubmittedOn] <= SELECTEDVALUE('End Date'[End Date]))
)=1,0.5,0
)
)
 
Start Date and End Time are 
= GENERATESERIES(DATE(2020, 1,1), DATE(2060,12,31))
 
The problem is I want the returend value to be flitered by a date slicer on my dashboard, and I'm unable to do so using the DAX above.
 
But when I under the dates manually into the function, using Date(Year, Month, Day), it works perfectly.
 
Is there anyway to make this work in a calculated column?
 
Thanks.
1 ACCEPTED SOLUTION
v-zhenbw-msft
Community Support
Community Support

Hi @NaderSaeed ,

 

If you want to use date slicer to control the result, you need to create a measure not a calculate column.

We create a measure based on your business logic to meet your requirement.

 

1. We need to create a relationship between Mail table and Test table.

 

cal1.jpg

 

2. Then we can create a measure.

 

 

Measure = 
VAR M =
    MAX ( Mail[Mails] )
VAR _selected_Start =
    SELECTEDVALUE ( 'Start Date'[Value] )
VAR _selected_End =
    SELECTEDVALUE ( 'End Date'[Value] )
VAR _result1 =
    IF (
        CALCULATE (
            DISTINCTCOUNT ( Test[SubmittedOn] ),
            FILTER (
                ALLSELECTED ( Test ),
                Test[Submittedby] = M
                    && Test[SubmittedOn] >= _selected_Start
                    && Test[SubmittedOn] <= _selected_End
            )
        ) >= 2,
        1,
        IF (
            CALCULATE (
                DISTINCTCOUNT ( Test[SubmittedOn] ),
                FILTER (
                    ALLSELECTED ( Test ),
                    Test[Submittedby] = M
                        && Test[SubmittedOn] >= _selected_Start
                        && Test[SubmittedOn] <= _selected_End
                )
            ) = 1,
            0.5,
            0
        )
    )
VAR _result2 =
    IF (
        CALCULATE (
            DISTINCTCOUNT ( Test[SubmittedOn] ),
            FILTER ( ALLSELECTED ( Test ), Test[Submittedby] = M )
        ) >= 2,
        1,
        IF (
            CALCULATE (
                DISTINCTCOUNT ( Test[SubmittedOn] ),
                FILTER ( ALLSELECTED ( Test ), Test[Submittedby] = M )
            ) = 1,
            0.5,
            0
        )
    )
RETURN
    IF (
        ISBLANK ( _selected_Start ) || ISBLANK ( _selected_End ),
        _result2,
        _result1
    )

 

 

3. At last we create two slicers based on Start Date and End Date.

 

cal2.jpg

 

cal3.jpg

 

If it doesn’t meet your requirement, could you please show the exact expected result based on the table that you have shared?

BTW, pbix as attached.

 

Best regards,

 

Community Support Team _ zhenbw

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

4 REPLIES 4
v-zhenbw-msft
Community Support
Community Support

Hi @NaderSaeed ,

 

If you want to use date slicer to control the result, you need to create a measure not a calculate column.

We create a measure based on your business logic to meet your requirement.

 

1. We need to create a relationship between Mail table and Test table.

 

cal1.jpg

 

2. Then we can create a measure.

 

 

Measure = 
VAR M =
    MAX ( Mail[Mails] )
VAR _selected_Start =
    SELECTEDVALUE ( 'Start Date'[Value] )
VAR _selected_End =
    SELECTEDVALUE ( 'End Date'[Value] )
VAR _result1 =
    IF (
        CALCULATE (
            DISTINCTCOUNT ( Test[SubmittedOn] ),
            FILTER (
                ALLSELECTED ( Test ),
                Test[Submittedby] = M
                    && Test[SubmittedOn] >= _selected_Start
                    && Test[SubmittedOn] <= _selected_End
            )
        ) >= 2,
        1,
        IF (
            CALCULATE (
                DISTINCTCOUNT ( Test[SubmittedOn] ),
                FILTER (
                    ALLSELECTED ( Test ),
                    Test[Submittedby] = M
                        && Test[SubmittedOn] >= _selected_Start
                        && Test[SubmittedOn] <= _selected_End
                )
            ) = 1,
            0.5,
            0
        )
    )
VAR _result2 =
    IF (
        CALCULATE (
            DISTINCTCOUNT ( Test[SubmittedOn] ),
            FILTER ( ALLSELECTED ( Test ), Test[Submittedby] = M )
        ) >= 2,
        1,
        IF (
            CALCULATE (
                DISTINCTCOUNT ( Test[SubmittedOn] ),
                FILTER ( ALLSELECTED ( Test ), Test[Submittedby] = M )
            ) = 1,
            0.5,
            0
        )
    )
RETURN
    IF (
        ISBLANK ( _selected_Start ) || ISBLANK ( _selected_End ),
        _result2,
        _result1
    )

 

 

3. At last we create two slicers based on Start Date and End Date.

 

cal2.jpg

 

cal3.jpg

 

If it doesn’t meet your requirement, could you please show the exact expected result based on the table that you have shared?

BTW, pbix as attached.

 

Best regards,

 

Community Support Team _ zhenbw

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

Genius, Thanks.

amitchandak
Super User IV
Super User IV

@NaderSaeed ,Can you share sample data and sample output in table format?



Did I answer your question? Mark my post as a solution! Appreciate your Kudos!!
Dashboard of My Blogs !! YouTube Channel !! Connect on Linkedin

Proud to be a Super User!

Sheet(Test)

NaderSaeed_1-1594655021982.png

 

Sheet (Mail)

NaderSaeed_0-1594654987744.png

 

The Sheet (Mail) has all the databbase for all emails, and the Sheet (Test) only has the ones who have submitted, so I'm distinct-counting the SubmittedOn Coulmn as it'd be the best indicator in our case.

Helpful resources

Announcements
PBI User Groups

Welcome to the User Group Public Preview

Check out new user group experience and if you are a leader please create your group

April Update

Check it Out!

Click here to read more about the April 2021 Updates!

MBAS Carousel

Sign up for our May 4th event!

May the fourth be with you, join us online!

secondImage

The largest Power BI virtual conference

100+ sessions, 100+ speakers, Product managers, MVPs, and experts. All about Power BI. Attend online or watch the recordings.