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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
Catherine84
Helper I
Helper I

To convert MTD data to YTD but with 3 variables

Hi all,

 

I will like to seek your kind help. I am pretty new to power BI and running into trouble getting the correct formulas.

 

I have a set of data below. Q1 numbers are correct. Q2,Q3 and Q4 are all YTD numbers and i need to create another columns to get the it to reflect QTD numbers

 

I have been trying but its not working, not sure if you all can help. I have quite a few items that must consider Ie RU, account code, year. Not sure how to gel them! 

 

Value2 = VAR pq = IF ( [Period] = "Q1", "Q2", "Q1" ) RETURN IF ( [Period] = "Q1", [Amount], [Amount] - CALCULATE ( MAX ( [Amount] ), FILTER ( ALL ( table ), [Year] = EARLIER ( [Year] ) && [Period] = pq), Filter([Table],[RU n  Account code]=[RU]&[Account code]) ) )

 

 

Thanks in Advance

 

RU

Account code

Period

Year

 YTD Amount

XYZ Co

Salaries and Wages

Q1

2017

20

XYZ Co

Salaries and Wages

Q2

2017

30

XYZ Co

Salaries and Wages

Q3

2017

45

XYZ Co

Salaries and Wages

Q4

2017

80

XYZ Co

Salaries and Wages

Q1

2016

30

XYZ Co

Salaries and Wages

Q2

2016

50

XYZ Co

Salaries and Wages

Q3

2016

55

XYZ Co

Salaries and Wages

Q4

2016

80

ABC Co

Salaries and Wages

Q1

2017

34

ABC Co

Salaries and Wages

Q2

2017

60

ABC Co

Salaries and Wages

Q3

2017

75

ABC Co

Salaries and Wages

Q4

2017

100

ABC Co

Salaries and Wages

Q1

2016

20

ABC Co

Salaries and Wages

Q2

2016

43

ABC Co

Salaries and Wages

Q3

2016

54

ABC Co

Salaries and Wages

Q4

2016

80

XYZ Co

Bonus

Q1

2017

10

XYZ Co

Bonus

Q2

2017

20

XYZ Co

Bonus

Q3

2017

24

XYZ Co

Bonus

Q4

2017

32

XYZ Co

Bonus

Q1

2016

3

XYZ Co

Bonus

Q2

2016

5

XYZ Co

Bonus

Q3

2016

10

XYZ Co

Bonus

Q4

2016

15

XYZ Co

Bonus

Q1

2017

30

XYZ Co

Bonus

Q2

2017

43

XYZ Co

Bonus

Q3

2017

60

XYZ Co

Bonus

Q4

2017

75

XYZ Co

Bonus

Q1

2016

12

XYZ Co

Bonus

Q2

2016

25

XYZ Co

Bonus

Q3

2016

56

XYZ Co

Bonus

Q4

2016

76

2 ACCEPTED SOLUTIONS
Sean
Community Champion
Community Champion

Hi @Catherine84 ,

I would suggest shaping the data better first In the Query Editor

1) select the Period column - Transform tab - click Extract - select Last Characters - type 1 - OK

2) change the Data Type of the Period column to Whole Number

3) click Group By - select Advanced

4) add these 4 groupings - RU - Account Code - Year - Period

5) for New column name - type - YTD Amount

6) for Operation - select - Sum

7) for Column - select - YTD Amount - OK

😎 Close and Apply

9) Finally create a New Column (this would be a DAX column)

DAX Amount =
VAR Company = Table1[RU]
VAR Code = Table1[Account code]
VAR CYear = Table1[Year]
VAR CQuarter = Table1[Period] // Period column is Number (1, 2, 3, 4) representing Quarters
RETURN
    [YTD Amount]
        - CALCULATE (
            SUM ( Table1[YTD Amount] ),
            FILTER (
                Table1,
                Table1[RU] = Company
                    && Table1[Account code] = Code
                    && Table1[Year] = CYear
                    && Table1[Period] = CQuarter - 1
            )
        )

DAX Amount V2 =
VAR Company = Table1[RU]
VAR Code = Table1[Account code]
VAR CYear = Table1[Year]
VAR CQuarter = Table1[Quarter] // Quarter column is Text (Q1, Q2, Q3, Q4)
RETURN
    Table1[YTD Amount]
        - CALCULATE (
            MAX ( Table1[YTD Amount] ), //Have to use MAX!
            FILTER (
                Table1,
                Table1[RU] = Company
                    && Table1[Account code] = Code
                    && Table1[Year] = CYear
                    && Table1[Quarter] < CQuarter
            )
        )

