Displaying negative time

B

Babs

Hi everyone,
first time on here so hope you can help me.

I use Excel (2003) for recording employee time / flexi hours. This is
allowed to go into a negative but I can't seem to display this. The formula
calculates fine and when the time is positive is shown in the time format (ie
15:30 etc) but when it is negative I just get #### which usually means the
column needs widening but this doesn't make any difference.
Any ideas anyone?
Thanks
 
D

Dave Peterson

You can display negative time if you're using the 1904 base date.

In xl2003 menus:
Tools|Options|Calculation tab|check "1904 date system"

Be aware that your existing dates will be now be off by 4 years and one day.
You can fix this, though. But a bigger problem may be when you copy dates from
one workbook to another (each using different date systems).

Saved from a previous post:

Be aware that any existing date will now be off by 4 years and 1 day. And
copying dates between workbooks becomes a problem, too.

One workbook was using a base year of 1900 and the other was using 1904.
(tools|options|calculation tab|1904 date system)

One way to add those four years back is to find an empty cell, put 1462 into
that cell.

Copy that cell.

Select your range that contains the dates. Edit|PasteSpecial|click Add (in the
operation box).

You may have to reformat the cell as a date (mine turned to a 5 digit number).
But it should work.

You may want to do it against a copy...just in case.

(I'm not sure which one you'll fix. You may want to edit|pastespecial|click
subtract.)

Most windows users use 1900 as the base date. Mac users (mostly??) use 1904 as
the base date.
 
F

Fred Smith

The only way to display negative times is to switch to the 1904 date system.
However, this will change every date in your spreadsheet by 4 years and 1
day, so for most people it's impractical.

Excel will do all the calculations, it just won't *display* negative times.
An alternative, therefore, may be to display decimal hours rather than
times. To do this, multiply your result by 24, and format as a number (or
general).

Is this something you can work with?

Regards,
Fred.
 
N

Niek Otten

Although Excel can't display negative times, the undelying value is still
correct, so you can include them in calculations like SUM().
To display them, you would need a separate cell like

=IF(C1>0,TEXT(C1,"hh:mm:ss"),"-"&TEXT(ABS(C1),"hh:mm:ss"))

Of course that is text, so only for display, not for calculation
 
B

Babs

Many thanks Niek,
I prefer your option rather than changing the date system so I've inserted a
row and used your formula which works fine! ...... the next question is can
I now use conditional formatting to make the negative (text) time show in red
& bold! I have tried and it doesn't seem to work but of course it's now text
not a number below zero.

At lease it does show the time with a - (minus) sign so I'm please with that
and I can hide the calculating cell if needs,
thanks again
 
F

Fred Smith

You can still use conditional formatting, you just have to do it for text,
not a number. Use a formula like:
=left(a1,1)="-"

Regards
Fred

Babs said:
Many thanks Niek,
I prefer your option rather than changing the date system so I've inserted
a
row and used your formula which works fine! ...... the next question is
can
I now use conditional formatting to make the negative (text) time show in
red
& bold! I have tried and it doesn't seem to work but of course it's now
text
not a number below zero.

At lease it does show the time with a - (minus) sign so I'm please with
that
and I can hide the calculating cell if needs,
thanks again
 
B

Babs

Absolutely brilliant! I'd never have know how to do this, many thanks for
your help
 
B

Bernard Liengme

Thanks, Niek, for putting me straight. I do not work much with time and have
always assumed the #### was an error rather than just a message "I cannot
show you that"
best wishes
 

Ask a Question

Want to reply to this thread or ask your own question?

You'll need to choose a username for the site, which only take a couple of moments. After that, you can post your question and our members will help you out.

Ask a Question

Top