The ultimate Fabric, Power BI, SQL, and AI community-led learning event. Save €200 with code FABCOMM.
Get registeredEnhance your career with this limited time 50% discount on Fabric and Power BI exams. Ends August 31st. Request your voucher.
Hi PowerBians
I am trying to get a calculation which gives me result as mentioned in table below
I tried below dax which is not giving me right results
Data | |||
Order Date | Ship Date | Product | Quantity |
6/1/2022 | 6/10/2022 | A | 20 |
6/2/2022 | 6/11/2022 | B | 20 |
6/3/2022 | 6/12/2022 | C | 10 |
6/4/2022 | 6/13/2022 | D | 20 |
6/5/2022 | 6/14/2022 | A | 10 |
6/6/2022 | 6/15/2022 | B | 17 |
6/7/2022 | 6/16/2022 | C | 17 |
6/8/2022 | 6/17/2022 | D | 12 |
6/9/2022 | 6/18/2022 | A | 12 |
6/10/2022 | 6/19/2022 | B | 14 |
6/11/2022 | 6/20/2022 | C | 10 |
6/12/2022 | 6/21/2022 | D | 17 |
6/13/2022 | 6/22/2022 | A | 20 |
6/14/2022 | 6/23/2022 | B | 15 |
6/15/2022 | 6/24/2022 | C | 15 |
6/16/2022 | 6/25/2022 | D | 10 |
6/17/2022 | 6/26/2022 | A | 15 |
6/18/2022 | 6/27/2022 | B | 12 |
6/19/2022 | 6/28/2022 | C | 12 |
6/20/2022 | 6/29/2022 | D | 19 |
6/21/2022 | 6/30/2022 | A | 16 |
6/22/2022 | 7/1/2022 | B | 17 |
6/23/2022 | 7/2/2022 | C | 13 |
By using a Month\Day filter, I would like to look at how many products were shipped and how many were delivered on that day.
Result | ||
Product | Ordererd | Shipped |
A | 20 | 17 |
B | 30 | 25 |
C | 40 | 33 |
D | 50 | 41 |
Solved! Go to Solution.
Hi @mithunt ,
I created a sample pbix file(see attachment) for you, please check whether that is what you want.
1. Create a date dimension table(Do not create any relationship with Data table)
Date = CALENDAR(DATE(2022,6,1),DATE(2022,7,31))
2. Create two measures as below to get the ordered qty and shipped qty base on the selected dates
Ordererd Qty =
CALCULATE (
SUM ( 'Data'[Quantity] ),
'Data'[Order Date] IN ALLSELECTED ( 'Date'[Date] )
)
Shipped Qty =
CALCULATE (
SUM ( 'Data'[Quantity] ),
'Data'[Ship Date] IN ALLSELECTED ( 'Date'[Date] )
)
3. Create the visuals
If the above one can't help you get the desired result, please provide some sample data in your tables (exclude sensitive data) with Text format and your expected result with backend logic and special examples. It is better if you can share a simplified pbix file. You can refer the following link to upload the file to the community. Thank you.
How to upload PBI in Community
Best Regards
Hi @mithunt ,
I created a sample pbix file(see attachment) for you, please check whether that is what you want.
1. Create a date dimension table(Do not create any relationship with Data table)
Date = CALENDAR(DATE(2022,6,1),DATE(2022,7,31))
2. Create two measures as below to get the ordered qty and shipped qty base on the selected dates
Ordererd Qty =
CALCULATE (
SUM ( 'Data'[Quantity] ),
'Data'[Order Date] IN ALLSELECTED ( 'Date'[Date] )
)
Shipped Qty =
CALCULATE (
SUM ( 'Data'[Quantity] ),
'Data'[Ship Date] IN ALLSELECTED ( 'Date'[Date] )
)
3. Create the visuals
If the above one can't help you get the desired result, please provide some sample data in your tables (exclude sensitive data) with Text format and your expected result with backend logic and special examples. It is better if you can share a simplified pbix file. You can refer the following link to upload the file to the community. Thank you.
How to upload PBI in Community
Best Regards
Test Column will be :
TestColumn = IF( [Order Date] = [Ship Date], 1 , 0 )
To get the count of all and the count of shipped same day :
Count Of All = COUNT( [TestColumn] )
Count of Shipped Same Day = SUM( [TestColumn] )
Hope it makes things more clear
Hi,
You can create in Power Query or in a DAX, a conditionnal column to test :
if OrderDate= ShipDate then return 1 or 0 (when it's false).
Then you'll just have to sum this column within a measure and you'll get expected count.
Let us know if you need more detailed explanation...
Hi AilleryO,
Doing that would exclude entries if the Orderdate and Shipdate are not same.
I would need all the shipped details, ordered details too
Hi,
To get the count of every shipment you'll count your shipment number (COUNTA or DISTINCTCOUNT), or you could even count the number of value in the "test column". This would count the 0 and the 1.
And to get the count of shipment made the same day, you'll sum up the column you'll create with the test returning 1 or 0.
Is it ok ?
User | Count |
---|---|
11 | |
8 | |
6 | |
6 | |
6 |
User | Count |
---|---|
23 | |
14 | |
13 | |
10 | |
8 |