Help with dates please

jedibrown

Board Regular
Joined
Oct 17, 2011
Messages
136
Hi, I was just wondering whether there was a formula to change a date once per week.

For example, instead of using =today() is there a way that I can make the date stay on a Friday until the following one.

So tomorrow it would change to 16/12/11 and stay like that until next Friday when it would change to 23/12/11 and so on.

This is because I am trying to put in "week beginning" but my week begins on a Friday. Thanks :)
 
MrKowz, is there something different about the weekday function in Excel versions 2007 up?

It would appear that way. I am using Excel 2010. Doing some quick research to find out when it changed:

<b>Excel 2010</b><table cellpadding="2.5px" rules="all" style=";background-color: #FFFFFF;border: 1px solid;border-collapse: collapse; border-color: #BBB"><colgroup><col width="25px" style="background-color: #DAE7F5" /><col /><col /><col /></colgroup><thead><tr style=" background-color: #DAE7F5;text-align: center;color: #161120"><th></th><th>A</th><th>B</th><th>C</th></tr></thead><tbody><tr ><td style="color: #161120;text-align: center;">1</td><td style=";">Date</td><td style=";">MrKowz</td><td style=";">P45cal</td></tr><tr ><td style="color: #161120;text-align: center;">2</td><td style="text-align: right;;">Tue 13 Dec 2011</td><td style="text-align: right;;">Fri 9 Dec 2011</td><td style="text-align: right;;">Fri 9 Dec 2011</td></tr><tr ><td style="color: #161120;text-align: center;">3</td><td style="text-align: right;;">Wed 14 Dec 2011</td><td style="text-align: right;;">Fri 9 Dec 2011</td><td style="text-align: right;;">Fri 9 Dec 2011</td></tr><tr ><td style="color: #161120;text-align: center;">4</td><td style="text-align: right;;">Thu 15 Dec 2011</td><td style="text-align: right;;">Fri 9 Dec 2011</td><td style="text-align: right;;">Fri 9 Dec 2011</td></tr><tr ><td style="color: #161120;text-align: center;">5</td><td style="text-align: right;;">Fri 16 Dec 2011</td><td style="text-align: right;;">Fri 16 Dec 2011</td><td style="text-align: right;;">Fri 16 Dec 2011</td></tr><tr ><td style="color: #161120;text-align: center;">6</td><td style="text-align: right;;">Sat 17 Dec 2011</td><td style="text-align: right;;">Fri 16 Dec 2011</td><td style="text-align: right;;">Fri 16 Dec 2011</td></tr><tr ><td style="color: #161120;text-align: center;">7</td><td style="text-align: right;;">Sun 18 Dec 2011</td><td style="text-align: right;;">Fri 16 Dec 2011</td><td style="text-align: right;;">Fri 16 Dec 2011</td></tr><tr ><td style="color: #161120;text-align: center;">8</td><td style="text-align: right;;">Mon 19 Dec 2011</td><td style="text-align: right;;">Fri 16 Dec 2011</td><td style="text-align: right;;">Fri 16 Dec 2011</td></tr><tr ><td style="color: #161120;text-align: center;">9</td><td style="text-align: right;;">Tue 20 Dec 2011</td><td style="text-align: right;;">Fri 16 Dec 2011</td><td style="text-align: right;;">Fri 16 Dec 2011</td></tr><tr ><td style="color: #161120;text-align: center;">10</td><td style="text-align: right;;">Wed 21 Dec 2011</td><td style="text-align: right;;">Fri 16 Dec 2011</td><td style="text-align: right;;">Fri 16 Dec 2011</td></tr><tr ><td style="color: #161120;text-align: center;">11</td><td style="text-align: right;;">Thu 22 Dec 2011</td><td style="text-align: right;;">Fri 16 Dec 2011</td><td style="text-align: right;;">Fri 16 Dec 2011</td></tr><tr ><td style="color: #161120;text-align: center;">12</td><td style="text-align: right;;">Fri 23 Dec 2011</td><td style="text-align: right;;">Fri 23 Dec 2011</td><td style="text-align: right;;">Fri 23 Dec 2011</td></tr></tbody></table><p style="width:3.6em;font-weight:bold;margin:0;padding:0.2em 0.6em 0.2em 0.5em;border: 1px solid #BBB;border-top:none;text-align: center;background-color: #DAE7F5;color: #161120">Sheet2</p><br /><br /><table width="85%" cellpadding="2.5px" rules="all" style=";border: 2px solid black;border-collapse:collapse;padding: 0.4em;background-color: #FFFFFF" ><tr><td style="padding:6px" ><b>Worksheet Formulas</b><table cellpadding="2.5px" width="100%" rules="all" style="border: 1px solid;text-align:center;background-color: #FFFFFF;border-collapse: collapse; border-color: #BBB"><thead><tr style=" background-color: #DAE7F5;color: #161120"><th width="10px">Cell</th><th style="text-align:left;padding-left:5px;">Formula</th></tr></thead><tbody><tr><th width="10px" style=" background-color: #DAE7F5;color: #161120">B2</th><td style="text-align:left">=A2-WEEKDAY(<font color="Blue">A2,15</font>)+1</td></tr><tr><th width="10px" style=" background-color: #DAE7F5;color: #161120">C2</th><td style="text-align:left">=A2-MOD(<font color="Blue">A2+1,7</font>)</td></tr></tbody></table></td></tr></table><br />
 
Upvote 0

Excel Facts

Copy a format multiple times
Select a formatted range. Double-click the Format Painter (left side of Home tab). You can paste formatting multiple times. Esc to stop
Quick research showed that this change was made in Excel 2010. Thank you for catching that, P45cal. :biggrin:
 
Upvote 0
=A1-WEEKDAY(A1,15)+1

easily modifiable for earlier versions, both of these will do the same thing

=A1-WEEKDAY(A1+3,3)

or

=A1-WEEKDAY(A1+2)+1

Personally I would avoid solutions using MOD like

=A1-MOD(A1+1,7)

because the result can change depending on date system, that will return a Thursday if you are using 1904 date system
 
Upvote 0

Forum statistics

Threads
1,223,250
Messages
6,171,036
Members
452,374
Latest member
keccles

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