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
RubanBasilea
Helper II
Helper II

Mapping of delivery item with work order based on sequence and quantity of material delivered - AI

Hi Experts, can anyone help me for this logic (Kind of Artificial Intelligence)

There are two tables - Main & Delivery table. (Refer the table below) Main table needs quantity from Delivery table to fulfil the WO need – i.e. column C is the required quantity column in Main table. The sequence in which these lines get materials is specified in column D. Furthermore in Delivery table there would be multiple deliveries and the sequence in which material gets allotted to Main table from Delivery table is specified in column D. We want to achieve the below mentioned "Required output" in main table  

 

Table 1 (Main Table)

 

Work orderMaterialRequired QtySequence of delivery allocationRequired Output (From Table 2)
1133d
21102a,b,c
31111a

Table 2 (Delivery table)

 

DeliveryMaterialQuantitySequence
a1171
b132
c113
d134
e195

 

 

Detail Explanation:

First iteration in Table 1 : In the above example, Work order ‘3’ is the first line to get materials (this is based on sequence=column D) and it requires 11 quantity. This line will get materials from delivery ‘a’ since it has 17 quantities and it is the first line to give away materials (again this is based on sequence in table 2).

 

After this first iteration, in Table 2 for delivery ‘a’ since 11 quantities are already consumed by Work order ‘3’. The remaining quantity of ‘a’ in table2 would be 6.

 

Now for the second iteration in Table 1 : Work order ‘2’ is the second line to get materials (this is again based on sequence=column D) and it requires 10 quantity. This line will get materials from three different deliveries. This is because delivery ‘a’ has 6 quantities left, delivery ‘b’ has 3 quantities and delivery ‘c’ has 1 quantity .

 

After this second iteration, in Table 2 for deliveries a, b & c are completely consumed. The only open deliveries available are d & e.

 

Now, for third iteration : Work order ‘1’ is the last line to get materials (this is again based on sequence=column D) and it requires 3 quantity. This line will get materials from delivery d since it has 3 quantities.

 

Finally after this third iteration, in Table 2, Deliveries a,b,c & d are completely consumed. The only open delivery left out would be ‘e’.

 

Thanks

Kind Regards

1 ACCEPTED SOLUTION
v-zhenbw-msft
Community Support
Community Support

Hi @RubanBasilea ,

 

Sorry for that we cannot create a measure because each line has the different logic.

So we need to create a column in each table and create a calculate table to meet your requirement.

 

1. We need to calculate the cumulative value in each table.

 

accumQty = 
CALCULATE(SUM('Table 1'[Required Qty]),FILTER('Table 1','Table 1'[Sequence of delivery allocation]<=EARLIER('Table 1'[Sequence of delivery allocation])))

 

map1.jpg

 

accum qty = 
CALCULATE(SUM('Table 2'[Quantity]),FILTER('Table 2','Table 2'[Sequence]<=EARLIER('Table 2'[Sequence])))

 

map2.jpg

 

2. Then we need to create a calculate table.

 

Table = 
var _order1 = 
ADDCOLUMNS(
    FILTER('Table 1','Table 1'[Work order]=1),
    "Column1",CALCULATE(MAX('Table 2'[Delivery]),FILTER('Table 2','Table 2'[accum qty]<=[accumQty])))
var _order2 = 
ADDCOLUMNS(
    FILTER('Table 1','Table 1'[Work order]=2),
    "Column1",CONCATENATEX(FILTER('Table 2','Table 2'[accum qty]<=[accumQty]),'Table 2'[Delivery],","))
var _order3 =
ADDCOLUMNS(
    FILTER('Table 1','Table 1'[Work order]=3),
    "Column1",CALCULATE(MIN('Table 2'[Delivery]),FILTER('Table 2','Table 2'[accum qty]>=[accumQty])))
return
UNION(
    _order1,_order2,_order3)

 

map3.jpg

 

Best regards,

 

Community Support Team _ zhenbw

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

 

BTW, pbix as attached.

View solution in original post

1 REPLY 1
v-zhenbw-msft
Community Support
Community Support

Hi @RubanBasilea ,

 

Sorry for that we cannot create a measure because each line has the different logic.

So we need to create a column in each table and create a calculate table to meet your requirement.

 

1. We need to calculate the cumulative value in each table.

 

accumQty = 
CALCULATE(SUM('Table 1'[Required Qty]),FILTER('Table 1','Table 1'[Sequence of delivery allocation]<=EARLIER('Table 1'[Sequence of delivery allocation])))

 

map1.jpg

 

accum qty = 
CALCULATE(SUM('Table 2'[Quantity]),FILTER('Table 2','Table 2'[Sequence]<=EARLIER('Table 2'[Sequence])))

 

map2.jpg

 

2. Then we need to create a calculate table.

 

Table = 
var _order1 = 
ADDCOLUMNS(
    FILTER('Table 1','Table 1'[Work order]=1),
    "Column1",CALCULATE(MAX('Table 2'[Delivery]),FILTER('Table 2','Table 2'[accum qty]<=[accumQty])))
var _order2 = 
ADDCOLUMNS(
    FILTER('Table 1','Table 1'[Work order]=2),
    "Column1",CONCATENATEX(FILTER('Table 2','Table 2'[accum qty]<=[accumQty]),'Table 2'[Delivery],","))
var _order3 =
ADDCOLUMNS(
    FILTER('Table 1','Table 1'[Work order]=3),
    "Column1",CALCULATE(MIN('Table 2'[Delivery]),FILTER('Table 2','Table 2'[accum qty]>=[accumQty])))
return
UNION(
    _order1,_order2,_order3)

 

map3.jpg

 

Best regards,

 

Community Support Team _ zhenbw

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

 

BTW, pbix as attached.

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.