Find everything you need to get certified on Fabric—skills challenges, live sessions, exam prep, role guidance, and more. Get started
Hi,
I have the below data. a list of detailed invoice product lines. Each invoice has an estimated total amount which appears on several lines when the invoice has more than 1 product.
Invoice | Product | Price | Estimated Invoice total | Customer | Details |
1 | A | 100 | 500 | Cond | Amazon |
1 | B | 200 | 500 | Cond | Amazon |
1 | N | 3 | 500 | Cond | Amazon |
2 | B | 200 | 200 | Sana | Amazon |
3 | C | 500 | 600 | Sana | Amazon |
3 | D | 150 | 600 | Sana | Amazon |
4 | E | 20 | 20 | Torc | Amazon |
How do I calculate the measure for Estimated Total to be able to compare the estimated total with the real value of the invoice?
Invoice | Actual Total | Estimated total | Count Product | Customer | |
1 | 203 | 500 | 3 | Cond | |
2 | 200 | 200 | 1 | Sana | |
3 | 650 | 600 | 2 | Sana | |
4 | 20 | 20 | 1 | Torc | |
Total | 1073 | 1320 | 7 |
Thank you,
Zosy
Solved! Go to Solution.
Hi @Zosy,
Not sure the solution below is optimal, but it should work:
TotalEstimated = SUMX ( SUMMARIZE ( data, [Invoice], "Result", AVERAGE ( data[Estimated Invoice total] ) ), [Result] )
Best Regards,
Alexander
Hi @Zosy,
Try this one out:
Estimated Revenue (in selected currency) v2 =
VAR _tbl =
ADDCOLUMNS (
SUMMARIZE (
'Invoice Details', [Invoice],
"Date",
MIN ( 'Invoice Details'[Invoice Date] ),
"TotEst",
[TotalEstimated] ),
"Rate",
LOOKUPVALUE(
'Currency Rates'[exchangerate],
'Currency Rates'[currency_code], 'Currency Filter'[Selected Currency],
'Currency Rates'[Year], YEAR ( [Date] ) ) )
RETURN SUMX ( _tbl, [TotEst] * [Rate] )
Here's your PBIX with this measure - https://www.dropbox.com/s/lhwz19j80g9glpw/SUM%20of%20invoice%20lines%20with%20dynamic%20exchange%20c...
Best Regards,
Alexander
Hi @Zosy,
Not sure the solution below is optimal, but it should work:
TotalEstimated = SUMX ( SUMMARIZE ( data, [Invoice], "Result", AVERAGE ( data[Estimated Invoice total] ) ), [Result] )
Best Regards,
Alexander
Hi @barritown ,
The formula works very well, but I am stuck in the next step. How would I incorporate the TotalEstimated formula in the below measure, where it gets the currency converted dynamically? If I use it like below, it disregards the distinct invoice number.
Do you know what I am doing wrong?
Estimated Revenue (in selected currency) =
SUMX(
'Invoice Details',
VAR vExchange =
LOOKUPVALUE(
'CurrencyRates'[Exchange Rates],
'CurrencyRates'[currencycode], 'Currency Filters'[Selected Currency],
'CurrencyRates'[Year], 'Invoice Details'[Created On].[Year]
)
RETURN
'Invoice Details'[TotalEstimated]*vExchange
)
Thank you,
Zosy
Hi @Zosy,
I doubt I can help having just this code... If you can break down your new problem the way you did the initial one (with the input data and the desired outcome), there, I'll have more chances. 🙂
Best Regards,
Alexander
Hi @barritown ,
I have uploaded the file in dropbox. Hope this helps
SUM of invoice lines with dynamic exchange currency PBIX
What I want to achieve is to calculate the Estimated Revenue (in selected currency) for each individual invoice.
Invoice 1 has TotalEstimated = 500 but when I convert it to USD (FX rate=2 ) it should be 1000 not 3000 like below.
The result is 3000 because there are 3 prooducts on invoice 1 and it adds the Estimated Invoice Total for all the lines. 500*3=1500 converted to USD equals 3000.
Invoice details table
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMlTSUXIEYkMDAyBpCiad8/NSQMK5iVX5eUCGgZG+gam+kYGRkVKsDkSLExAbkabFD4iNidVghGIHhAxOzEtE1mJoqm9gAtJiCNYCMtsZbr4Zdi2W+gZmCFtAWlzAJhGtxQQo5Ap2EowIyS9KRtFgAtUAdFYsAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Invoice = _t, Product = _t, Price = _t, #"Estimated Invoice total" = _t, Customer = _t, Details = _t, #"Invoice Date" = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Invoice", Int64.Type}, {"Product", type text}, {"Price", Int64.Type}, {"Estimated Invoice total", Int64.Type}, {"Customer", type text}, {"Details", type text}, {"Invoice Date", type date}})
in
#"Changed Type"
Measures Invoice Details table
Actual Price (Base currency) = SUM('Invoice Details'[Price])
Actual Price (in selected currency) =
SUMX(
'Invoice Details',
VAR vExchange =
LOOKUPVALUE(
'Currency Rates'[exchangerate],
'Currency Rates'[currency_code], 'Currency Filter'[Selected Currency],
'Currency Rates'[Year], 'Invoice Details'[Invoice Date].[Year]
)
RETURN
'Invoice Details'[Actual Price (Base currency)]*vExchange
)
TotalEstimated = SUMX ( SUMMARIZE ('Invoice Details', [Invoice], "Result", AVERAGE ( 'Invoice Details'[Estimated Invoice total] ) ), [Result] )
Estimated Revenue (in selected currency) =
SUMX(
'Invoice Details',
VAR vExchange =
LOOKUPVALUE(
'Currency Rates'[exchangerate],
'Currency Rates'[currency_code], 'Currency Filter'[Selected Currency],
'Currency Rates'[Year], 'Invoice Details'[Invoice Date].[Year]
)
RETURN
'Invoice Details'[TotalEstimated]*vExchange
)
Currency Rates Table
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMlXSUTIyMLQEUq6lRfkgKjRIKVYHRSY0WMElPycnsQjMdgFLm4CljQwwNSLJYNNoDJE2xNSIJINNoxFE2ghTI5IMhsZYAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [exchangerate = _t, year = _t, currency_name = _t, currency_code = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"exchangerate", type number}, {"year", Int64.Type}, {"currency_name", type text}, {"currency_code", type text}})
in
#"Changed Type"
Currency Filter Table
let
Source = #"Currency Rates",
#"Removed Other Columns" = Table.SelectColumns(Source,{"currency_code"}),
#"Removed Duplicates" = Table.Distinct(#"Removed Other Columns")
in
#"Removed Duplicates"
Measures Currency Filter Table
Selected Currency = SELECTEDVALUE('Currency Filter'[currency_code])
Let me know if you have any other questions
Hi @Zosy,
Try this one out:
Estimated Revenue (in selected currency) v2 =
VAR _tbl =
ADDCOLUMNS (
SUMMARIZE (
'Invoice Details', [Invoice],
"Date",
MIN ( 'Invoice Details'[Invoice Date] ),
"TotEst",
[TotalEstimated] ),
"Rate",
LOOKUPVALUE(
'Currency Rates'[exchangerate],
'Currency Rates'[currency_code], 'Currency Filter'[Selected Currency],
'Currency Rates'[Year], YEAR ( [Date] ) ) )
RETURN SUMX ( _tbl, [TotEst] * [Rate] )
Here's your PBIX with this measure - https://www.dropbox.com/s/lhwz19j80g9glpw/SUM%20of%20invoice%20lines%20with%20dynamic%20exchange%20c...
Best Regards,
Alexander
Thank you so much for your help! I couldn't figure it out by myself, having a temporary table with the calculations does an amazing job!
Check out the September 2024 Power BI update to learn about new features.
Learn from experts, get hands-on experience, and win awesome prizes.
User | Count |
---|---|
109 | |
97 | |
95 | |
38 | |
36 |
User | Count |
---|---|
150 | |
124 | |
76 | |
74 | |
53 |