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

Find everything you need to get certified on Fabric—skills challenges, live sessions, exam prep, role guidance, and more. Get started

Reply
valor
Regular Visitor

Summary table by year with start value from different table

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
Screenshot 2023-09-20 174644.png

 

Transaction table

Account historyAccount history

 

Here's the summary data I'd like to see and roll up by transaction date (year, quarter, month, etc)

Desired summaryDesired summary

 

 

[EDIT] Here's a link [Dropbox]  to the sample file I drew up if it's helpful

1 ACCEPTED SOLUTION
v-yiruan-msft
Community Support
Community Support

Hi @valor ,

I updated your sample pbix file(see the attachment), please find the details in it.

1. Create a date dimension table

vyiruanmsft_1-1695363940956.png

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

vyiruanmsft_0-1695363838689.png

Best Regards

Community Support Team _ Rena
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

1 REPLY 1
v-yiruan-msft
Community Support
Community Support

Hi @valor ,

I updated your sample pbix file(see the attachment), please find the details in it.

1. Create a date dimension table

vyiruanmsft_1-1695363940956.png

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

vyiruanmsft_0-1695363838689.png

Best Regards

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

Helpful resources

Announcements
Europe Fabric Conference

Europe’s largest Microsoft Fabric Community Conference

Join the community in Stockholm for expert Microsoft Fabric learning including a very exciting keynote from Arun Ulag, Corporate Vice President, Azure Data.

AugPowerBI_Carousel

Power BI Monthly Update - August 2024

Check out the August 2024 Power BI update to learn about new features.

August Carousel

Fabric Community Update - August 2024

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