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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
Anonymous
Not applicable

Calculating percent using data from two tables

Hi,

 

I am calculating daily employee attendance, and want to create a table that has the daily employee count and a column with the percent of employees that attended the office that day. I made a visual that organizes the data by day and location, and I have another table that displays the amount of employees assigned to each location (as well as the total number of seats available in each office).

 

Here is some sample data: 

 etijerina_0-1648651909150.png

 

One manual method would be to group the table by location and divide the values by the corresponding employee count. So I would, for example, divide all of the Atlanta daily swipe values by 11, which is the total number of employees in that office. I would like to find a more efficient way to do this, would anyone have any advice? 

 

 

1 ACCEPTED SOLUTION

Ok, First create a Calendar Table using the following code in a new table (under Modeling in the ribbon)

 

 

Calendar Table =
ADDCOLUMNS (
    CALENDAR ( MIN ( 'Attendance Table'[Date] ), MAX ( 'Attendance Table'[Date] ) ),
    "MonthNum", MONTH ( [Date] ),
    "Month", FORMAT ( [Date], "MMM" ),
    "Year", YEAR ( [Date] )
)

 

 

Next create relationships between the Location field in the Employee table and the Date field in the Calendar table witht he corresponding fields in the Attendance table. The model looks like this:

model.jpg

Next create the measures:

 

 

Employees by Location = 
SUM('Employee Table'[Employee Count])
Employee Attendance = SUM('Attendance Table'[Daily Attendance])

 

As for the %, you need to decide which value you would like to compute.

 

What is the % of attendance for the workforce, including locations with no attendance?

 

% Attendance of workforce =
VAR _Days =
    DISTINCTCOUNT ( 'Attendance Table'[Date] )
VAR TWF =
    CALCULATE ( [Employees by Location], ALL ( 'Employee Table' ) )
VAR WF =
    IF (
        ISINSCOPE ( 'Calendar Table'[Date] ),
        [Employees by Location],
        TWF * _Days
    )
RETURN
    DIVIDE ( [Employee Attendance], WF )

What is the % of attendance of the workforce in locations with attendance only?

% Attendance by location =
VAR WF =
    SUMX (
        ADDCOLUMNS (
            SUMMARIZE (
                'Attendance Table',
                'Calendar Table'[Date],
                'Employee Table'[Location]
            ),
            "Calc",
                CALCULATE (
                    IF ( ISBLANK ( [Employee Attendance] ), 0, [Employees by Location] )
                )
        ),
        [Calc]
    )
RETURN
    DIVIDE ( [Employee Attendance], WF )

What is the average % of attendance

Average % Attended =
AVERAGEX (
    SUMMARIZE (
        'Attendance Table',
        'Employee Table'[Location],
        'Calendar Table'[Date]
    ),
    CALCULATE ( DIVIDE ( [Employee Attendance], [Employees by Location] ) )
)

 

 

Set up the visuals using the Location field from the Employee table and the date field from the Calendar table

% variations.jpg

 

small mult.jpg

 

 

 I've attached the sample PBIX

 

 





Did I answer your question? Mark my post as a solution!
In doing so, you are also helping me. Thank you!

Proud to be a Super User!
Paul on Linkedin.






View solution in original post

10 REPLIES 10
v-shex-msft
Community Support
Community Support

Hi @Anonymous,

Any update for these? Did the above suggestions help with your scenario? if that is the case, you can consider Kudo or accept the helpful suggestions to help others who faced similar requirements.

If these also don't help, please share more detailed information to help us clarify your scenario to test.

How to Get Your Question Answered Quickly 

Regards,

Xiaoxin Sheng

Community Support Team _ Xiaoxin
If this post helps, please consider accept as solution to help other members find it more quickly.
PaulDBrown
Community Champion
Community Champion

It's important that all data shared is non confidential. Ideally we need sample from the relevant tables. You can edit any confidential fields in Excel. 
So the first sample you posted is an example of the attendance table and the last sample is the employee table? If so we can work with what you have already posted.





Did I answer your question? Mark my post as a solution!
In doing so, you are also helping me. Thank you!

Proud to be a Super User!
Paul on Linkedin.






Anonymous
Not applicable

Here is the daily attendance sample for two days of data: 

 

LocationDate Daily Attendance
LEXINGTON2/1/2022 0:00 2
NAPA2/1/2022 0:00 3
ATLANTA2/1/2022 0:00 4
AVON2/1/2022 0:00 4
CEDAR RAPIDS2/1/2022 0:00 4
KANSAS CITY2/1/2022 0:00 4
MIAMI2/1/2022 0:00 4
SCOTTSDALE2/1/2022 0:00 4
CALABASAS2/1/2022 0:00 5
RED BANK2/1/2022 0:00 5
CANONSBURG2/1/2022 0:00 8
CHICAGO2/1/2022 0:00 8
FORT WASHINGTON2/1/2022 0:00 13
INDIANAPOLIS2/1/2022 0:00 16
OVERLAND PARK2/1/2022 0:00 24
NEW YORK CITY2/1/2022 0:00 71
RED BANK2/2/2022 0:00 3
SCOTTSDALE2/2/2022 0:00 3
CEDAR RAPIDS2/2/2022 0:00 4
LEXINGTON2/2/2022 0:00 4
OVERLAND PARK2/2/2022 0:00 5
CALABASAS2/2/2022 0:00 6
MIAMI2/2/2022 0:00 6
CANONSBURG2/2/2022 0:00 8
ATLANTA2/2/2022 0:00 9
NAPA2/2/2022 0:00 10
AVON2/2/2022 0:00 11
FORT WASHINGTON2/2/2022 0:00 14
INDIANAPOLIS2/2/2022 0:00 15
NEW YORK CITY2/2/2022 0:00 106

 

