1st / 2nd / 3rd Days of the week

rrd_donn

New Member
Joined
Sep 30, 2005
Messages
5
All, I hope you can assist me. I am encountering an issue using formula to calcuate the 1st / 2nd / 3rd 4th / Mondays - Sunday of each month.

In my spreadsheet cell B2 - M2 has the month (Jan - Dec 2011). From this i need to work out the 1st Monday / 2nd Monday etc etc.

My formula keeps erroring and I cannot workout the weekday function. Can you offer me any advice?.

Many thanks.
 

Excel Facts

Shade all formula cells
To shade all formula cells: Home, Find & Select, Formulas to select all formulas. Then apply a light fill color.
All, I hope you can assist me. I am encountering an issue using formula to calcuate the 1st / 2nd / 3rd 4th / Mondays - Sunday of each month.

In my spreadsheet cell B2 - M2 has the month (Jan - Dec 2011). From this i need to work out the 1st Monday / 2nd Monday etc etc.

My formula keeps erroring and I cannot workout the weekday function. Can you offer me any advice?.

Many thanks.

See this link, hope it may help you.

http://www.mrexcel.com/forum/showthread.php?t=80465

Regards
RAMU
 
Upvote 0
Hello, Thankyou for your reply. I'm still struggling to figure it out, if possible a little more help would be great!.

Here is the layout of my spreadsheet.....

A1 B1 C1 D1

Date Device October November

1st Monday Device 1
1st Monday Device 2
1st Saturday Device 3
2nd Sunday Device 4
3rd Sunday Device 5
4th Saturday Device 6
3rd Wednesday Device 7
4th Tuesday Device 8

So I need the date for the 1st Monday to be entered in the October and November columns and then the respective 1st Sat, 2nd Sun etc etc onwards.
 
Upvote 0
Hello, Thankyou for your reply. I'm still struggling to figure it out, if possible a little more help would be great!.

Here is the layout of my spreadsheet.....

A1 B1 C1 D1

Date Device October November

1st Monday Device 1
1st Monday Device 2
1st Saturday Device 3
2nd Sunday Device 4
3rd Sunday Device 5
4th Saturday Device 6
3rd Wednesday Device 7
4th Tuesday Device 8

So I need the date for the 1st Monday to be entered in the October and November columns and then the respective 1st Sat, 2nd Sun etc etc onwards.

Which Year ?
 
Upvote 0
One way:

Code:
      ---A--- ---B--- ---C---- -------D------- -------E-------
  1   Ordinal Weekday Whatever    Oct-2011        Nov-2011    
  2         1       2          Mon 03 Oct 2011 Mon 07 Nov 2011
  3         1       7          Sat 01 Oct 2011 Sat 05 Nov 2011
  4         2       1          Sun 09 Oct 2011 Sun 13 Nov 2011

Ordinal means 1st, 2nd, ...

Weekday mean Sun=1, Mon=2, ...

In D2 and copied across and down,

=DATE(YEAR(D$1), MONTH(D$1), 1 + ( ($A2 - ($B2 >= WEEKDAY(DATE(YEAR(D$1), MONTH(D$1), 1)))) * 7) + ($B2 - WEEKDAY(DATE(YEAR(D$1), MONTH(D$1), 1))))
 
Upvote 0
With respect to Mr. Shg, I think this may be other way.

