Formula Assistance: Re-occuring Weekly Calculation

bosemachine

New Member
Joined
May 8, 2013
Messages
8
Hi all,

Using the top 3 rows in the table below, I'm trying to produce the "daily" row output.

datemontueswedthursfrisatsunmontueswedthursfrisatsun...
1/11/21/31/41/51/61/71/81/91/101/111/121/131/14...
weekly3060...
daily55555501010101010100...

<tbody>
</tbody>

Basically take the weekly total defined in the thurs column and divy it up from monday-saturday with sunday zero'd out and have it be auto-fill'able' to right for an infinite # of columns.

The trouble I'm running into us being able to reference the thursday weekly cell specifically for each of the repeat set in a way that's efficient and doesn't create a monstrosity of a formula.

Any suggestions?

B
 

Some videos you may like

Excel Facts

Did you know Excel offers Filter by Selection?
Add the AutoFilter icon to the Quick Access Toolbar. Select a cell containing Apple, click AutoFilter, and you will get all rows with Apple

LxQ

Well-known Member
Joined
Feb 9, 2006
Messages
619
I would use some logic like this: at any given day, Thursday is either 3 days ahead or it was 3 days ago... or anything in between. So, for example, on Sunday, 1/7 I can write a formula to look for "thurs" from 1/4 through 1/10

Let's say the 0 for Sunday, 1/7 is in H4

=if(h1="sun",0,hlookup("thurs",E1:K3,3,)/6)
 

bosemachine

New Member
Joined
May 8, 2013
Messages
8
I would use some logic like this: at any given day, Thursday is either 3 days ahead or it was 3 days ago... or anything in between. So, for example, on Sunday, 1/7 I can write a formula to look for "thurs" from 1/4 through 1/10

Let's say the 0 for Sunday, 1/7 is in H4

=if(h1="sun",0,hlookup("thurs",E1:K3,3,)/6)

Spot on! Thank you for that!

As a follow up (if you don't mind), what happens if the daily value for Friday-Thursday were derived from the weekly value of the following thursday (so it'll always be within 7 subsequent days unless it falls on a thursday)?

Building off your elegant formula:


=IF(h1="sun",0,(IF(h1="thur",OFFSET(h1,2,0)/6,HLOOKUP("thur",h1:O3,3)/6)))

It's way less desirable but I couldn't think of another way to avoid having 2 "thur" in one HLOOKUP with the one I need farthest away.

Thank you!!
 
Last edited:

bosemachine

New Member
Joined
May 8, 2013
Messages
8
I just wanted to say thank you again and that the above formula worked once HLOOKUP was re-written as HLOOKUP("thur",h1:O3,3,0), otherwise it would give #VALUE on all days except the immediately preceding Monday.

Thanks again and have a great evening!
 

Watch MrExcel Video

Forum statistics

Threads
1,123,307
Messages
5,600,869
Members
414,411
Latest member
Snowmanaus

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
Top