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
Frankcf
Frequent Visitor

Calculate with multiple tables

I have set up a report that required that i link 5 tables. Each table is responsible for an inventory count.

Main table is item, that all tables are related to

  1. table  1 is "inventroy_Qty displays current inventroy amount
  2. table 2  is "PO_Qty" displays the quantity on purchase order
  3. table 3  is " Prod_Qty" displays the quantity on a production order
  4. table 4  is "Sales_Qty" displays the quantity on sales order (not shipped)

 

the problem is that i need to calculate what is available to be sold

to accomplis this i am using the follwing formula in excel

 

(inventory_qty + po_qty) - (Prod_qty + Sales_Qty) = Available_Qty.

 

how can i perform this calculatin in Power BI. using BI desktop.

1 REPLY 1
v-shex-msft
Community Support
Community Support

Hi @Frankcf,

 

Based on my understanding, I build below sample, you can refer to it:

 

Tables.(t1,t2,t3,t4)

Capture.PNG

 

Capture2.PNG

 

Capture3.PNG

 

Capture4.PNG

 

Table formula:

 

Avible Inventory =
SELECTCOLUMNS(Sheet1,"Inventroy ID",[Inventroy ID],"Inventory Name",[Inventory Name],
"Avible Qty",([Inventroy Qty]+ SUMX(FILTER(ALL(Sheet2),Sheet2[Inventory ID]=EARLIER(Sheet1[Inventroy ID])),[PO_Qty]))
-(SUMX(FILTER(ALL(Sheet3),Sheet3[Inventory ID]=EARLIER(Sheet1[Inventroy ID])),Sheet3[Prod_Qty])+SUMX(FILTER(ALL(Sheet4),Sheet4[Inventory ID]=EARLIER(Sheet1[Inventroy ID])),Sheet4[Sales_Qty])))

 

Capture6.PNG

 

The detail result table:

 

Avible Inventory =
SELECTCOLUMNS(Sheet1,"Inventroy ID",[Inventroy ID],"Inventory Name",[Inventory Name],
"Avible Qty",([Inventroy Qty]+ SUMX(FILTER(ALL(Sheet2),Sheet2[Inventory ID]=EARLIER(Sheet1[Inventroy ID])),[PO_Qty]))
-(SUMX(FILTER(ALL(Sheet3),Sheet3[Inventory ID]=EARLIER(Sheet1[Inventroy ID])),Sheet3[Prod_Qty])+SUMX(FILTER(ALL(Sheet4),Sheet4[Inventory ID]=EARLIER(Sheet1[Inventroy ID])),Sheet4[Sales_Qty])),
"Qty_T1",Sheet1[Inventroy Qty],
"Qty_T2",SUMX(FILTER(ALL(Sheet2),Sheet2[Inventory ID]=EARLIER(Sheet1[Inventroy ID])),Sheet2[PO_Qty]),
"Qty_T3",SUMX(FILTER(ALL(Sheet3),Sheet3[Inventory ID]=EARLIER(Sheet1[Inventroy ID])),Sheet3[Prod_Qty]),
"Qty_T4",SUMX(FILTER(ALL(Sheet4),Sheet4[Inventory ID]=EARLIER(Sheet1[Inventroy ID])),Sheet4[Sales_Qty]))

 

Result:

Capture5.PNG

 

 

Regards,

Xiaoxin Sheng

Community Support Team _ Xiaoxin
If this post helps, please consider accept as solution to help other members find it more quickly.

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.