Help needed with rolling charts

Coverfire

New Member
Joined
Aug 24, 2020
Messages
1
Office Version
  1. 2013
Platform
  1. Windows
Hi there,

I've been asked by my boss to create a 7-day rolling chart following three sets of data. I need the totals on the y-axis and the dates on the x-axis. I feel I've done well, I followed an online tutorial and learned about=OFFSET but while the tutorial worked perfectly for a single dataset with dates, when I added more datasets, the dates threw a hissy fit. What I would like, is for the dates rolling with the cells that contain information so I can
preemptively drag down the dates for the season because that is what the workers are used too.

Though I have the datasets working nicely, the fact that the dates aren't working, while a minor irritation, is a nagging failure to me. I know dates in excel can be trying but is there anything I can do to fix this please?

Thanking you in advance,

Aaron

Chart.PNG
Chart 1.PNG
 

Excel Facts

Create a chart in one keystroke
Select the data and press Alt+F1 to insert a default chart. You can change the default chart to any chart type
Can't see your range selections for your chart. But, this is what I did... Since I don't know your skill level, I'll include all steps...

Make three named ranges on your data and use the OFFSET formula for the named ranges. On my sample sheet, this are the steps to create the first range...

Since you want the last seven days of data from ROW 5 (see below), and the corresponding date ranges from row 4, create a formula in a blank cell as follows:
=OFFSET(Data!$C$5,0,COUNTA(Data!$C$5:$ZZ$5)-7,1,7)
Next, create a range for your dates:
=OFFSET(Data!$C$4,0,COUNTA(Data!$C$4:$ZZ$4)-7,1,7)

If the two formulas bring back the correct data, and you can add data to the last column of the table and it shows in the test range, then copy the first formula into your clipboard (highlight, then <CTRL>+<X> then <ESC>....this cuts it into the buffer and the ESC puts it back). On the Formulas Tab, click Define Name. I called mine TestPumpHours. In the refers to box, select all references in there and paste <CTRL>+<V>. Click OK. To test this works, click in a blank cell, enter =TestPumpHours<enter> and you should see the right-most seven data points. If you add new data to the right of the table (cell L4 and L5), you should see the data update in your test range. This is how you're sure it works.

Do the same for the date range.

Finally, select your chart for this data range. On the Chart Design tab, click Select Data. Select the data range and click EDIT. You are going to change the existing data range to the named range you just created. The trick is you have to put the Sheet Name in front of the range name. In my example, I replaced the range with =Data!TestPumpHours. Click OK. If you did it correctly, Excel should accept your change. Next, do the same for the Horizontal Category Names (Dates) by clicking Edit and entering =Data!TestDateRange.

Click OK and OK and try adding data to your table and watch the graph automatically update to the last 7 days.

NOTE: The XL2BB did NOT copy my graph. But, if you follow the instructions, your graph should update as you wanted. Let me know if the info I wrote is not clear, or if you need more help.

Hope this helps.

Bill B.

Self Updating Chart.xlsx
ABCDEFGHIJKLMNO
3UNITSRO #1RO #1RO #1RO #1RO #1RO #1RO #1RO #1RO #1RO #1RO #1RO #1RO #1
4Date4/144/174/194/204/214/244/254/264/27
5Pump Hours 11,708 11,781 11,823 11,843 11,871 11,919 11,943 11,967 12,014
6
7Below test data to copy above…
84/19/20204/20/20204/21/20204/24/20204/25/20204/26/20204/27/20204/305/15/2
9TEST --> 11,823 11,843 11,871 11,919 11,943 11,967 12,014 12,049 12,084 12,102
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
Data
Cell Formulas
RangeFormula
D8:J8D8=OFFSET(Data!$C$4,0,COUNTA(Data!$C$4:$ZZ$4)-7,1,7)
D9:J9D9=OFFSET(Data!$C$5,0,COUNTA(Data!$C$5:$ZZ$5)-7,1,7)
Dynamic array formulas.
Named Ranges
NameRefers ToCells
TestDateRange=OFFSET(Data!$C$4,0,COUNTA(Data!$C$4:$ZZ$4)-7,1,7)D8
TestPumpHours=OFFSET(Data!$C$5,0,COUNTA(Data!$C$5:$L$5)-7,1,7)D9
 
Upvote 0

Forum statistics

Threads
1,214,788
Messages
6,121,575
Members
449,039
Latest member
Arbind kumar

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