That should do it! Smiley Happy

Now you data is shaped better and this new Amount column will show you the total per each Quarter only.

I'm sure ImkeF can probably do my last DAX step with M as well Smiley Happy

 

Convert YTD to QTD.gif

 

Convert YTD to QTD.png

 

View solution in original post

@Sean

Actually, I've written a function some time ago, that would make this task fairly easy: https://www.thebiccountant.com/2018/08/31/unravel-cumulative-totals-to-their-initial-elements-in-pow...

Imke Feldmann (The BIccountant)

If you liked my solution, please give it a thumbs up. And if I did answer your question, please mark this post as a solution. Thanks!

How to integrate M-code into your solution -- How to get your questions answered quickly -- How to provide sample data -- Check out more PBI- learning resources here -- Performance Tipps for M-queries

View solution in original post

20 REPLIES 20
Ashish_Mathur
Super User
Super User

Hi,

 

So the result you want for the first 4 rows are 20,10,15,35.  Am i correct?  Also, do you want this to be a measure or a calculated column?


Regards,
Ashish Mathur
http://www.ashishmathur.com
https://www.linkedin.com/in/excelenthusiasts/

Yes Ashish. Thanks for replying. Yes correct I need the first 4 rows to be 20,10,15,35.. It will be great if this can be a measure!

Hi,

 

I have made the following assumptions:

 

  1. There is a Calendar Table
  2. There is a relationship from the Date column of your base data table to the Date column of your Calednar Table
  3. In the Calendar Table, you also have the Period and Year columns
  4. The Period and year columns in your visual have been dragged from the Calendar Table
  5. The YTD amount column is a measure written as =SUM(Data[Amount])
  6. Try this measure

=[YTD amount]-CALCULATE([YTD Amount],PREVIOUSQUARTER(Calendar[Date]))

 

Hope this helps.


Regards,
Ashish Mathur
http://www.ashishmathur.com
https://www.linkedin.com/in/excelenthusiasts/

Hi Ashish,
There is no calendar table.. The data just comes in ytd q1, ytd q2, ytd q3 and ytd q4. But I need to calculate some Profit and loss accounts using mtd data so trying to break them up.. But not sure how to minus between the rows..

Hope u can help me ! 🙂

Hi,

 

Share the link from where i can download your PBI file.


Regards,
Ashish Mathur
http://www.ashishmathur.com
https://www.linkedin.com/in/excelenthusiasts/

 

 

Hi Ashish,

 

I have put up the publish the power BI in the link below:

 

https://app.powerbi.com/groups/me/reports/0191ed47-064f-41a9-ae40-b87f52bb2ddf?ctid=57368c21-b8cf-42...

 

Although my data do not have a calendar table, i tried to insert one and tried to name the Q1, Q2,Q3,Q4 into the calendar dates but still i cannot get the MTD data only. It seems to be still showing year to date data!

 

 

 Capture.png

 

Hi,

 

There is no PBI file there.  Share the link from where i can download the PBI file.


Regards,
Ashish Mathur
http://www.ashishmathur.com
https://www.linkedin.com/in/excelenthusiasts/

Hi Ashish,
Thanks for your kind help!! I tried to publish but it will not publish with the desktop functionality.
Is there any where I can read on how to publish the pbi file?

Thanks!

Hi,

 

If you still need my help, you may upload the PBI file to OneDrive/Google Drive and then share the download link here.


Regards,
Ashish Mathur
http://www.ashishmathur.com
https://www.linkedin.com/in/excelenthusiasts/

Thanks Ashish! I will do it next time 🙂 appreciate your kind help!
Sean
Community Champion
Community Champion

Hi @Catherine84 ,

I would suggest shaping the data better first In the Query Editor

1) select the Period column - Transform tab - click Extract - select Last Characters - type 1 - OK

2) change the Data Type of the Period column to Whole Number

3) click Group By - select Advanced

4) add these 4 groupings - RU - Account Code - Year - Period

5) for New column name - type - YTD Amount

6) for Operation - select - Sum

7) for Column - select - YTD Amount - OK

😎 Close and Apply

9) Finally create a New Column (this would be a DAX column)

