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

Be one of the first to start using Fabric Databases. View on-demand sessions with database experts and the Microsoft product team to learn just how easy it is to get started. Watch now

Reply
Anonymous
Not applicable

Calculation using a previous row within a hierarchy

I'm wanting to do a calculation to create a column or calculated measure using 2 values on differing rows. My data is a flat file (excel) and the table shown below contains a hierachy that I've created. I'm wanting to forcast numbers by using the retention (calculated measure) from the previous block and mulitplying that my current enrolled. Block 1 forecast will always be 0 and the hierarchy levels above block will be a sum of the forecasted block 1 and 2. See example below, the green box indicates what I want to mulitple by.

BuistJames_0-1604399836633.png

Any help greatly appreciated and from my own digging around indexing seems the only option though getts messy with hierarchy.

1 ACCEPTED SOLUTION
v-yingjl
Community Support
Community Support

Hi @Anonymous ,

Based on your picture, I think it is the part of your data I will just focus on the forecast result ignoring the sum value of other two fields [Retention] and [Enrolled].

Also, since the [Retention] is a measure, I have created a simple sum measure to imitate it in my sample file:

 

Retention = SUM('Table'[value])

 

To get the previous row value in this case to calculate the forecast value, you can create this measure:

 

Forecast =
VAR tab =
    SUMMARIZE (
        'Table',
        'Table'[Department],
        'Table'[Class],
        'Table'[Block],
        'Table'[Enrolled],
        "prows",
            VAR _pre =
                CALCULATE (
                    MAXX ( 'Table', [Retention] ),
                    FILTER (
                        ALL ( 'Table' ),
                        'Table'[Department] IN DISTINCT ( 'Table'[Department] )
                            && 'Table'[Class] IN DISTINCT ( 'Table'[Class] )
                            && 'Table'[Block]
                                = CALCULATE (
                                    MAX ( 'Table'[Block] ),
                                    FILTER (
                                        ALL ( 'Table' ),
                                        'Table'[Department] IN DISTINCT ( 'Table'[Department] )
                                            && 'Table'[Class] IN DISTINCT ( 'Table'[Class] )
                                            && 'Table'[Block] < MAX ( 'Table'[Block] )
                                    )
                                )
                    )
                )
            RETURN
                IF ( ISBLANK ( _pre ), 0, _pre )
    )
RETURN
    SUMX ( tab, [prows] * [Enrolled] )

 

M.png

Attached my sample file in the below, hopes to help you.

 

Best Regards,
Community Support Team _ Yingjie Li
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

2 REPLIES 2
v-yingjl
Community Support
Community Support

Hi @Anonymous ,

Based on your picture, I think it is the part of your data I will just focus on the forecast result ignoring the sum value of other two fields [Retention] and [Enrolled].

Also, since the [Retention] is a measure, I have created a simple sum measure to imitate it in my sample file:

 

Retention = SUM('Table'[value])

 

To get the previous row value in this case to calculate the forecast value, you can create this measure:

 

Forecast =
VAR tab =
    SUMMARIZE (
        'Table',
        'Table'[Department],
        'Table'[Class],
        'Table'[Block],
        'Table'[Enrolled],
        "prows",
            VAR _pre =
                CALCULATE (
                    MAXX ( 'Table', [Retention] ),
                    FILTER (
                        ALL ( 'Table' ),
                        'Table'[Department] IN DISTINCT ( 'Table'[Department] )
                            && 'Table'[Class] IN DISTINCT ( 'Table'[Class] )
                            && 'Table'[Block]
                                = CALCULATE (
                                    MAX ( 'Table'[Block] ),
                                    FILTER (
                                        ALL ( 'Table' ),
                                        'Table'[Department] IN DISTINCT ( 'Table'[Department] )
                                            && 'Table'[Class] IN DISTINCT ( 'Table'[Class] )
                                            && 'Table'[Block] < MAX ( 'Table'[Block] )
                                    )
                                )
                    )
                )
            RETURN
                IF ( ISBLANK ( _pre ), 0, _pre )
    )
RETURN
    SUMX ( tab, [prows] * [Enrolled] )

 

M.png

Attached my sample file in the below, hopes to help you.

 

Best Regards,
Community Support Team _ Yingjie Li
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

 

amitchandak
Super User
Super User

@Anonymous , Can you share sample data and sample output in table format? Or a sample pbix after removing sensitive data.

Join us as experts from around the world come together to shape the future of data and AI!
At the Microsoft Analytics Community Conference, global leaders and influential voices are stepping up to share their knowledge and help you master the latest in Microsoft Fabric, Copilot, and Purview.
️ November 12th-14th, 2024
 Online Event
Register Here

Helpful resources

Announcements
Las Vegas 2025

Join us at the Microsoft Fabric Community Conference

March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!

Dec Fabric Community Survey

We want your feedback!

Your insights matter. That’s why we created a quick survey to learn about your experience finding answers to technical questions.

ArunFabCon

Microsoft Fabric Community Conference 2025

Arun Ulag shares exciting details about the Microsoft Fabric Conference 2025, which will be held in Las Vegas, NV.

December 2024

A Year in Review - December 2024

Find out what content was popular in the Fabric community during 2024.