
Originally Posted by
Russ15
Any suggestions? Any help is greatly appreciated.
I think the worksheet "fix" in the file "russ fixed.xlsx" (click on the file name) does what you intended. The formulas:
C14: =--TEXT(MOD(C13+"1:00",1),"hh:mm")
E13: =--TEXT(MOD(C13+"2:00",1),"hh:mm")
G11: =IF(AND(ISNUMBER(C11),ISNUMBER(E11)),ROUND(MOD(E11-C11,1)*96,0)/4,"")
H11: =IF(N(G11)=0,"",IF(G11<=2,3,""))
I11: =IF(N(G11)>2,2,"")
J11: =IF(N(G11)>2,ROUND(G11-2,2),"")
Copy C14 down through C30
Copy D13 down through E30
Copy G11:J11 down through G35:J35
Similar changes in G53:I78
In Russ'soriginal design, columns G:J represented hours as a decimal number. There is no need to change that, as FDibbins did. In fact, I think the change to hh:mm representation complicates the arithmetic.
The formulas in columns C and E ensure that time is rounded to the minute with the correct binary representation. That was part of Russ's original problem: the unrounded time arithmetic (Fill Series) created infinitesimal binary anomalies.
The formula in column G is essentially the correction that Bernie suggested: replacing SUM with ROUND. Bernie's change did not seem to work as intended because of mistakes in Russ's original formula, to wit:
1. In column H, =IF(G11=0,0,IF(G11<2,3,0)) should be =IF(G11=0,0,IF(G11<=2,3,0)).
2. The formula in I11, =IF(G11>2,MIN(2,G11),""), is changed to =IF(G25>=2,MIN(2,G25),"") starting in I25.
The N() function in columns H:I allow for the value in column G to be the null string ("").
I believe the formulas in columns H:I resolve ambiguities in Russ's description. But only Russ can confirm that. The ambiguities are described below.
In another discussion, Russ wrote:

Originally Posted by
Russ15
If you work 2 hours or less you get paid 3 hours of straight time over time (STO)
If you work 2 hours or more you get paid the first 2 hours at 1 1/2 (1.5X) times (THO) and the rest at 2X (DTO).
For exactly 2 hours, there would be results in both STO and THO. I don't believe that is the intention.
In fact, in this discussion, Russ wrote:

Originally Posted by
Russ15
When there are exactly 2 hours or less worked the result should be 3 hours of STO.
One minute over that total and it should go to THO for the first 2 hours and DTO for any time after the 2 hours.
Thus, the formula in column H is =IF(N(G11)=0,"",IF(G11<=2,3,"")).
And the formulas in column I:J are =IF(N(G11)>2,2,"") and =IF(N(G11)>2,ROUND(G11-2,2),"").
However, there is still an ambiguity. Russ wrote "one minute over that". But in fact, his original formula rounds to the nearest quarter-hour.
So in fact, 7 minutes or less over 2 hours is rounded to 2 hours. So 3 hours of STO is recorded. See row 31.
But 8 minutes or more over 2 hours is rounded to 2.25 hours or more. So THO and DTO time are recorded. See row 32.
Finally....
It seems odd to me that effectively time-and-one-half (3) is record in STO, but just time (2) and time-over-two are recorded for THO and DTO.

Originally Posted by
Russ15
That is true, I did put in times and copy down. [....] For some reason, the vast majority of any entries of exactly 2 hours excel does not deal with well. If it is one minute under (119 minutes) or one minute over (121 minutes) excel does a great job of those, but exactly 120 minutes it cannot handle. I have no explanation.
See the comment about unrounded time arithmetic above. If that is not sufficient, I can explain in more detail.
In a nutshell, Excel time is represented as a fraction of a day. And with the binary representation that Excel (and most applications) uses internally, most non-integer values cannot be represented exactly. These infinitesimal differences cause the result of most arithmetic to be different from mathematical expectations.
Bookmarks