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
satubuku83
Frequent Visitor

Calculate % Changes based on group

Hi

 

Assuming I have this table.

 

MetricGL CodeAmount
Premium10010000
Premium2005000
Premium300400
Reinsurance4005000
Reinsurance500

5000

 

And I would like to build a new measure that keeps track of the % change (different formulae depending on the metric) as below. There will be cases new metric is added and % change(for checking) for that metric will be anoter division over group.

 

For the case below, no checking is needed for premium, but a % checking for reinsurance (total reinsurance/total premium)

 

 Total Amount% Change (for checking)
Premium15400-
Reinsurance1000065%

 

 

Would appreciate if there is some light shed in this? Not too sure how filters would be able to help in this.

 

Regards

CS

1 ACCEPTED SOLUTION

HI @satubuku83,

 

Actually, your requirement not very suitable for power bi. I think it should be more simply to achieve in excel pivot table.

I also shared power bi version below:

 

1. Grouping and transform table.

1.PNG

 

2. Write measure formulas:

Condition Total = 
VAR categoryLevel =
    CALCULATE ( SUM ( GL[Amount] ), GL[SubCategory] <> "OutWard" )
        - CALCULATE ( SUM ( GL[Amount] ), GL[SubCategory] = "OutWard" )
VAR premium =
    CALCULATE (
        CALCULATE ( SUM ( GL[Amount] ), GL[SubCategory] <> "OutWard" )
            - CALCULATE ( SUM ( GL[Amount] ), GL[SubCategory] = "OutWard" ),
        GL[Categroy] = "Premium"
    )
VAR claim =
    CALCULATE (
        CALCULATE ( SUM ( GL[Amount] ), GL[SubCategory] <> "OutWard" )
            - CALCULATE ( SUM ( GL[Amount] ), GL[SubCategory] = "OutWard" ),
        GL[Categroy] = "Claim"
    )
RETURN
    IF (
        ISFILTERED ( GL[Categroy] ),
        IF (
            ISFILTERED ( GL[SubCategory] ),
            SUM ( GL[Amount] ),
            CALCULATE ( categoryLevel, VALUES ( GL[Categroy] ) )
        ),
        premium - claim
    )


Changes = 
IF (
    ISFILTERED ( GL[SubCategory] ),
    SWITCH (
        SELECTEDVALUE ( GL[Categroy] ),
        "Premium", IF (
            SELECTEDVALUE ( GL[SubCategory] ) <> "In Stock",
            CALCULATE (
                SUM ( GL[Amount] ),
                VALUES ( GL[Categroy] ),
                VALUES ( GL[SubCategory] )
            )
                / CALCULATE (
                    SUM ( GL[Amount] ),
                    VALUES ( GL[Categroy] ),
                    GL[SubCategory] = "In Stock"
                )
        ),
        "Claim", IF (
            SELECTEDVALUE ( GL[SubCategory] ) <> "In Stock",
            CALCULATE (
                SUM ( GL[Amount] ),
                VALUES ( GL[Categroy] ),
                VALUES ( GL[SubCategory] )
            )
                / CALCULATE (
                    SUM ( GL[Amount] ),
                    GL[Categroy] = "Premium",
                    VALUES ( GL[SubCategory] )
                )
        )
    ),
    IF (
        SELECTEDVALUE ( GL[Categroy] ) = "Claim",
        DIVIDE (
            CALCULATE ( [Condition Total], GL[Categroy] = "Claim" ),
            CALCULATE ( [Condition Total], GL[Categroy] = "Premium" ),
            -1
        )
    )
)

 

 

3. Create matrix visual.

2.PNG

 