DAX Amount =
VAR Company = Table1[RU]
VAR Code = Table1[Account code]
VAR CYear = Table1[Year]
VAR CQuarter = Table1[Period] // Period column is Number (1, 2, 3, 4) representing Quarters
RETURN
    [YTD Amount]
        - CALCULATE (
            SUM ( Table1[YTD Amount] ),
            FILTER (
                Table1,
                Table1[RU] = Company
                    && Table1[Account code] = Code
                    && Table1[Year] = CYear
                    && Table1[Period] = CQuarter - 1
            )
        )

DAX Amount V2 =
VAR Company = Table1[RU]
VAR Code = Table1[Account code]
VAR CYear = Table1[Year]
VAR CQuarter = Table1[Quarter] // Quarter column is Text (Q1, Q2, Q3, Q4)
RETURN
    Table1[YTD Amount]
        - CALCULATE (
            MAX ( Table1[YTD Amount] ), //Have to use MAX!
            FILTER (
                Table1,
                Table1[RU] = Company
                    && Table1[Account code] = Code
                    && Table1[Year] = CYear
                    && Table1[Quarter] < CQuarter
            )
        )

That should do it! Smiley Happy

Now you data is shaped better and this new Amount column will show you the total per each Quarter only.

I'm sure ImkeF can probably do my last DAX step with M as well Smiley Happy

 

Convert YTD to QTD.gif

 

Convert YTD to QTD.png

 

@Sean

Actually, I've written a function some time ago, that would make this task fairly easy: https://www.thebiccountant.com/2018/08/31/unravel-cumulative-totals-to-their-initial-elements-in-pow...

Imke Feldmann (The BIccountant)

If you liked my solution, please give it a thumbs up. And if I did answer your question, please mark this post as a solution. Thanks!

How to integrate M-code into your solution -- How to get your questions answered quickly -- How to provide sample data -- Check out more PBI- learning resources here -- Performance Tipps for M-queries

Sean
Community Champion
Community Champion

Thanks to @ImkeF we now have the M solution as well Smiley Happy

Although she says "Referencing a previous row in DAX is still faster than my method" lets follow the steps...

Please NOTE: @ImkeF's solution does NOT require you to perform ANY of the steps in my original post!

Also you can or rather should follow her on Twitter as she posted about this topic on Aug 31, 2018

 

But back in Query Editor I'll continue from where I left off just to compare the DAX results to the M results.

10) Home tab - New Source - Blank Query - Advanced Editor

11) Go here and copy the function code (Ctrl+C) and Thank @ImkeF

12) Paste the function (Ctrl+V) in the Advanced Editor - Done

13) Rename the Query - fnGetPreviousRow

14) Back to Table1 - add a step after the Grouped Rows Step - click fx

15) in the formula bar enter the code provided in ImkeF's blog post here

 

fnGetPreviousRow(#"Grouped Rows", null, {"YTD Amount"}, {"Account code", "Year"}, null, null)

16) right-click the newly created YTD Amount.Prev column - Replace Values - null - 0 - OK

 

17) change Data Type to Decimal Number

18) Add Column tab - Custom Column - QTD Amount - [YTD Amount]-[YTD Amount.Prev] - OK

19) change Data Type to Decimal Number

20) you can now remove the YTD Amount.Prev column if you wish

21) Home tab - Close & Apply

As expected the results are the same! Smiley Happy

 

Convert YTD to QTD - M.gif

 

Thanks! Smiley Happy

I'm pretty sure we can find a DAX solution to this without Grouping By first as well. But I'm done for the day Smiley Wink

@OwenAuger@Phil_Seamark

The pure DAX-solution could look like so: 

 

QtlyAmount =
Table1[ YTD Amount]
    - CALCULATE (
        MAX ( Table1[ YTD Amount] ),
        FILTER (
            Table1,
            Table1[Account code] = EARLIER ( Table1[Account code] )
                && Table1[Year] = EARLIER ( Table1[Year] )
                && Table1[RU] = EARLIER ( Table1[RU] )
                && Table1[Period] < EARLIER ( Table1[Period] )
        )
    )

This function is not as portable as the M-function, as it requires a bit more typing. 

BTW: I assumed that there is an error in the source data and there should be no duplicate attribute combinations. So replacing the last 8 rows with "ABC Co" instead of "XYZ Co". (Otherwise one should aggregate these rows in the query editor before).

