Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

The Power BI DataViz World Championships are on! With four chances to enter, you could win a spot in the LIVE Grand Finale in Las Vegas. Show off your skills.

Reply
MartinAa
Frequent Visitor

Calculate allocation percentage based on the days within a range

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.

 

MartinAa_0-1675410712026.png

 

So as an output - 

empnamemonthallocationPerc
RockyDec 202250%
RockyJan 2022100%
RockyFeb 2022100%

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..!!

1 ACCEPTED SOLUTION
v-tangjie-msft
Community Support
Community Support

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.

vtangjiemsft_0-1675671137855.png

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. 

View solution in original post

3 REPLIES 3
v-tangjie-msft
Community Support
Community Support

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.

vtangjiemsft_0-1675671137855.png

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. 

Thank you very much @v-tangjie-msft ..!! 

 

lbendlin
Super User
Super User

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

Helpful resources

Announcements
Las Vegas 2025

Join us at the Microsoft Fabric Community Conference

March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!

Feb2025 Sticker Challenge

Join our Community Sticker Challenge 2025

If you love stickers, then you will definitely want to check out our Community Sticker Challenge!

Feb2025 NL Carousel

Fabric Community Update - February 2025

Find out what's new and trending in the Fabric community.