Full query:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WCihKzc0szVXSUTI0MICQQDpWB1nGCCxjiilhDJYwQRVXCErNzCsuLUrMS05V8MwrTyxKgSrCNANFrX9pCVSxKVixGUyxc05iZq6CS2ZRanIJRBzqXJySRiiSWB1kDlZojFMhwjUWCF/GAgA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [Metric = _t, #"GL Code" = _t, Amount = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Metric", type text}, {"GL Code", Int64.Type}, {"Amount", Int64.Type}}),
    #"Added Custom" = Table.AddColumn(#"Changed Type", "Categroy", each Text.Split([Metric]," "){0}),
    #"Grouped Rows" = Table.Group(#"Added Custom", {"Categroy"}, {{"Content", each Table.AddColumn(_, "SubCategory", each Text.AfterDelimiter([Metric],"Reinsurance ")), type table}}),
    #"Expanded Content" = Table.ExpandTableColumn(#"Grouped Rows", "Content", {"GL Code", "Amount", "SubCategory"}, {"GL Code", "Amount", "SubCategory"}),
    #"Reordered Columns" = Table.ReorderColumns(#"Expanded Content",{"Categroy", "SubCategory", "GL Code", "Amount"}),
    #"Replaced Value" = Table.ReplaceValue(#"Reordered Columns","","In Stock",Replacer.ReplaceValue,{"SubCategory"})
in
    #"Replaced Value"

 

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

4 REPLIES 4
v-shex-msft
Community Support
Community Support

Hi @satubuku83,

 

Since power bi tables not contains column index and row index, I think you need to add a index column to achieve this requirement.

 

Steps:

1. Add group index.

30.gif

2. Write measure.

% Changes = 
VAR index =
    MAX ( Metric[Index] )
VAR previous =
    LOOKUPVALUE ( Metric[Metric], [Index], index - 1 )
RETURN
    DIVIDE (
        CALCULATE ( SUM ( Metric[Amount] ), VALUES ( Metric[Metric] ) ),
        CALCULATE ( SUM ( Metric[Amount] ), Metric[Metric] = previous ),
        BLANK ()
    )

3. Create matrix visual.

24.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.

Hi Xiao Xin/ @v-shex-msft

 

Always happy to hear from you.  

 

Currently i am using Contains, will try out the method you suggested too!

% of Metric (Checking) = IF(CONTAINS('DIM_SOURCE',DIM_SOURCE[Metric],"Reinsurance"),DIVIDE([MTD Closing Balance],[MTD Gross Premium]),
if(CONTAINS('DIM_SOURCE',DIM_SOURCE[Metric],"Premium"),BLANK()))

 

Anyway, do you have any good way to do GL statement in Power BI? Its driving me crazy.

 

Assuming same data structure with additional data.

 

Metric

GL CodeAmount
Premium10010000
Premium2005000
Premium300400
Premium Reinsurance Inward4005000
Premium Reinsurance Outward5006000
Claim Direct600100
Claim Direct600200
Claim Reinsurance Inward700300
Claim Reinsurance Outward800400

 

Any clever way using DAX/ modeling to achieve the following? (ignore the remark - for your understanding purposes on the formulae)

 

Really appreciate for your time!

 

Remark for AmountMetricAmount% ChangesRemark for % Changes
 Premium15400  
 Premium Reinsurance Inward500032%Premium Reinsurance Inward / Premium
 Premium Reinsurance Outward600039%Premium Reinsurance Outward / Premium
Premium + Premium Reinsurance Inward - Premium Reinsurance OutwardGross Premium14400  
     
 Claim Direct3002%Claim Direct/ Premium
 Claim Reinsurance Inward3006%Claim Reinsurance Inward/ Premium Reinsurance Inward
 Claim Reinsurance Outward4007%Claim Reinsurance Inward/ Premium Reinsurance Outward
Claim Direct + Claim Reinsurance Inward - Claim Reinsurance OutwardGross Claim2001%Gross Claim/ Gross Premium
     
Gross Premium - Gross ClaimNet Amount14200  

 

Regards

CS

HI @satubuku83,

 

Actually, your requirement not very suitable for power bi. I think it should be more simply to achieve in excel pivot table.

I also shared power bi version below:

 

1. Grouping and transform table.

1.PNG

 

2. Write measure formulas:

Condition Total = 
VAR categoryLevel =
    CALCULATE ( SUM ( GL[Amount] ), GL[SubCategory] <> "OutWard" )
        - CALCULATE ( SUM ( GL[Amount] ), GL[SubCategory] = "OutWard" )
VAR premium =
    CALCULATE (
        CALCULATE ( SUM ( GL[Amount] ), GL[SubCategory] <> "OutWard" )
            - CALCULATE ( SUM ( GL[Amount] ), GL[SubCategory] = "OutWard" ),
        GL[Categroy] = "Premium"
    )
VAR claim =
    CALCULATE (
        CALCULATE ( SUM ( GL[Amount] ), GL[SubCategory] <> "OutWard" )
            - CALCULATE ( SUM ( GL[Amount] ), GL[SubCategory] = "OutWard" ),
        GL[Categroy] = "Claim"
    )
RETURN
    IF (
        ISFILTERED ( GL[Categroy] ),
        IF (
            ISFILTERED ( GL[SubCategory] ),
            SUM ( GL[Amount] ),
            CALCULATE ( categoryLevel, VALUES ( GL[Categroy] ) )
        ),
        premium - claim
    )


Changes = 
IF (
    ISFILTERED ( GL[SubCategory] ),
    SWITCH (
        SELECTEDVALUE ( GL[Categroy] ),
        "Premium", IF (
            SELECTEDVALUE ( GL[SubCategory] ) <> "In Stock",
            CALCULATE (
                SUM ( GL[Amount] ),
                VALUES ( GL[Categroy] ),
                VALUES ( GL[SubCategory] )
            )
                / CALCULATE (
                    SUM ( GL[Amount] ),
                    VALUES ( GL[Categroy] ),
                    GL[SubCategory] = "In Stock"
                )
        ),
        "Claim", IF (
            SELECTEDVALUE ( GL[SubCategory] ) <> "In Stock",
            CALCULATE (
                SUM ( GL[Amount] ),
                VALUES ( GL[Categroy] ),
                VALUES ( GL[SubCategory] )
            )
                / CALCULATE (
                    SUM ( GL[Amount] ),
                    GL[Categroy] = "Premium",
                    VALUES ( GL[SubCategory] )
                )
        )
    ),
    IF (
        SELECTEDVALUE ( GL[Categroy] ) = "Claim",
        DIVIDE (
            CALCULATE ( [Condition Total], GL[Categroy] = "Claim" ),
            CALCULATE ( [Condition Total], GL[Categroy] = "Premium" ),
            -1
        )
    )
)

 

 

3. Create matrix visual.

2.PNG

 

Full query:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WCihKzc0szVXSUTI0MICQQDpWB1nGCCxjiilhDJYwQRVXCErNzCsuLUrMS05V8MwrTyxKgSrCNANFrX9pCVSxKVixGUyxc05iZq6CS2ZRanIJRBzqXJySRiiSWB1kDlZojFMhwjUWCF/GAgA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [Metric = _t, #"GL Code" = _t, Amount = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Metric", type text}, {"GL Code", Int64.Type}, {"Amount", Int64.Type}}),
    #"Added Custom" = Table.AddColumn(#"Changed Type", "Categroy", each Text.Split([Metric]," "){0}),
    #"Grouped Rows" = Table.Group(#"Added Custom", {"Categroy"}, {{"Content", each Table.AddColumn(_, "SubCategory", each Text.AfterDelimiter([Metric],"Reinsurance ")), type table}}),
    #"Expanded Content" = Table.ExpandTableColumn(#"Grouped Rows", "Content", {"GL Code", "Amount", "SubCategory"}, {"GL Code", "Amount", "SubCategory"}),
    #"Reordered Columns" = Table.ReorderColumns(#"Expanded Content",{"Categroy", "SubCategory", "GL Code", "Amount"}),
    #"Replaced Value" = Table.ReplaceValue(#"Reordered Columns","","In Stock",Replacer.ReplaceValue,{"SubCategory"})
in
    #"Replaced Value"

 

Regards,

Xiaoxin Sheng

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

Hi XiaoXin /  

 

Yes indeed i feel doesnt really utilize/suit using Power BI with the GL thingy as well...not so easy to read and maintained, especially when i have more hierarchy and metrics.

 

Really appreciate for the help and time and effort for the solution.

 

Regards

CS

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.