cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
Highlighted
Helper IV
Helper IV

Get Previous Running Total for Missing Month

Hi All,

 

I want to make accumulative line graph of which line should always increase.

- Even though there is missing month for each item, the month should exist with previous value.

so the graph must not decrease or cut for the missing month.

Let say I have two tables like below, the 'Date' table and 'ShipQty' table has relation in date column.

X axis: Date, Y axis: Qty

 

image.png

 

image.png

 

 

image.png

 

 

Please kindly help me.

 

Thanks in advance.

 

 

1 ACCEPTED SOLUTION

Accepted Solutions
Highlighted
Community Support
Community Support

Re: Get Previous Running Total for Missing Month

Hi, @DanielLinda 

 

Based on your description, I created data to reproduce your scenario. The pbix file is attached in the end.

ShipQty:

f1.png

 

Date:

Date = CALENDAR(DATE(2001,1,1),DATE(2022,12,31))

 

There is a relationship between two tables.

 

You may create  calculated columns and a measure as below.

Calculated column:
YearMonth = VALUE(FORMAT('Date'[Date],"yyyymm"))
YearMonthDay = FORMAT('Date'[Date],"yyyy-mm-"&"01")
YearMonth2 = VALUE(FORMAT(ShipQty[Date],"yyyymm"))

Measure:
Result = 
CALCULATE(
    SUM(ShipQty[Qty]),
    FILTER(
        ALL(ShipQty),
        ShipQty[Item] = SELECTEDVALUE(ShipQty[Item])&&
        ShipQty[YearMonth2]<=SELECTEDVALUE('Date'[YearMonth])
    )
)

 

Result:

f2.png

 

Best Regards

Allan

 

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

2 REPLIES 2
Highlighted
Super User IV
Super User IV

Re: Get Previous Running Total for Missing Month

Right, so normally the way you tackle this is to have a separate, (sometimes unrelated) calendar table with all the dates. You use the date column from this in your visualization and code your measure like this:

 

Cumulative Measure =
  VAR __Date = MAX('Calendar'[Date])
RETURN
  SUMX(FILTER('Table','Table'[Date] <= __Date),[Column])

 


---------------------------------------

Putting square pegs in round holes since 1972.

I have a NEW book! 
DAX Cookbook from Packt
Over 120 DAX Recipes!




Did I answer your question? Mark my post as a solution!

Proud to be a Super User!




Highlighted
Community Support
Community Support

Re: Get Previous Running Total for Missing Month

Hi, @DanielLinda 

 

Based on your description, I created data to reproduce your scenario. The pbix file is attached in the end.

ShipQty:

f1.png

 

Date:

Date = CALENDAR(DATE(2001,1,1),DATE(2022,12,31))

 

There is a relationship between two tables.

 

You may create  calculated columns and a measure as below.

Calculated column:
YearMonth = VALUE(FORMAT('Date'[Date],"yyyymm"))
YearMonthDay = FORMAT('Date'[Date],"yyyy-mm-"&"01")
YearMonth2 = VALUE(FORMAT(ShipQty[Date],"yyyymm"))

Measure:
Result = 
CALCULATE(
    SUM(ShipQty[Qty]),
    FILTER(
        ALL(ShipQty),
        ShipQty[Item] = SELECTEDVALUE(ShipQty[Item])&&
        ShipQty[YearMonth2]<=SELECTEDVALUE('Date'[YearMonth])
    )
)

 

Result:

f2.png

 

Best Regards

Allan

 

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

Helpful resources

Announcements
Community Blog

Community Blog

Visit our Community Blog for articles, guides, and information created by fellow community members.

Using the Community

Using the Community

Need help with the Power BI Community? Our 'Using the Community' support articles are a great place to start.

Community Summit North America

Community Summit North America

Innovate, Collaborate, Grow. The top training and networking event across the globe for Microsoft Business Applications

Power Platform 2020 release wave 2 plan

Power Platform 2020 release wave 2 plan

Features releasing from October 2020 through March 2021

Top Solution Authors
Top Kudoed Authors