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

Earn the coveted Fabric Analytics Engineer certification. 100% off your exam for a limited time only!

Reply
Anonymous
Not applicable

Calculated Column: calculate ranking of deliveries per orderNo

Hi all,

 

I have a table with ordered materials with the according order numbers and delivery numbers for when an item was shipped, every delivery no has a creation date.

 

One order can be send out in multiple deliveries. E.g. when I order 100 phones with order no 749, and only 80 were in stock, first a shipment of 80 goes out (delivery no 633) and on a later date the remaining 20 (delivery no 655)

With a distinct count of delivery no’s for every order no’s I can determine the number of shipments that was needed to fulfill the order.

 

However I also want (as endgoal) to determine how many items were shipped in the first shipment, how many in the second etc.

 

For this I want to create a column that indicates for each shipment no, if it was the first, second, or third etc. shipment for the order, based on the creation date.

 

In Excel I do this manually now by first combining the order.no and delivery.no to make a unique number. Then create a pivot table and put in the order.no, the unique combined no and the creation date. I sort by delivery no low-high (higher number is in principle later delivery) and oldest-new for creation date. Then with some manual excel tricks I form this into a ranking. I use this with vlookup to insert into my table.

 

However, I would like to automate this in Power BI using DAX.

 

Given the above, does anyone know which DAX formula to use to get a column with the ranking of deliveries per order based on either only the delivery no’s belonging to the order.no or possibly also the creation date as well as extra assurance?

 

So to summarize:

I have [CreationDate] [DeliveryNo] [OrderNo] for a list of materials.
With DAX formula I want to create calculated column ‘Delivery #’ that ranks DeliveryNo for each OrderNo based on either DeliveryNo’s numeric value or the associated Creation date.

 

Example output in Excel:

Example.PNG

 

Any help is appreciated. A smarter way to directly reach my endgoal in one calculation would also be awesome 😉

 

Thanks,

Martin

 

p.s. apologies if this is posted twice, my first attempt is nowhere to be found.

 

1 ACCEPTED SOLUTION
Vvelarde
Community Champion
Community Champion

 

@Anonymous

 

Hi, please try with this calculated column:

 

Rank =
RANKX (
    FILTER ( Table2, Table2[OrderNo] = EARLIER ( Table2[OrderNo] ) ),
    Table2[Creation Date],
    ,
    ASC,
    DENSE
)

 

Rankx.png

 

Regards

 

Victor

Lima - Peru




Lima - Peru

View solution in original post

3 REPLIES 3
Vvelarde
Community Champion
Community Champion

 

@Anonymous

 

Hi, please try with this calculated column:

 

Rank =
RANKX (
    FILTER ( Table2, Table2[OrderNo] = EARLIER ( Table2[OrderNo] ) ),
    Table2[Creation Date],
    ,
    ASC,
    DENSE
)

 

Rankx.png

 

Regards

 

Victor

Lima - Peru




Lima - Peru
Anonymous
Not applicable

As there are issues getting this thread visible, I'm replying now to attempt to get it visible in the thread list.
edit: that worked 🙂

Anonymous
Not applicable

Hi all,

 

 

I have a table with ordered materials with the according order numbers and delivery numbers for when an item was shipped, every delivery no has a creation date.

 

One order can be send out in multiple deliveries. E.g. when I order 100 phones with order no 749, and only 80 were in stock, first a shipment of 80 goes out (delivery no 633) and on a later date the remaining 20 (delivery no 655).

 

With a distinct count of delivery no’s for every order no’s I can determine the number of shipments that was needed to fulfill the order.

 

However I also want to determine how many items were shipped in the first shipment, how many in the second etc.

For this I want to create a column that indicates for each shipment no, if it was the first, second, or third etc. shipment for the order, based on the creation date.

 

In Excel I do this manually now by first combining the order.no and delivery.no to make a unique number. Then create a pivot table and put in the order.no, the unique combined no and the creation date. I sort by delivery no low-high (higher number is in principle later delivery) and oldest-new for creation date. Then with some manual excel tricks I form this into a ranking. I use this with vlookup to insert into my table.

 

However, I would like to automate this in Power BI using DAX.

 

Given the above, does anyone know which DAX formula to use to get a column with the ranking of deliveries per order based on either only the delivery no’s belonging to the order.no or possibly also the creation date as well as extra assurance?

 

So to summarize:

 

I have [CreationDate] [DeliveryNo] [OrderNo] for a list of materials.
With DAX formula I want to create calculated column ‘Delivery #’ that ranks DeliveryNo for each OrderNo based on either DeliveryNo’s numeric value or both the DeliveryNo and the associated Creation date.

 

Output would be like this (example from excel):

Example.PNG

 

Any help is appreciated.

 

Thanks,

Martin

 

Helpful resources

Announcements
April AMA free

Microsoft Fabric AMA Livestream

Join us Tuesday, April 09, 9:00 – 10:00 AM PST for a live, expert-led Q&A session on all things Microsoft Fabric!

March Fabric Community Update

Fabric Community Update - March 2024

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