This is the employee table:

 

LocationEmployee Count
ATLANTA11
AVON16
CALABASAS16
CEDAR RAPIDS6
CHICAGO27
FORT WASHINGTON13
INDIANAPOLIS62
KANSAS CITY6
LEXINGTON16
MINEOLA8
NAPA20
NEW YORK CITY153
OVERLAND PARK181
PITTSBURGH7
RED BANK6
SCOTTSDALE7
COON RAPIDS4
LAKE MARY16
SAN FRANCISCO2
VANCOUVER8
WESTLAKE4
MORRISTOWN4

 

 

I can provide more if this doesn't work. Thank you again for all your help! 

Ok, First create a Calendar Table using the following code in a new table (under Modeling in the ribbon)

 

 

Calendar Table =
ADDCOLUMNS (
    CALENDAR ( MIN ( 'Attendance Table'[Date] ), MAX ( 'Attendance Table'[Date] ) ),
    "MonthNum", MONTH ( [Date] ),
    "Month", FORMAT ( [Date], "MMM" ),
    "Year", YEAR ( [Date] )
)

 

 

Next create relationships between the Location field in the Employee table and the Date field in the Calendar table witht he corresponding fields in the Attendance table. The model looks like this:

model.jpg

Next create the measures:

 

 

Employees by Location = 
SUM('Employee Table'[Employee Count])
Employee Attendance = SUM('Attendance Table'[Daily Attendance])

 

As for the %, you need to decide which value you would like to compute.

 

What is the % of attendance for the workforce, including locations with no attendance?

 

% Attendance of workforce =
VAR _Days =
    DISTINCTCOUNT ( 'Attendance Table'[Date] )
VAR TWF =
    CALCULATE ( [Employees by Location], ALL ( 'Employee Table' ) )
VAR WF =
    IF (
        ISINSCOPE ( 'Calendar Table'[Date] ),
        [Employees by Location],
        TWF * _Days
    )
RETURN
    DIVIDE ( [Employee Attendance], WF )

What is the % of attendance of the workforce in locations with attendance only?

% Attendance by location =
VAR WF =
    SUMX (
        ADDCOLUMNS (
            SUMMARIZE (
                'Attendance Table',
                'Calendar Table'[Date],
                'Employee Table'[Location]
            ),
            "Calc",
                CALCULATE (
                    IF ( ISBLANK ( [Employee Attendance] ), 0, [Employees by Location] )
                )
        ),
        [Calc]
    )
RETURN
    DIVIDE ( [Employee Attendance], WF )

What is the average % of attendance

Average % Attended =
AVERAGEX (
    SUMMARIZE (
        'Attendance Table',
        'Employee Table'[Location],
        'Calendar Table'[Date]
    ),
    CALCULATE ( DIVIDE ( [Employee Attendance], [Employees by Location] ) )
)

 

 

Set up the visuals using the Location field from the Employee table and the date field from the Calendar table

% variations.jpg

 

small mult.jpg

 

 

 I've attached the sample PBIX

 

 





Did I answer your question? Mark my post as a solution!
In doing so, you are also helping me. Thank you!

Proud to be a Super User!
Paul on Linkedin.






Anonymous
Not applicable

Hi, 

 

So I tried using the same methods; not sure if I am making a mistake somewhere. I keep getting this error: 

etijerina_0-1648756281629.png

 

At what step does the error occur ?





Did I answer your question? Mark my post as a solution!
In doing so, you are also helping me. Thank you!

Proud to be a Super User!
Paul on Linkedin.






PaulDBrown
Community Champion
Community Champion

Can you please post sample data or a mockup PBIX file and a depiction of the expected outcome?





Did I answer your question? Mark my post as a solution!
In doing so, you are also helping me. Thank you!

Proud to be a Super User!
Paul on Linkedin.






Anonymous
Not applicable

Hi,

 

Thank you so much! This should be what I'm looking for, I am just trying to replicate it - I will upadate once I successfully do. 


One question, how were you able to place the measures/calculations under a seaparate field in the Fields section? When creating the new measurements, they automatically go under the current field I have open. 

 

Thanks again! 

Anonymous
Not applicable

Here is some mockup data. I would like to make a visual that would show me the percentage of employees that attended a location every single day. I am not very savvy with PowerBI, so I am not sure if what I am trying to do is possible or how I would go about it...

 

For example, in a table, I would like to have a drop down option for each location to display the daily attendance count for that location. 

As an example: 

 

LocationDateDaily AttendanceTotal EmployeesPercent Attended
NYC1/1585/8
NYC1/2787/8
NYC1/3383/8

Houston

1/1090/9

Houston

1/2696/9

Houston

1/3292/9

LA 

1/1101010/10

LA

1/25105/10

LA

1/38108/10

 

I would want to have a visual in this sort of Format on PowerBI, where the rows with dates in them can be expanded to be separated by location or vice versa.  

 

etijerina_0-1648659578623.png

This table above shows the attendance for each day, and I want to divide those values by the total number of employees per location, found in this table. 

etijerina_1-1648659784680.png

 

I want to ultimately make a trend report that lets me see the attendance percentage every day, organized by location. 

 

etijerina_2-1648660030969.png

 

This is what I have managed to put together, but I am still hoping to get a percentage for each office. 

Is the sample table of data representative of your actual tables? I'm asking because you include an image of employees by location.
Ideally we need sample data of the tables in you dataset (I would assume you at least have a table for attendance and another for employees by location, if I'm interpreting your info correctly). This will help us create the model and measures according to your actual needs.





Did I answer your question? Mark my post as a solution!
In doing so, you are also helping me. Thank you!

Proud to be a Super User!
Paul on Linkedin.






Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

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