Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
Anonymous
Not applicable

Select date to same month 1st Average

Hi Team,

I have 5 column similar

 

DateCountry_NameCountBPIDRES/NON
20-May-20INDIA20Z10RES
20-May-20INDIA15Z12NONRES
20-May-20AMERICA10z12RES
20-May-20South africa30Z10RES
21-May-20INDIA25Z10RES
21-May-20INDIA25Z14RES
21-May-20AMERICA10Z12RES
21-May-20South africa25Z15NONRES
24-May-20INDIA30Z20NONRES
24-May-20INDIA34Z20RES
24-May-20AMERICA10Z35RES
24-May-20South africa34Z10

NONRES

 

 

I need If select one date same month 1st date average required(average formala=SUM(countcolumn values)/COUNT(no .of dates)

If i am select 24th may the data availble 21 then out shoube INDIA output =(20+15+25+25+30+34)/3=49.6

if i am select jan 27 then average shoube  01-jan to 27-jan

if i am select 15-jan then average shoulbe 01-jan to 15-jan

similar select date to same month 1st average required please help me.

if i am select 20-Feb then average shoulbemonth 01-feb to 20-15

 

 

Thanks

Shanvitha

2 ACCEPTED SOLUTIONS
amitchandak
Super User
Super User

@Anonymous , see like you are looking for Month till date, You have totalmtd and datesmtd to help. Use them with a date table

examples

MTD Sales = CALCULATE(Sum(Sales[Sales Amount]),DATESMTD('Date'[Date]))

MTD Dates= CALCULATE(distinctcount(Sales[Sales Date]),DATESMTD('Date'[Date]))

 

Avg = divide([MTD Sales],[MTD Dates])

 

To get the best of the time intelligence function. Make sure you have a date calendar and it has been marked as the date in model view. Also, join it with the date column of your fact/s. Refer :
https://radacad.com/creating-calendar-table-in-power-bi-using-dax-functions
https://www.archerpoint.com/blog/Posts/creating-date-table-power-bi
https://www.sqlbi.com/articles/creating-a-simple-date-table-in-dax/

See if my webinar on Time Intelligence can help: https://community.powerbi.com/t5/Webinars-and-Video-Gallery/PowerBI-Time-Intelligence-Calendar-WTD-YTD-LYTD-Week-Over-Week/m-p/1051626#M184


Appreciate your Kudos.

View solution in original post

v-eachen-msft
Community Support
Community Support

Hi @Anonymous ,

 

At first, use DISTINCT() to create a date dimension table based on your fact table.

Then refer to the following measure:

Measure =
VAR a =
    SELECTEDVALUE ( 'Date'[Date] )
VAR b =
    CALCULATE (
        MIN ( 'Table'[Date] ),
        FILTER ( 'Table', 'Table'[Column] = SELECTEDVALUE ( 'Date'[Column] ) )
    )
VAR total =
    CALCULATE (
        SUM ( 'Table'[Count] ),
        FILTER ( 'Table', 'Table'[Date] >= b && 'Table'[Date] <= a )
    )
VAR day =
    CALCULATE (
        DISTINCTCOUNT ( 'Table'[Date] ),
        FILTER ( 'Table', 'Table'[Date] >= b && 'Table'[Date] <= a )
    )
RETURN
    DIVIDE ( total, day )

Here is my test file for your reference.

 

Community Support Team _ Eads
If this post helps, then please consider Accept it as the solution to help the other members find it.

View solution in original post

2 REPLIES 2
v-eachen-msft
Community Support
Community Support

Hi @Anonymous ,

 

At first, use DISTINCT() to create a date dimension table based on your fact table.

Then refer to the following measure:

Measure =
VAR a =
    SELECTEDVALUE ( 'Date'[Date] )
VAR b =
    CALCULATE (
        MIN ( 'Table'[Date] ),
        FILTER ( 'Table', 'Table'[Column] = SELECTEDVALUE ( 'Date'[Column] ) )
    )
VAR total =
    CALCULATE (
        SUM ( 'Table'[Count] ),
        FILTER ( 'Table', 'Table'[Date] >= b && 'Table'[Date] <= a )
    )
VAR day =
    CALCULATE (
        DISTINCTCOUNT ( 'Table'[Date] ),
        FILTER ( 'Table', 'Table'[Date] >= b && 'Table'[Date] <= a )
    )
RETURN
    DIVIDE ( total, day )

Here is my test file for your reference.

 

Community Support Team _ Eads
If this post helps, then please consider Accept it as the solution to help the other members find it.
amitchandak
Super User
Super User

@Anonymous , see like you are looking for Month till date, You have totalmtd and datesmtd to help. Use them with a date table

examples

MTD Sales = CALCULATE(Sum(Sales[Sales Amount]),DATESMTD('Date'[Date]))

MTD Dates= CALCULATE(distinctcount(Sales[Sales Date]),DATESMTD('Date'[Date]))

 

Avg = divide([MTD Sales],[MTD Dates])

 

To get the best of the time intelligence function. Make sure you have a date calendar and it has been marked as the date in model view. Also, join it with the date column of your fact/s. Refer :
https://radacad.com/creating-calendar-table-in-power-bi-using-dax-functions
https://www.archerpoint.com/blog/Posts/creating-date-table-power-bi
https://www.sqlbi.com/articles/creating-a-simple-date-table-in-dax/

See if my webinar on Time Intelligence can help: https://community.powerbi.com/t5/Webinars-and-Video-Gallery/PowerBI-Time-Intelligence-Calendar-WTD-YTD-LYTD-Week-Over-Week/m-p/1051626#M184


Appreciate your Kudos.

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

Find out what's new and trending in the Fabric Community.