<TABLE style="PADDING-RIGHT: 2pt; PADDING-LEFT: 2pt; FONT-SIZE: 11pt; FONT-FAMILY: Calibri,Arial; BACKGROUND-COLOR: #ffffff" cellSpacing=0 cellPadding=0 border=1><COLGROUP><COL style="FONT-WEIGHT: bold; WIDTH: 30px"><COL style="WIDTH: 69px"><COL style="WIDTH: 69px"><COL style="WIDTH: 64px"><COL style="WIDTH: 64px"><COL style="WIDTH: 80px"><COL style="WIDTH: 64px"><COL style="WIDTH: 76px"><COL style="WIDTH: 64px"></COLGROUP><TBODY><TR style="FONT-WEIGHT: bold; FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center"><TD> </TD><TD>A</TD><TD>B</TD><TD>C</TD><TD>D</TD><TD>E</TD><TD>F</TD><TD>G</TD><TD>H</TD></TR><TR style="HEIGHT: 18px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">1</TD><TD style="TEXT-ALIGN: right">1</TD><TD> </TD><TD>Sunday</TD><TD style="TEXT-ALIGN: right">1</TD><TD> </TD><TD style="TEXT-ALIGN: right">2011</TD><TD>January</TD><TD style="TEXT-ALIGN: right">1</TD></TR><TR style="HEIGHT: 18px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">2</TD><TD style="TEXT-ALIGN: right">2</TD><TD> </TD><TD>Monday</TD><TD style="TEXT-ALIGN: right">2</TD><TD> </TD><TD> </TD><TD>February</TD><TD style="TEXT-ALIGN: right">2</TD></TR><TR style="HEIGHT: 18px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">3</TD><TD style="TEXT-ALIGN: right">3</TD><TD> </TD><TD>Tuesday</TD><TD style="TEXT-ALIGN: right">3</TD><TD> </TD><TD> </TD><TD>March</TD><TD style="TEXT-ALIGN: right">3</TD></TR><TR style="HEIGHT: 18px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">4</TD><TD style="TEXT-ALIGN: right">4</TD><TD> </TD><TD>Wednesday</TD><TD style="TEXT-ALIGN: right">4</TD><TD> </TD><TD> </TD><TD>April</TD><TD style="TEXT-ALIGN: right">4</TD></TR><TR style="HEIGHT: 18px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">5</TD><TD style="TEXT-ALIGN: right">5</TD><TD> </TD><TD>Thursday</TD><TD style="TEXT-ALIGN: right">5</TD><TD> </TD><TD> </TD><TD>May</TD><TD style="TEXT-ALIGN: right">5</TD></TR><TR style="HEIGHT: 18px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">6</TD><TD> </TD><TD> </TD><TD>Friday</TD><TD style="TEXT-ALIGN: right">6</TD><TD> </TD><TD> </TD><TD>June</TD><TD style="TEXT-ALIGN: right">6</TD></TR><TR style="HEIGHT: 18px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">7</TD><TD> </TD><TD> </TD><TD>Saturday</TD><TD style="TEXT-ALIGN: right">7</TD><TD> </TD><TD> </TD><TD>July</TD><TD style="TEXT-ALIGN: right">7</TD></TR><TR style="HEIGHT: 18px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">8</TD><TD> </TD><TD> </TD><TD> </TD><TD> </TD><TD> </TD><TD> </TD><TD>August</TD><TD style="TEXT-ALIGN: right">8</TD></TR><TR style="HEIGHT: 18px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">9</TD><TD> </TD><TD> </TD><TD> </TD><TD> </TD><TD> </TD><TD> </TD><TD>September</TD><TD style="TEXT-ALIGN: right">9</TD></TR><TR style="HEIGHT: 18px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">10</TD><TD> </TD><TD> </TD><TD> </TD><TD> </TD><TD> </TD><TD> </TD><TD>October</TD><TD style="TEXT-ALIGN: right">10</TD></TR><TR style="HEIGHT: 18px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">11</TD><TD> </TD><TD> </TD><TD> </TD><TD> </TD><TD> </TD><TD> </TD><TD>November</TD><TD style="TEXT-ALIGN: right">11</TD></TR><TR style="HEIGHT: 18px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">12</TD><TD> </TD><TD> </TD><TD> </TD><TD> </TD><TD> </TD><TD> </TD><TD>December</TD><TD style="TEXT-ALIGN: right">12</TD></TR><TR style="HEIGHT: 18px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">13</TD><TD> </TD><TD> </TD><TD> </TD><TD> </TD><TD> </TD><TD> </TD><TD> </TD><TD> </TD></TR><TR style="HEIGHT: 18px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">14</TD><TD>1st Sunday of September 2011</TD><TD> </TD><TD> </TD><TD> </TD><TD> </TD><TD> </TD><TD> </TD><TD> </TD></TR><TR style="HEIGHT: 18px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">15</TD><TD style="FONT-SIZE: 10pt; FONT-FAMILY: Verdana; BACKGROUND-COLOR: #ffff00; TEXT-ALIGN: right">04-09-11</TD><TD> </TD><TD> </TD><TD> </TD><TD> </TD><TD> </TD><TD> </TD><TD> </TD></TR></TBODY></TABLE>
<TABLE style="FONT-SIZE: 10pt; BORDER-LEFT-COLOR: #00ff00; BORDER-BOTTOM-COLOR: #00ff00; COLOR: #000000; BORDER-TOP-STYLE: groove; BORDER-TOP-COLOR: #00ff00; FONT-FAMILY: Arial; BORDER-RIGHT-STYLE: groove; BORDER-LEFT-STYLE: groove; BACKGROUND-COLOR: #fffcf9; BORDER-RIGHT-COLOR: #00ff00; BORDER-BOTTOM-STYLE: groove"><TBODY><TR><TD>Spreadsheet Formulas</TD></TR><TR><TD><TABLE style="FONT-SIZE: 9pt; FONT-FAMILY: Arial" cellSpacing=0 cellPadding=2 border=1><TBODY><TR style="FONT-SIZE: 10pt; BACKGROUND-COLOR: #cacaca"><TD>Cell</TD><TD>Formula</TD></TR><TR><TD>A15</TD><TD>=DATE(F1,H9,1+7*A1)-WEEKDAY(DATE(F1,H9,8-D1))</TD></TR></TBODY></TABLE></TD></TR></TBODY></TABLE>
 
Upvote 0

Forum statistics

Threads
1,224,514
Messages
6,179,219
Members
452,895
Latest member
BILLING GUY

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top