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

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.