Power BI is turning 10, and we’re marking the occasion with a special community challenge. Use your creativity to tell a story, uncover trends, or highlight something unexpected.
Get startedJoin 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.
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.
Any help greatly appreciated and from my own digging around indexing seems the only option though getts messy with hierarchy.
Solved! Go to Solution.
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] )
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.
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] )
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.
This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.
Check out the June 2025 Power BI update to learn about new features.
User | Count |
---|---|
56 | |
55 | |
54 | |
37 | |
29 |
User | Count |
---|---|
77 | |
62 | |
45 | |
40 | |
40 |