Microsoft Fabric Community Conference 2025, March 31 - April 2, Las Vegas, Nevada. Use code FABINSIDER for a $400 discount.
Register nowThe Power BI DataViz World Championships are on! With four chances to enter, you could win a spot in the LIVE Grand Finale in Las Vegas. Show off your skills.
Hello all, I've been searching for a way to do this and can't come up with a way to do what I'm looking for.
This post is close, but doesn't get me to where I need to be:
Solved: Creating a combined summary table - Microsoft Fabric Community
I have a table of accounts, and a table of activity for those accounts and I want to generate a summary that I can summarize by Year/Quarter/Month. The problem is that the account's opening value isn't captured in the transaction, so I essentially need to take the oldest starting value for the account, then attribute that to the correct period.
The easiest would be to get the initial starting value into the "Net Change" column, but I can't modify the data source.
Thoughts on how I can do this in Power BI?
Here's a sample of my model:
Accounts table
Transaction table
Account history
Here's the summary data I'd like to see and roll up by transaction date (year, quarter, month, etc)
Desired summary
[EDIT] Here's a link [Dropbox] to the sample file I drew up if it's helpful
Solved! Go to Solution.
Hi @valor ,
I updated your sample pbix file(see the attachment), please find the details in it.
1. Create a date dimension table
2. Create a measure as below to get it
Measure =
VAR _selmonth =
SELECTEDVALUE ( 'Date'[Date].[MonthNo] )
VAR _selyear =
SELECTEDVALUE ( 'Date'[Date].[Year] )
VAR _initialvalue =
CALCULATE (
SUM ( 'Accounts'[Account start value (calculated)] ),
FILTER (
'Accounts',
YEAR ( 'Accounts'[Account start date] ) = _selyear
&& MONTH ( 'Accounts'[Account start date] ) = _selmonth
)
)
VAR _netchange =
CALCULATE (
SUM ( 'Account history'[Net change] ),
FILTER (
'Account history',
YEAR ( 'Account history'[Date] ) = _selyear
&& MONTH ( 'Account history'[Date] ) = _selmonth
)
)
RETURN
_initialvalue + _netchange
Best Regards
Hi @valor ,
I updated your sample pbix file(see the attachment), please find the details in it.
1. Create a date dimension table
2. Create a measure as below to get it
Measure =
VAR _selmonth =
SELECTEDVALUE ( 'Date'[Date].[MonthNo] )
VAR _selyear =
SELECTEDVALUE ( 'Date'[Date].[Year] )
VAR _initialvalue =
CALCULATE (
SUM ( 'Accounts'[Account start value (calculated)] ),
FILTER (
'Accounts',
YEAR ( 'Accounts'[Account start date] ) = _selyear
&& MONTH ( 'Accounts'[Account start date] ) = _selmonth
)
)
VAR _netchange =
CALCULATE (
SUM ( 'Account history'[Net change] ),
FILTER (
'Account history',
YEAR ( 'Account history'[Date] ) = _selyear
&& MONTH ( 'Account history'[Date] ) = _selmonth
)
)
RETURN
_initialvalue + _netchange
Best Regards
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!
Check out the February 2025 Power BI update to learn about new features.
User | Count |
---|---|
83 | |
78 | |
54 | |
39 | |
35 |
User | Count |
---|---|
98 | |
80 | |
50 | |
48 | |
48 |