Imke Feldmann (The BIccountant)

If you liked my solution, please give it a thumbs up. And if I did answer your question, please mark this post as a solution. Thanks!

How to integrate M-code into your solution -- How to get your questions answered quickly -- How to provide sample data -- Check out more PBI- learning resources here -- Performance Tipps for M-queries

Or an optimized version that calculates faster: 

 

QtlyAmount_Fast = 
Table1[ YTD Amount]
    - CALCULATE (
        MAX ( Table1[ YTD Amount]),
        FILTER ( Table1, Table1[Account code] = EARLIER ( Table1[Account code] ) ),
        FILTER ( Table1, Table1[Year] = EARLIER ( Table1[Year] ) ),
        FILTER ( Table1, Table1[RU] = EARLIER ( Table1[RU] ) ),
        FILTER ( Table1, Table1[Period] < EARLIER ( Table1[Period] ) )
        )

 

Imke Feldmann (The BIccountant)

If you liked my solution, please give it a thumbs up. And if I did answer your question, please mark this post as a solution. Thanks!

How to integrate M-code into your solution -- How to get your questions answered quickly -- How to provide sample data -- Check out more PBI- learning resources here -- Performance Tipps for M-queries

Possibly, this is even faster, please try it out:

 

QtlyAmount_Faster = 
VAR ThisAccountCode = Table1[Account code]
VAR ThisYear = Table1[Year]
VAR ThisRU = Table1[RU]
VAR ThisPeriod = Table1[Period]
Return
Table1[ YTD Amount]
    - CALCULATE (
        MAX ( Table1[ YTD Amount]),
        FILTER ( Table1, Table1[Account code] = ThisAccountCode ),
        FILTER ( Table1, Table1[Year] = ThisYear ),
        FILTER ( Table1, Table1[RU] = ThisRU ),
        FILTER ( Table1, Table1[Period] < ThisPeriod )
        )

Imke Feldmann (The BIccountant)

If you liked my solution, please give it a thumbs up. And if I did answer your question, please mark this post as a solution. Thanks!

How to integrate M-code into your solution -- How to get your questions answered quickly -- How to provide sample data -- Check out more PBI- learning resources here -- Performance Tipps for M-queries

Sean
Community Champion
Community Champion

@ImkeF

Indeed there's absolutely no need for all conditions in my original solution!

So here's the revised solution when the Quarter column is Text

DAX Amount V2 =
VAR Company = Table1[RU]
VAR Code = Table1[Account code]
VAR CYear = Table1[Year]
VAR CQuarter = Table1[Quarter] // Quarter column is Text (Q1, Q2, Q3, Q4)
RETURN
    Table1[YTD Amount]
        - CALCULATE (
            MAX ( Table1[YTD Amount] ), //Have to use MAX!
            FILTER (
                Table1,
                Table1[RU] = Company
                    && Table1[Account code] = Code
                    && Table1[Year] = CYear
                    && Table1[Quarter] < CQuarter
            )
        )

And when the Quarter column is Number

DAX Amount =
VAR Company = Table1[RU]
VAR Code = Table1[Account code]
VAR CYear = Table1[Year]
VAR CQuarter = Table1[Period] // Period column is Number (1, 2, 3, 4) representing Quarters
RETURN
    [YTD Amount]
        - CALCULATE (
            SUM ( Table1[YTD Amount] ),
            FILTER (
                Table1,
                Table1[RU] = Company
                    && Table1[Account code] = Code
                    && Table1[Year] = CYear
                    && Table1[Period] = CQuarter - 1
            )
        )

BTW I agree about the source data that there should be no duplicate attribute combinations!

 

That's really all for tonight folks! Smiley Happy

@Sean s version with the quarter number has the big advantage that it caters for possible negative numbers as well!

 

If performance is an issue, consider splitting up the conditions into different filters like in my last code.

Imke Feldmann (The BIccountant)

If you liked my solution, please give it a thumbs up. And if I did answer your question, please mark this post as a solution. Thanks!

How to integrate M-code into your solution -- How to get your questions answered quickly -- How to provide sample data -- Check out more PBI- learning resources here -- Performance Tipps for M-queries

Thanks Sean ! It works! 🙂 really appreciate your help!

Thanks ! I will revert once I get to the computer tonight 🙂 appreciate your kind help! 🙂

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

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

April Fabric Community Update

Fabric Community Update - April 2024

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