Starting December 3, join live sessions with database experts and the Microsoft product team to learn just how easy it is to get started
Learn moreGet certified in Microsoft Fabric—for free! For a limited time, get a free DP-600 exam voucher to use by the end of 2024. Register now
I consider myself an intermediate Dax user but Im having problems figuring out this measure. I have a table that has the following (sample) data:
year part num prod group revenue qty sold
2020 xx X 5 2
2020 xx X 17 4
2020 xx2 X 50 2
2020 xx2 X 59 3
2020 yy Y 15 1
2020 yy Y 50 4
2020 yy3 Y 5 5
2020 yy3 Y 65 9
2019 xx X 75 6
2019 xx2 X 5 2
2019 xx X 5 2
I want to select a product group and a year from slicers, and have measures that will show the part number with the greatest total revenue and greatest total quantity sold for that product group and year, along with the value of the total revenue and quantity. In the above data, if we select product group X and 2020 as the year in the slicers, I want the measure to show that product xx had the most quantity sold at 6 and product xx2 had the most revenue generated at 109.
any help I could get would be much appreciated.
Solved! Go to Solution.
Try these measures. The ADDCOLUMNS function allows you to calculate the total quantity or revenue at the part level, and TOPN filters for the largest amount.
Total Quantity Sold = SUM (Table1[qty sold] )
Total Revenue = SUM ( Table1[revenue] )
Most Quantity Sold =
VAR vTable =
ADDCOLUMNS ( VALUES ( Table1[part num] ), "@Amount", [Total Quantity Sold] )
VAR vTopRow =
TOPN ( 1, vTable, [@Amount], DESC )
VAR vPart =
MAXX ( vTopRow, Table1[part num] )
VAR vAmount =
MAXX ( vTopRow, [@Amount] )
VAR vResult = vPart & " - " & vAmount
RETURN
vResult
Most Revenue Generated =
VAR vTable =
ADDCOLUMNS ( VALUES ( Table1[part num] ), "@Amount", [Total Revenue] )
VAR vTopRow =
TOPN ( 1, vTable, [@Amount], DESC )
VAR vPart =
MAXX ( vTopRow, Table1[part num] )
VAR vAmount =
MAXX ( vTopRow, [@Amount] )
VAR vResult = vPart & " - " & vAmount
RETURN
vResult
Proud to be a Super User!
Try these measures. The ADDCOLUMNS function allows you to calculate the total quantity or revenue at the part level, and TOPN filters for the largest amount.
Total Quantity Sold = SUM (Table1[qty sold] )
Total Revenue = SUM ( Table1[revenue] )
Most Quantity Sold =
VAR vTable =
ADDCOLUMNS ( VALUES ( Table1[part num] ), "@Amount", [Total Quantity Sold] )
VAR vTopRow =
TOPN ( 1, vTable, [@Amount], DESC )
VAR vPart =
MAXX ( vTopRow, Table1[part num] )
VAR vAmount =
MAXX ( vTopRow, [@Amount] )
VAR vResult = vPart & " - " & vAmount
RETURN
vResult
Most Revenue Generated =
VAR vTable =
ADDCOLUMNS ( VALUES ( Table1[part num] ), "@Amount", [Total Revenue] )
VAR vTopRow =
TOPN ( 1, vTable, [@Amount], DESC )
VAR vPart =
MAXX ( vTopRow, Table1[part num] )
VAR vAmount =
MAXX ( vTopRow, [@Amount] )
VAR vResult = vPart & " - " & vAmount
RETURN
vResult
Proud to be a Super User!
thank you SO much, that is really elegant and works perfectly. I will accept as a solution
Thanks, glad to hear that!
Proud to be a Super User!
Starting December 3, join live sessions with database experts and the Fabric product team to learn just how easy it is to get started.
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early Bird pricing ends December 9th.
User | Count |
---|---|
87 | |
85 | |
85 | |
67 | |
49 |
User | Count |
---|---|
132 | |
113 | |
100 | |
68 | |
67 |