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
PotaePango
New Member

Aging Bucket as a Measure for Current Back Orders

Hi all,

 

I've just getting started with Power BI and created a report for current backorders for our office. I have report setup and perfect for our needs but I can't for the life of me figure this one out (if it's possible). For some context, the data set is a live data set hosted in the cloud so I'm unable to create calculated columns (this would be an easy solution if I could). 

 

As part of the report, I would like to show the number of current back orders that are:

  • less than a week
  • 1 to 4 weeks
  • 4 - 12 weeks
  • over 12 weeks

 

I've tried to create a DAX measure that shows the number of days a product has been on back order with this formula below but I'm getting nowhere.

No. of Days on Back Order = SUMX('Order', DATEDIFF('Order'[OrderCreatedDate], Today(),DAY))
 
Any help is much appreciated
 

 

 

1 ACCEPTED SOLUTION
FreemanZ
Super User
Super User

hi   @PotaePango 

try to create four measures like this:
 
OrdersWthin1Week =
CALCULATE(
    COUNTROWS('Order'),
    'Order'[OrderCreatedDate]>=TODAY()-6
)
 
Orders1To4Weeks =
CALCULATE(
    COUNTROWS('Order'),
    'Order'[OrderCreatedDate]< TODAY()-6
        &&'Order'[OrderCreatedDate]>=TODAY()-27
)
 
Orders4To12Weeks =
CALCULATE(
    COUNTROWS('Order'),
    'Order'[OrderCreatedDate]< TODAY()-27
        &&'Order'[OrderCreatedDate]>=TODAY()-83
)
 
OrdersOver12Weeks =
CALCULATE(
    COUNTROWS('Order'),
    'Order'[OrderCreatedDate]< TODAY()-84
)
 
You might need to fine tune the cut-off days, like 6 or 7, >= or >.

View solution in original post

3 REPLIES 3
v-yangliu-msft
Community Support
Community Support

Hi  @PotaePango ,

I created some data:

vyangliumsft_0-1672116574974.png

Here are the steps you can follow:

1. Create calculated column.

Week =
WEEKNUM('Table'[Date])

vyangliumsft_1-1672116574975.png

2. Enter data – Create table.

vyangliumsft_2-1672116574976.png

3. Create measure.

Flag =
VAR _today =
    TODAY ()
VAR _weektoday =
    WEEKNUM ( _today )
RETURN
    SWITCH (
        TRUE (),
        MAX ( 'Table2'[Group] ) = "less than a week",
            CALCULATE (
                DISTINCTCOUNT ( 'Table'[goods] ),
                FILTER ( ALL ( 'Table' ), 'Table'[Week] = _weektoday )
            ),
        MAX ( 'Table2'[Group] ) = "1 to 4 weeks",
            CALCULATE (
                DISTINCTCOUNT ( 'Table'[goods] ),
                FILTER (
                    ALL ( 'Table' ),
                    'Table'[Week] >= _weektoday - 4
                        && 'Table'[Week] < _weektoday
                )
            ),
        MAX ( 'Table2'[Group] ) = "4 - 12 weeks",
            CALCULATE (
                DISTINCTCOUNT ( 'Table'[goods] ),
                FILTER (
                    ALL ( 'Table' ),
                    'Table'[Week] >= _weektoday - 12
                        && 'Table'[Week] < _weektoday - 4
                )
            ),
        MAX ( 'Table2'[Group] ) = "over 12 weeks",
            CALCULATE (
                DISTINCTCOUNT ( 'Table'[goods] ),
                FILTER ( ALL ( 'Table' ), 'Table'[Week] < _weektoday - 12 )
            )
    )

4. Select [Group] – Column tools – Sort by column –[Index].

vyangliumsft_3-1672116574978.png

5. Result:

vyangliumsft_4-1672116574982.png

 

Best Regards,

Liu Yang

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly

FreemanZ
Super User
Super User

hi   @PotaePango 

try to create four measures like this:
 
OrdersWthin1Week =
CALCULATE(
    COUNTROWS('Order'),
    'Order'[OrderCreatedDate]>=TODAY()-6
)
 
Orders1To4Weeks =
CALCULATE(
    COUNTROWS('Order'),
    'Order'[OrderCreatedDate]< TODAY()-6
        &&'Order'[OrderCreatedDate]>=TODAY()-27
)
 
Orders4To12Weeks =
CALCULATE(
    COUNTROWS('Order'),
    'Order'[OrderCreatedDate]< TODAY()-27
        &&'Order'[OrderCreatedDate]>=TODAY()-83
)
 
OrdersOver12Weeks =
CALCULATE(
    COUNTROWS('Order'),
    'Order'[OrderCreatedDate]< TODAY()-84
)
 
You might need to fine tune the cut-off days, like 6 or 7, >= or >.

Thank you, this solution worked for me 😁

 

Instead of having CALCULATE(COUNTROWS('Order') in the formula, I used a [Back Order Quantity] measure and this worked perfectly for our needs.

Helpful resources

Announcements
Fabcon_Europe_Social_Bogo

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.

Power BI Carousel June 2024

Power BI Monthly Update - June 2024

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

PBI_Carousel_NL_June

Fabric Community Update - June 2024

Get the latest Fabric updates from Build 2024, key Skills Challenge voucher deadlines, top blogs, forum posts, and product ideas.

RTI Forums Carousel3

New forum boards available in Real-Time Intelligence.

Ask questions in Eventhouse and KQL, Eventstream, and Reflex.