Microsoft is giving away 50,000 FREE Microsoft Certification exam vouchers. Get Fabric certified for FREE! Learn more
Hi All,
I want to create a table visualization, with name of each employee and allocation percentage by month (Within the range of start date and end date).
Output table with – Employeename, Month and allocation percentage à ability to slice by month.
Also, if possible, view the allocation by year or YTD
I have three tables in my model –
Dim_date – date columns
Dim employee – Name, country and first working date,
Fact_project allocation – empname, startdate, end date , allocation perc( value from 0.1 to 1)
I have attached sample data for reference, please suggest.
So as an output -
empname | month | allocationPerc |
Rocky | Dec 2022 | 50% |
Rocky | Jan 2022 | 100% |
Rocky | Feb 2022 | 100% |
Dec 2022 - 50% Because only 15days are allocated in that month.
And so on ..!!
..
Thank you .
-Martin
Hi - @wdx223_Daniel . Would really appreciate if you could help me on this..!!
Solved! Go to Solution.
Hi @MartinAa ,
According to your description, here are my steps you can follow as a solution.
(1) My test data is the same as yours.
(2) We can create a table.
Output =
var _a = ADDCOLUMNS(CALENDAR(MIN('Table'[start_date]),MAX('Table'[end_date])),"Month",FORMAT([Date],"MMM YYYY"))
var _b = CROSSJOIN(VALUES('Table'[empname]),_a)
var _c = ADDCOLUMNS(_b,"FFlag",SUMX(ADDCOLUMNS(FILTER('Table',[empname]=EARLIER('Table'[empname])),"Flag",IF([Date]>=[start_date]&&[Date]<=[end_date],1,0)),[Flag]))
var _d = SUMMARIZE(_c,'Table'[empname],[Month],"allocationPerc",DIVIDE(COUNTX(FILTER(_c,[empname]=EARLIER('Table'[empname])&&[Month]=EARLIER([Month])&&[FFlag]<>0),[FFlag]),MAXX(FILTER(_a,[Month]=EARLIER([Month])),DAY(EOMONTH([Date],0)))))
return FILTER(_d,[allocationPerc]<>0)
(3) Then the result is as follows.
Best Regards,
Neeko Tang
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Hi @MartinAa ,
According to your description, here are my steps you can follow as a solution.
(1) My test data is the same as yours.
(2) We can create a table.
Output =
var _a = ADDCOLUMNS(CALENDAR(MIN('Table'[start_date]),MAX('Table'[end_date])),"Month",FORMAT([Date],"MMM YYYY"))
var _b = CROSSJOIN(VALUES('Table'[empname]),_a)
var _c = ADDCOLUMNS(_b,"FFlag",SUMX(ADDCOLUMNS(FILTER('Table',[empname]=EARLIER('Table'[empname])),"Flag",IF([Date]>=[start_date]&&[Date]<=[end_date],1,0)),[Flag]))
var _d = SUMMARIZE(_c,'Table'[empname],[Month],"allocationPerc",DIVIDE(COUNTX(FILTER(_c,[empname]=EARLIER('Table'[empname])&&[Month]=EARLIER([Month])&&[FFlag]<>0),[FFlag]),MAXX(FILTER(_a,[Month]=EARLIER([Month])),DAY(EOMONTH([Date],0)))))
return FILTER(_d,[allocationPerc]<>0)
(3) Then the result is as follows.
Best Regards,
Neeko Tang
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Please provide sample data that covers your issue or question completely.
https://community.powerbi.com/t5/Community-Blog/How-to-provide-sample-data-in-the-Power-BI-Forum/ba-...
Please show the expected outcome based on the sample data you provided.
https://community.powerbi.com/t5/Desktop/How-to-Get-Your-Question-Answered-Quickly/m-p/1447523