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

Aggregating Dates and Categories

Sorry for the newbie question, but I am having trouble getting my data to aggregate from individual day level into week, month, and year levels for each of my categories. Here is an example of my data which goes over multiple years:

 

DateTesting StatusProductLocationCount
1/1/2018TestedXHS105
1/1/2018TestedXAY1000100
1/1/2018UntestedXHS1020
1/1/2018UntestedXAY100020
1/2/2018TestedYAB550
1/2/2018UntestedYAB55
1/2/2018TestedZHS1030
1/2/2018UntestedZHS105

 

I would like to show the Amount Tested and Untested By Product And Location each week, month, and year, in addition to showing the change to date of each Tested/Untested Product and Location.

 

I was able to get it to show the date aggregation for all products and each products but not by testing status or location.

 

Any help would be very apprciated. I have been trying to do this for weeks.

1 ACCEPTED SOLUTION
v-frfei-msft
Community Support
Community Support

Hi @Anonymous ,

 


Hi

Firstly to create some calculated column in your fact table.

 

Year = YEAR('Table1'[Date])
Month = FORMAT('Table1'[Date],"mmm")
week = WEEKNUM('Table1'[Date])

Then we can create two measures to get the result as we need.

 

Tested = var k = FILTER(Table1,Table1[Testing Status]="Tested")
return
CALCULATE(SUM(Table1[Count]),ALLEXCEPT(Table1,Table1[Year],Table1[Month],Table1[week],Table1[Location],Table1[Product]),KEEPFILTERS(k))
unTested = var k = FILTER(Table1,Table1[Testing Status]="Untested")
return
CALCULATE(SUM(Table1[Count]),ALLEXCEPT(Table1,Table1[Year],Table1[Month],Table1[week],Table1[Location],Table1[Product]),KEEPFILTERS(k))

Capture.PNG

For mroe details, please check the pbix as attached.

 

Regards,
Frank

Community Support Team _ Frank
If this post helps, then please consider Accept it as the solution to help the others find it more quickly.

View solution in original post

1 REPLY 1
v-frfei-msft
Community Support
Community Support

Hi @Anonymous ,

 


Hi

Firstly to create some calculated column in your fact table.

 

Year = YEAR('Table1'[Date])
Month = FORMAT('Table1'[Date],"mmm")
week = WEEKNUM('Table1'[Date])

Then we can create two measures to get the result as we need.

 

Tested = var k = FILTER(Table1,Table1[Testing Status]="Tested")
return
CALCULATE(SUM(Table1[Count]),ALLEXCEPT(Table1,Table1[Year],Table1[Month],Table1[week],Table1[Location],Table1[Product]),KEEPFILTERS(k))
unTested = var k = FILTER(Table1,Table1[Testing Status]="Untested")
return
CALCULATE(SUM(Table1[Count]),ALLEXCEPT(Table1,Table1[Year],Table1[Month],Table1[week],Table1[Location],Table1[Product]),KEEPFILTERS(k))

Capture.PNG

For mroe details, please check the pbix as attached.

 

Regards,
Frank

Community Support Team _ Frank
If this post helps, then please consider Accept it as the solution to help the others find it more quickly.

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.