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

The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now! Learn more

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.

Share with Power BI Enthusiasts: Full Power BI Video (20 Hours) YouTube
Microsoft Fabric Series 60+ Videos YouTube
Microsoft Fabric Hindi End to End YouTube

Helpful resources

Announcements
Power BI DataViz World Championships

Power BI Dataviz World Championships

The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now!

December 2025 Power BI Update Carousel

Power BI Monthly Update - December 2025

Check out the December 2025 Power BI Holiday Recap!

FabCon Atlanta 2026 carousel

FabCon Atlanta 2026

Join us at FabCon Atlanta, March 16-20, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.