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

Earn the coveted Fabric Analytics Engineer certification. 100% off your exam for a limited time only!

Reply
abhay03
Helper I
Helper I

Sum of values by date for each category

In my report, there is a report-level filter on the current month. I have to show the values of Amount for each category side by side for 2 different time period: first for the current month and for 2 months prior. Below are the two tables:

 

DimCategory

Key

Category
1ABC
2DEF
3GHI

 

FactCategory

KeyAmountDate
11009/01/2017
22009/01/2017
23009/11/2017
34009/01/2017
15010/01/2017
26010/02/2017
37010/11/2017
18011/15/2017
29011/16/2017
38011/17/2017
37011/18/2017

 

I tried writing measure to calculate two months prior Amount for each category but the result I am getting is the sum of all category for that time period. 

 

Measure = CALCULATE(SUM(FactCategory[Amount]), 
FILTER(ALL(FactCategory), MONTH(FactCategory[Date]) = 9)) Measure 2 = SUMX( SUMMARIZE( FactCategory, DimCategory[Category], "VALUE", CALCULATE(SUM(FactCategory[Amount]), FILTER(ALL(FactCategory), MONTH(FactCategory[Date]) = 9)) ), [VALUE] )

 

image.png 

 

How can I get the below output:

CategoryAmountAmount 2 months prior
ABC8010
DEF9050
GHI15040
1 ACCEPTED SOLUTION
v-shex-msft
Community Support
Community Support

Hi @abhay03,

 

You can try to use below formula to get previous data.

 

Measure:

Previous 2 Month =
VAR current_Date =
    MAX ( FactCategory[Date] )
RETURN
    SUMX (
        FILTER (
            ALL ( FactCategory ),
            [Key] = MAX ( DimCategory[Key] )
                && FORMAT ( [Date], "yyyy mmm" )
                    = FORMAT (
                        DATE ( YEAR ( current_Date ), MONTH ( current_Date ) - 2, 1 ),
                        "yyyy mmm"
                    )
        ),
        [Amount]
    )

1.PNG

 

Regards,

Xiaoxin Sheng

Community Support Team _ Xiaoxin
If this post helps, please consider accept as solution to help other members find it more quickly.

View solution in original post

2 REPLIES 2
v-shex-msft
Community Support
Community Support

Hi @abhay03,

 

You can try to use below formula to get previous data.

 

Measure:

Previous 2 Month =
VAR current_Date =
    MAX ( FactCategory[Date] )
RETURN
    SUMX (
        FILTER (
            ALL ( FactCategory ),
            [Key] = MAX ( DimCategory[Key] )
                && FORMAT ( [Date], "yyyy mmm" )
                    = FORMAT (
                        DATE ( YEAR ( current_Date ), MONTH ( current_Date ) - 2, 1 ),
                        "yyyy mmm"
                    )
        ),
        [Amount]
    )

1.PNG

 

Regards,

Xiaoxin Sheng

Community Support Team _ Xiaoxin
If this post helps, please consider accept as solution to help other members find it more quickly.

Thanks, @v-shex-msft. This is exactly what I was looking for.

Helpful resources

Announcements
April AMA free

Microsoft Fabric AMA Livestream

Join us Tuesday, April 09, 9:00 – 10:00 AM PST for a live, expert-led Q&A session on all things Microsoft Fabric!

March Fabric Community Update

Fabric Community Update - March 2024

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