Get certified in Microsoft Fabric—for free! For a limited time, the Microsoft Fabric Community team will be offering free DP-600 exam vouchers. Prepare now
Hi,
I have a few materials which consume the same bill of material, in order to produce a finished product.
Currently, I have a very simple subtraction formula.
But it is now showing that the stock on hand is reducing for the bill of material.
Finished product | Bill of material | Stock on hand Bill of material | Due to deliverer finished product | Correct Variance | Incorrect Variance | |
390555zGDE | 390555ZZDE1 | 4317 | 978 | 3339 | 3339 | |
390555zGDE | 390555ZZDE1 | 4317 | 2007 | 1332 | 2310 | |
390555zGDE | 390555ZZDE1 | 4317 | 1540 | -208 | 2777 |
The stock on hand for material 390555ZZDE1 = 4317, but I need it to reduce with each consumption of the material.
Will you be able to help with this, please?
Regards and Thanks
Solved! Go to Solution.
Hi @Anonymous ,
You need to create an index column first in power query editor to calculate.
If you do not want the index column load into your table, you can use power query for calculations throughout. The whole query would be like this:
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMrY0MDU1rXJ3cVXSgXKiolxcDYE8E2NDcyBlaW6hFKtDjEojAwNzIpUampoYKMXGAgA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Finished product" = _t, #"Bill of material" = _t, #"Stock on hand Bill of material" = _t, #"Due to deliverer finished product" = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Finished product", type text}, {"Bill of material", type text}, {"Stock on hand Bill of material", Int64.Type}, {"Due to deliverer finished product", Int64.Type}}),
#"Added Index" = Table.AddIndexColumn(#"Changed Type", "Index", 1, 1, Int64.Type),
#"Added Custom" = Table.AddColumn(#"Added Index", "Result", each [Stock on hand Bill of material] -List.Sum(List.Range(#"Added Index"[Due to deliverer finished product],0,[Index]))),
#"Removed Columns" = Table.RemoveColumns(#"Added Custom",{"Index"}),
#"Changed Type1" = Table.TransformColumnTypes(#"Removed Columns",{{"Result", Int64.Type}})
in
#"Changed Type1"
If you want to use DAX to calculate, the index column would be kept and you can create a calculated column like this:
Result =
[Stock on hand Bill of material]
- CALCULATE (
SUM ( 'Table_DAX'[Due to deliverer finished product] ),
FILTER ( 'Table_DAX', 'Table_DAX'[Index] <= EARLIER ( 'Table_DAX'[Index] ) )
)
Best Regards,
Community Support Team _ Yingjie Li
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Hi @Anonymous ,
You need to create an index column first in power query editor to calculate.
If you do not want the index column load into your table, you can use power query for calculations throughout. The whole query would be like this:
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMrY0MDU1rXJ3cVXSgXKiolxcDYE8E2NDcyBlaW6hFKtDjEojAwNzIpUampoYKMXGAgA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Finished product" = _t, #"Bill of material" = _t, #"Stock on hand Bill of material" = _t, #"Due to deliverer finished product" = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Finished product", type text}, {"Bill of material", type text}, {"Stock on hand Bill of material", Int64.Type}, {"Due to deliverer finished product", Int64.Type}}),
#"Added Index" = Table.AddIndexColumn(#"Changed Type", "Index", 1, 1, Int64.Type),
#"Added Custom" = Table.AddColumn(#"Added Index", "Result", each [Stock on hand Bill of material] -List.Sum(List.Range(#"Added Index"[Due to deliverer finished product],0,[Index]))),
#"Removed Columns" = Table.RemoveColumns(#"Added Custom",{"Index"}),
#"Changed Type1" = Table.TransformColumnTypes(#"Removed Columns",{{"Result", Int64.Type}})
in
#"Changed Type1"
If you want to use DAX to calculate, the index column would be kept and you can create a calculated column like this:
Result =
[Stock on hand Bill of material]
- CALCULATE (
SUM ( 'Table_DAX'[Due to deliverer finished product] ),
FILTER ( 'Table_DAX', 'Table_DAX'[Index] <= EARLIER ( 'Table_DAX'[Index] ) )
)
Best Regards,
Community Support Team _ Yingjie Li
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Thank you, will try and let you know 😃
@Anonymous
I am not quite sure how you have set up your files and the calculations. Better, you could share a sample PBIX file explaining the issues and the desired results.
⭕ Subscribe and learn Power BI from these videos
⚪ Website ⚪ LinkedIn ⚪ PBI User Group
Check out the October 2024 Power BI update to learn about new features.
Learn from experts, get hands-on experience, and win awesome prizes.
User | Count |
---|---|
115 | |
112 | |
105 | |
95 | |
58 |
User | Count |
---|---|
174 | |
147 | |
136 | |
102 | |
82 |