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

Join us for an expert-led overview of the tools and concepts you'll need to become a Certified Power BI Data Analyst and pass exam PL-300. Register 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.

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
Join our Fabric User Panel

Join our Fabric User Panel

This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.

June 2025 Power BI Update Carousel

Power BI Monthly Update - June 2025

Check out the June 2025 Power BI update to learn about new features.

June 2025 community update carousel

Fabric Community Update - June 2025

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