I have data in a table that looks like this:
VISIT ID | Surgeon | Surgeon Arrival Before Schedule in Minutes | ...
123 | Dr. A | -45
156 | Dr. A | -25
198 | Dr. A | 32
... | ...
I want to construct a query that will bin and count, meaning I would like an output like the following:
Surgeon | Bin 1 | Bin 2 | Bin 3 | ... | Bin 6
Dr. A | 2 | 0 | 4 | ... | 0
Above, the Bin(s) are defined where the Surgeon Arrival Before Schedule in Minutes
column falls into a bin with the following logic:
Bin 1 = Surgeon Arrival Before Schedule in Minutes <= -30
Bin 2 = -30 < Surgeon Arrival Before Schedule in Minutes <= -15
Bin 3 = -15 < Surgeon Arrival Before Schedule in Minutes <= 0
Bin 4 = 0 < Surgeon Arrival Before Schedule in Minutes <= 15
Bin 5 = 15 < Surgeon Arrival Before Schedule in Minutes <= 30
Bin 6 = Surgeon Arrival Before Schedule in Minutes > 30
I want to COUNT
how many Encounter ID
numbers fall into each bin to produce the desired result.
I have been trying queries such as:
TRANSFORM Count([or on time log].[ENCOUNTER ID]) AS CountOfID
SELECT [or on time log].[Surgeon]
FROM [or on time log]
GROUP BY [or on time log].[Surgeon]
PIVOT IIf([Surgeon Arrival Before Schedule in Minutes] <= -30, "Bin 1",
IIf(-30 < [Surgeon Arrival Before Schedule in Minutes] <= -15, "Bin 2",
IIf(-15 < [Surgeon Arrival Before Schedule in Minutes] <=0, "Bin 3",
IIf(0 < [Surgeon Arrival Before Schedule in Minutes] <=15, "Bin 4",
IIf(15 < [Surgeon Arrival Before Schedule in Minutes] <= 30, "Bin 5",
IIf(30 < [Surgeon Arrival Before Schedule in Minutes], "Bin 6")
)
)
)
)
)
;
Doing so gives me only bins 1 and 3 Surgeon which is not accurate.
As a first step, assign the bin number for each arrival.
This is the sample table I used.
VISIT_ID Surgeon Arrival
123 Dr. A -45
156 Dr. A -25
198 Dr. A 32
The query below uses a Switch expression to assign the bin number, giving me this result set.
VISIT_ID Surgeon Arrival bin_number
123 Dr. A -45 1
156 Dr. A -25 2
198 Dr. A 32 6
SELECT
o.VISIT_ID,
o.Surgeon,
o.Arrival,
Switch
(
o.Arrival <= -30, 1,
o.Arrival <= -15, 2,
o.Arrival <= 0, 3,
o.Arrival <= 15, 4,
o.Arrival <= 30, 5,
o.Arrival > 30, 6,
) AS bin_number
FROM OR_on_time_log AS o;
You can build on that with a PIVOT
to return the bin counts for each surgeon.