quarterly, semi-annually??

C

colonel-shoe

Hi,
new to the forum so be gentle. ok deep breath....
I need help with a spreadsheet i have drawn up to keep track of bills


In one column you can select whether the bill i
monthly,quarterly,semi-annual or yearly (using a dropdown list). In th
next column you can select the 1st month the bill is paid (another dro
down box, date in mmm format). The next column displays whether th
bill is payable this month based on todays date (either yes or no). S
it looks something like this:

TODAYS DATE

____________M,Q,SA,Y? ___1ST BILL MONTH ___PAYABLE THIS MONTH?
BILL1 _________SA ______________MAY ______________YES
BILL2 _________Q________________JULY _____________NO
BILL3 _________Y________________MARCH____________ NO

This last column is the one im having trouble with. I can get it to sa
yes if the 1st bill month matches todays month, but writing a formul
that works out subsequent billing months based on the m,q,sa column an
then seeing if they match todays month is a real headache. they end u
being massive nested affairs of the form
=IF(OR(TEXT(I5,"mmm")=TEXT(D9,"mmm"),TEXT(DATE(YEAR(D9),MONTH(D9)+3,DAY(D9)),"mmm")=TEXT(I5,"mmm")),"yes","no"
where I5 is todays date and D9 is the first bill month column. This on
just sees whether today matches the bill month or the bill month +3, s
you could see how +3, +6, +9 would become huge.

monthly and yearly are easy to sort out in a formula, because if
bills monthly it will always be payable and if its yearly then its onl
going to fall on the 1st bill month no matter what. So the problem is
formula for semi annual and quarterly months.
Im getting myself tied up in arrays and index,match etc so i need t
take a step back and let a fresh set of eyes look at the problem.

cheers for listening to my rant :
 
D

daddylonglegs

Assuming C9 contains "SA", "Q" or "Y", D9 a date, I5 today's date the
try

=IF(MOD(MONTH($I$5)-MONTH(D9),IF(C9="Q",3,IF(C9="Y",12,6))),"No","Yes"
 
D

daddylonglegs

To accommodate "M" also....

=IF(MOD(MONTH($I$5)-MONTH(D9),IF(C9="Q",3,IF(C9="Y",12,IF(C9="M",1,6)))),"No","Yes
 
B

Bob Phillips

If you change the first bill date from just a month to the actual date (you
could format it as mmmm to look the same), then just use

=OR(MONTH(C2)=MONTH(TODAY()),IF(B2="SA",MONTH(TODAY())=MONTH(DATE(YEAR(C2),M
ONTH(C2)+6,1))),IF(B2="Q",MONTH(TODAY())=MONTH(DATE(YEAR(C2),MONTH(C2)+{3,6,
9},1))))

which is an array formula, it should be committed with Ctrl-Shift-Enter, not
just Enter.

--
HTH

Bob Phillips

(remove xxx from email address if mailing direct)

"colonel-shoe" <[email protected]>
wrote in message
news:[email protected]...
 
C

colonel-shoe

cheers for the reply guys.

daddylonglegs, could you explain how your equation works, im not ver
familiar with the MOD function.

ill mess about with both and see how i get o
 
D

daddylonglegs

colonel-shoe said:
cheers for the reply guys.

daddylonglegs, could you explain how your equation works, im not very
familiar with the MOD function.

ill mess about with both and see how i get on

The IF function gives the second argument of the MOD function. To
simplify things assume C9 is "Q" then this

=IF(MOD(MONTH($I$5)-MONTH(D9),IF(C9="Q",3,IF(C9="Y",12,IF(C9="M",1,6))
)),"No","Yes" )

becomes

=IF(MOD(MONTH($I$5)-MONTH(D9),3),"No","Yes" )

so whenever MOD(MONTH($I$5)-MONTH(D9),3) is zero you get "Yes",
otherwise "No"

Assuming MONTH($I$5) is 5 (for May) then when MONTH(D9) is 2,5,8 or 11
the MOD function is zero, thus returning "Yes" every 3 months. Look up
Excel help on MOD for further information.

Clearly "SA" and "Y" etc. work the same way although the second
argument of MOD would be set to 6 and 12 respectively, giving you "Yes"
every 6 or 12 months respectively
 

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