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
I am trying to figure out how to show time block useage for college course registration data. This would be most used as well as least used time blocks throughout each day of the week. The data are: Day, Start_Time, End_Time, CountofID (count of students in time block). Unfortunately not all time blocks are the same duration, thus lots of overlapping times.
I can plot a histogram of frequency by start time but because of the variability in timeblock duration, the plot is not particularlly acurate as to actual in-class or available times. Ideas?
.
Here's what I built in Power BI.
Hi,
I'm working on a similar task and would like to see how you build it in Power BI.
Thanks!
Lan
I ended up taking the section start and end times and creating one row for each minute of the section. I did this by duplicating the columns for start and end times and changing them to a whole number format, then I added a column that extrapolated that by using a custom column with the following formula: {[SSRMEET_BEGIN_TIME]..[SSRMEET_END_TIME]} which creates a row for each value between the times. For example, a 1000 start to 1150 finish would give you all values between 1,000 and 1,150 for that section. You can then filter out any values where the last two characters are greater than 59 (to eliminate 1075, for example, which obviously isn’t a time value).
I also added a time table (see code below) to link the scheduling data to and used that table, along with counts to create a matrix visual with conditional formatting (see photo). I used a hierarchy so you can drill down from hour to half hour, quarter hours and even down to the minute. This allows you to see all of the overlap for the times. Let me know if this make sense!
Code for time table: You’ll need to add this into a blank query
let CreateTimeTable = () as table =>
let
// Similar to our CreateDateTable script, we start with the smallest unit of the dimension, minute
// There are a fixed number of minutes in a day, so no need for parameters here
// 525,600 minutes divided by 365 days in a year = 1440 minutes in a day.
// Who says we never learn from Broadway musicals?
MinuteCount = 1440,
// Now create a Time type list for a total of 1440 minutes, incrementing one minute at a time
Source = List.Times(#time(0, 0, 0),MinuteCount, #duration(0,0,1,0)),
// Turn that list into a one column table
TableFromList = Table.FromList(Source, Splitter.SplitByNothing()),
// Change that table's one column to type Time
ChangedType = Table.TransformColumnTypes(TableFromList,{{"Column1", type time}}),
// Rename column to Time
RenamedColumns = Table.RenameColumns(ChangedType,{{"Column1", "Time"}}),
// Start inserting columns for each unit of time to represent in the dimension
InsertHour = Table.AddColumn(RenamedColumns, "Hour", each Time.StartOfHour([Time])),
InsertMinute = Table.AddColumn(InsertHour, "Minute", each Time.Minute([Time])),
ChangedTypeHour = Table.TransformColumnTypes(InsertMinute,{{"Hour", type time}}),
// Creating levels in the hierarchy that might be useful for reporting. Omit if not useful to yours
InsertQuarterHour = Table.AddColumn(ChangedTypeHour, "Quarter Hour", each if [Minute]<15 then [Hour] else if [Minute] < 30 then Value.Add([Hour],#duration(0,0,15, 0)) else if [Minute] < 45 then Value.Add([Hour],#duration(0,0,30, 0)) else Value.Add([Hour],#duration(0,0,45, 0))),
ChangedTypeQtrHr = Table.TransformColumnTypes(InsertQuarterHour,{{"Quarter Hour", type time}}),
ReorderedColumns = Table.ReorderColumns(ChangedTypeQtrHr,{"Time", "Hour", "Quarter Hour", "Minute"}),
InsertHourNumber = Table.AddColumn(ReorderedColumns, "Hour Number", each Time.Hour([Time])),
NextHour = Table.AddColumn(InsertHourNumber, "Next Hour", each Value.Add([Hour],#duration(0,1,0, 0))),
NextQuarterHour = Table.AddColumn(NextHour, "Next Quarter Hour", each Value.Add([Quarter Hour],#duration(0,0,15, 0))),
InsertPeriod = Table.AddColumn(NextQuarterHour, "Period of Day",
each if [Hour Number] >= 0 and [Hour Number] < 4 then "After Midnight" else
if [Hour Number] >= 4 and [Hour Number] < 8 then "Early Morning" else
if [Hour Number] >= 8 and [Hour Number] < 12 then "Late Morning" else
if [Hour Number] >= 12 and [Hour Number] < 16 then "Afternoon" else
if [Hour Number] >= 16 and [Hour Number] < 20 then "Evening" else "Late Night"),
InsertPeriodSort = Table.AddColumn(InsertPeriod, "PeriodSort", each
if [Hour Number] >= 0 and [Hour Number] < 4 then 0 else
if [Hour Number] >= 4 and [Hour Number] < 8 then 1 else
if [Hour Number] >= 8 and [Hour Number] < 12 then 2 else
if [Hour Number] >= 12 and [Hour Number] < 16 then 3 else
if [Hour Number] >= 16 and [Hour Number] < 20 then 4 else 5),
InsertTimeKey = Table.AddColumn(InsertPeriodSort, "TimeKey", each Time.ToText([Time], "HHmm"), type text)
in
InsertTimeKey
in
CreateTimeTable
Can you please share the sample script with me.
@Anonymous
Thank you very much for the detailed information. I'm very new to Power BI and there are a lot things I have to learn. I created the time table with your code, but I don't know on how to add a new column use the formula {[SSRMEET_BEGIN_TIME]..[SSRMEET_END_TIME]}". what I did is choose Add Column in Query Editor, Column from Examples, from all columns, then I copied the line {[SSRMEET_BEGIN_TIME]..[SSRMEET_END_TIME]} into the new added column, it shows something as below and the new column seems merged.
= Table.AddColumn(#"Changed Type", "Merged", each Text.Combine({" {[SSRMEET_BEGI", [Mon], "_TIME]..[SSRMEET_E", [Mon], "D_TIME]} "}), type text)
Could you tell me what I did wrong since I'm not really know what's {[SSRMEET_BEGIN_TIME]..[SSRMEET_END_TIME]} means.
Thank you!
Lan
You'll want to leave the time table as is. The additional column will be added to your original data table. For example, my original table (let’s call it MySchedule) had columns for each course, with the day of the week it meets, the start time, end time, etc (see attached sample report). In the MySchedule table you'll add the new column with the formula. You'll go to the Power Query Editor (you can get here by clicking the Transform data button in the ribbon), selecting your table in the left-side pane, going to the Add Column tab of the ribbon and selecting Custom Column. This is where you’ll enter your formula using your start and end time columns, creating a new column called 'Meet Times'.
= {[Start_Time_Column]..[End_Time_Column]}
In the example, this formula will create a list of all numbers between 1000 and 1100 for ABC 101. Once you click the top right of that column to expand it, it creates a new row for each value in the list. Then you'll need to filter that list since you'll get non-time values such as 1099.
Then, convert the Meet Times column back to a time value, close out of the query editor and create a relationship between your new, Meet Time, column and the Time Table, Time column.
Hopefully the example report I provided helps it make more sense! Let me know if you have any issues- always happy to help!
Can you please share the sample power bi report with me.
Hello, could you please share the sample report with me as well? The link above is expired. Thank you so much!!
Thank you so much for the information, my data worked the same way as your sample. Great! that's what I'm looking for.
All the Best!
I like it!
We've not fully defined our analysis needs but comparing overlap hours for lower division courses as well as time slot frequency are at the top of our list. Think “Guide Pathways” and that really encapsulates what we as a community college need to analyze.
I'm working on trying to solve the same problem in Power BI. Were you ever able to find a solution?
kw127533,
I ended up breaking each day into timeblocks of minutes (1,440 min/day) and then performing a simple comparison of course start time/end time against each timeblock. This worked for me and I was able to visualize course schedule density by various units of time (i.e. day, week, month, term, year, etc.). So many of our courses start and end at odd times rather than on the hour so I couldn't think of another way to tackle this challenge other than moving to smaller time units.
I've been sidetracked on other projects but when I get back to it, I want to bring in course geolocation data and overlay that on our campus map to analyse traffic flows and space utilization.
Hope that helps.
Yeah, I was considering that approach as well but by the quarter or half hour. How did you manage creating the timeblocks? Did you create a column for each minute or use something like R to automate this?
kw127533,
I created a lookup table with 1,440 rows for the minutes througout the day and then used DAX to evaluate if the minute of time fell between class start/stop time. This gave me bands of rows that could be used for density plots. Don't recall all the details as I've been busy with other projects but hope to get back to it again soon.
I am absolutely sure there is a much more elegant way to do this that uses pure DAX without a lookup table but this is the approach I used to quickly solve the problem. The calendar feature of Power BI may also facilitate this kind of analysis but I"ve not had time to explore. I'm also sure others in this forum has solved similar problems but during my search, I wasn't able to find the solution I was after.
Good luck!
Well that's definitely a better solution than what I had in mind and anything I found in the forums. Thanks for the information! I'll keep you posted as to how my analysis goes.
hi, @BlueTeam
Consider only END-TIME for your review.
And use YEAR and MONTH filter for your controls.
Download the visual
Download sample
Please try and test using it. And please mark the right reply as answer if your issue has been resolved, otherwise, please feel free to ask if you have any other issue.
Best Regards,
Rfranca
I could be wrong, but I do not think this custom visual will solve the problem I have describe. The custom histogram visual shows two dimensions of: Bin and frequency (count of occurrences). If the Bin is defined as the start or end time and then we use count of occurrences for the values, we end up with a visual of time usage but it does not account for the days in the week. For example, most 3-credit courses meet Monday, Wednesday and Friday. By not including the day name, we will not see time openings on Tuesday and Thursday because we are looking at the entire year, term or month.
I keep thinking about a calendar type component or heat map visual of day/time but maybe I'm not going about this the right way.
To reintegrate the challenge, I am attempting to identify high and low usage time blocks throughout the week (Monday-Friday). The data contain everything needed to identify the blocks but how to visually represent this in an intuitive fashion has eluded me.
Thanks!
Hi @BlueTeam,
What's the expected outcome? Maybe you can assign an ID for each usage.
Best Regards,
Dale
The outcome desired is to identify low use time blocks so as to best schedule faculty meetings for professional development. Because not all time blocks are the same duration, it is a bit more challenging. A heatmap grid might work well but again, I'm not sure what would be most useful as a visual tool for those who will be utilizing it.
On a related note, I also believe solving this problem may help me work throught the next challenge which is classroom utilization.
Thanks!
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 |
---|---|
94 | |
92 | |
83 | |
71 | |
49 |
User | Count |
---|---|
143 | |
120 | |
110 | |
60 | |
57 |