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
jlawrence_eplus
Regular Visitor

Average Number of Instances per week

I have a attendance report for our office where users have the option of coming into the office (vs working from home). Our management is interested in knowing how many people are coming in one day a week, vs two days, vs three days etc, with the ability to show how that has changed over each week. Maybe because it's Friday afternoon my brain is mush but I cannot figure out how to calculate this. 

 

Here's some sample Data:

NameOffice Attendance DateEnd of Week
Person A -9/14/20209/19/2020
Person A -9/15/20209/19/2020
Person A -9/18/20209/19/2020
Person B -9/14/20209/19/2020
Person B -9/17/20209/19/2020
Person C -9/15/20209/19/2020
Person D -9/15/20209/19/2020
Person D -9/17/20209/19/2020
Person A -9/21/20209/26/2020
Person A -9/22/20209/26/2020
Person A -9/23/20209/26/2020
Person B -9/23/20209/26/2020
Person C -9/22/20209/26/2020
Person C -9/25/20209/26/2020
Person D -9/24/20209/26/2020

 

And here's the results I'd like to show (based on the sample data):

Week 1Count
   1 Day1
   2 Days2
   3 Days 1
   4 Days0
   5 Days0
Week 2 
   1 Day2
   2 Days1
   3 Days 1
   4 Days0
   5 Days0

 

I do have a date dimension that has the end of the week in a column for every date but am unsure how to utilize this for the reporting. 

 

Any help would be greatly appreciated!

1 ACCEPTED SOLUTION
stevedep
Memorable Member
Memorable Member

I guess this is what you are looking for (p.s. _week is a calculated column):

 

_NumberOfPeopleAmountOfDaysInOffice = 
COUNTROWS(
    FILTER(SUMMARIZE('Table','Table'[_Week],[Name], "No", DISTINCTCOUNT('Table'[Office Attendance Date])), [No] = SELECTEDVALUE(NumberOfDays[NumberOfDaysValue])
    ))

_Week = WEEKDAY('Table'[Office Attendance Date])

Helper table generated with:
(modeling -> add table)
NumberOfDays = GENERATESERIES(1,5,1)

 

As seen here, use cross tab to display change over time:

office.png

Link to file

Please mark as solution if so. Thumbs up for the effort are appreciated.

Kind regards, 
Steve. 

View solution in original post

5 REPLIES 5
stevedep
Memorable Member
Memorable Member

I guess this is what you are looking for (p.s. _week is a calculated column):

 

_NumberOfPeopleAmountOfDaysInOffice = 
COUNTROWS(
    FILTER(SUMMARIZE('Table','Table'[_Week],[Name], "No", DISTINCTCOUNT('Table'[Office Attendance Date])), [No] = SELECTEDVALUE(NumberOfDays[NumberOfDaysValue])
    ))

_Week = WEEKDAY('Table'[Office Attendance Date])

Helper table generated with:
(modeling -> add table)
NumberOfDays = GENERATESERIES(1,5,1)

 

As seen here, use cross tab to display change over time:

office.png

Link to file

Please mark as solution if so. Thumbs up for the effort are appreciated.

Kind regards, 
Steve. 

Could you please help me understanding how did we got "NumberOfDays[NumberOfDaysValue]". I could find NumberOfDays[Value].

Also is matrix visual and cross tab both same? If yes could you please help me what should be mapped to columns rows and values?

Also I dint not understand where we have used the "_NumberOfPeopleAmountOfDaysInOffice" column.

Thanks that did it! Much appreciated!

daxer-almighty
Solution Sage
Solution Sage

 

// Your calendar should have all the pieces
// of time that you'll need and connect
// it on [Date] to T[Office Attendance Date].
// T[End of Week] should be moved to your
// calendar. Also, you should have a table
// with all your people, 'Persons'. Then,
// these should be connected to T and T as 
// the fact table should be hidden (fact tables
// should always be hidden). There'll be
// another table in the model that will store
// number of days in a week, 1,2,3,4,5. It
// will be DISCONNECTED. The measure I give
// you works for any period of time, not
// only weeks. Let's say that Persons is
// joined to T on [PersonID] (an integer).
// All columns that store ID's in all tables 
// must be hidden as they are only keys
// without any business meaning.

[People Count] =
var __numOfDays =
    SELECTEDVALUE(
        // This is the disconnected table.
        'Office Working Days'[Number Of Days],
        -1 // this is important to get rid of 0's
    )
var __peopleCount =
    // We have to find out for each
    // visible person the number of
    // days from T and if the number
    // is equal to the above, we
    // have to add the person to the
    // set whose cardinality we'll
    // report.
    SUMX(
        People,
        CALCULATE(
            INT( COUNTROWS( T ) = __numOfDays )
        )
    )
return
    __peopleCount

 

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.

Top Solution Authors