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
Hi All,
I have 2 tables Targets and Sales. both tables were connected via the EMP Code column. Target amounts were given on monthly basis, whereas sales in the Sales table happened on daily basis. I need to present this data in a Matrix on a monthly and weekly basis. The requirement here is that the given monthly total targets shall be distributed over a number of weeks of a month.
( weekly target = monthly target / No of weeks ) and the fields of the matrix shall be EMP Name in the rows, month, and weeks (like W1, W1, etc., ) in the columns, and split the target amount in the values section.
Below is the link to the sample .pbix file and Need help writing the required DAX of the above.
https://drive.google.com/file/d/1KKddmCbMa5rvlothkHsk-i9VjAc8lxbn/view?usp=share_link
Cheers & Thanks in Advance,
VKB
Solved! Go to Solution.
Hi , @VKB
Based on your description, you want to divide the Target table into weeks by month. According to my understanding, there may be 4 or 5 weeks in a month, but for the first 4 weeks it is generally 7 days, and the fifth week is generally less than 7 days, so my understanding is to take the target/total number of days per month and then multiply the number of days per week to find the Target of the corresponding week.
Here are the steps you can refer to :
(1)We need to create a date table like this:
Date = var _t = ADDCOLUMNS( CALENDAR( FIRSTDATE('Targets'[From Date]) ,LASTDATE('Targets'[To Date])),
"Year" , YEAR([Date]),"Month",MONTH([Date]),"Month_Name",FORMAT([Date],"mmmm"),"Week","W"&ROUNDUP( DAY([Date])/7,0) )
var _t2 = ADDCOLUMNS(_t ,"Week_Days" , var _w = FILTER(_t ,[Year]=EARLIER([Year]) && [Month]=EARLIER([Month]) && [Week]=EARLIER([Week])) return COUNTROWS(_w))
return
_t2
(2)Then we need to create a measure :
Measure =
var _cur_date = MAX('Date'[Date])
var _days_in_month = DAY(EOMONTH(_cur_date,0))
var _target =SUMX( FILTER( 'Targets' , YEAR('Targets'[From Date])= YEAR(_cur_date) && MONTH('Targets'[From Date])= MONTH(_cur_date)) , [ Target ])
var cur_week_days = MAX('Date'[Week_Days])
return
DIVIDE(_target,_days_in_month) * cur_week_days
(3)Then we can put the fields on the visual and we can meet your need:
If this method does not meet your needs, you can provide us with your special sample data and the desired output sample data in the form of tables, so that we can better help you solve the problem.
Thank you for your time and sharing, and thank you for your support and understanding of PowerBI!
Best Regards,
Aniya Zhang
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly
Hi , @VKB
Based on your description, you want to divide the Target table into weeks by month. According to my understanding, there may be 4 or 5 weeks in a month, but for the first 4 weeks it is generally 7 days, and the fifth week is generally less than 7 days, so my understanding is to take the target/total number of days per month and then multiply the number of days per week to find the Target of the corresponding week.
Here are the steps you can refer to :
(1)We need to create a date table like this:
Date = var _t = ADDCOLUMNS( CALENDAR( FIRSTDATE('Targets'[From Date]) ,LASTDATE('Targets'[To Date])),
"Year" , YEAR([Date]),"Month",MONTH([Date]),"Month_Name",FORMAT([Date],"mmmm"),"Week","W"&ROUNDUP( DAY([Date])/7,0) )
var _t2 = ADDCOLUMNS(_t ,"Week_Days" , var _w = FILTER(_t ,[Year]=EARLIER([Year]) && [Month]=EARLIER([Month]) && [Week]=EARLIER([Week])) return COUNTROWS(_w))
return
_t2
(2)Then we need to create a measure :
Measure =
var _cur_date = MAX('Date'[Date])
var _days_in_month = DAY(EOMONTH(_cur_date,0))
var _target =SUMX( FILTER( 'Targets' , YEAR('Targets'[From Date])= YEAR(_cur_date) && MONTH('Targets'[From Date])= MONTH(_cur_date)) , [ Target ])
var cur_week_days = MAX('Date'[Week_Days])
return
DIVIDE(_target,_days_in_month) * cur_week_days
(3)Then we can put the fields on the visual and we can meet your need:
If this method does not meet your needs, you can provide us with your special sample data and the desired output sample data in the form of tables, so that we can better help you solve the problem.
Thank you for your time and sharing, and thank you for your support and understanding of PowerBI!
Best Regards,
Aniya Zhang
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly
https://www.dropbox.com/scl/fi/czqfhn8fholrgavu9iy1a/Sample-Data.xlsx?dl=0&rlkey=3evm1cus93wij4pkux9...
Can you help in this data?
Thank you very much. This solved my requirement.
The requirement here is that the given monthly total targets shall be distributed over a number of weeks of a month.
Months and weeks are incompatible. You need to use an external calendar table with precomputed mapping according to your company policies. "Weeks in a month" is always a red flag.
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 |
---|---|
92 | |
86 | |
85 | |
66 | |
49 |
User | Count |
---|---|
140 | |
113 | |
104 | |
64 | |
60 |