Home > Skills > Data Entry > Scroll Bar
Select Date With Excel Scroll
Use a scroll bar to change the end date for a summary report. Quickly scroll through data, without using any macros

|
Introduction
In Excel, you can add a Scroll Bar, and use it to change the values
in worksheet cells. In this example, the Scroll Bar will change the
end date in a summary report, so you can scroll through the months,
and see the data change.
This technique does not require any programming. 

Set up the Workbook
In this example, there is a data table, with sales order information.

A pivot table is on a separate worksheet, and is based on the sales
order table. The order month is in the row area, region is in the
column area, and quantity is in the values area. 

Create a List of Dates
On a separate worksheet, named AdminDates, you'll set
up a list of dates, and named cells to calculate which date has been
selected in the scroll bar.
In this example, we want to be able to scroll to any
date in the past 12 months, so you'll use formulas to create a list
of 12 month end dates:
- In column E, enter the numbers 1 to 12, in descending order.
- In cell F2, enter the following formula, to calculate the last
date in the current month:
=DATE(YEAR(TODAY()),MONTH(TODAY())+1,1)-1
- In cell F3, enter the following formula, to calculate the last
date in the previous month
=DATE(YEAR(F2),MONTH(F2),1)-1
- Select cell F3, and copy its formula down to cell F13, to create
a list of 12 month end dates.

Create the Date Cells
The scroll bar will be linked to a cell, so you'll name a cell on
the AdminDates worksheet.
- On the AdminDates worksheet, in cells B2:C3, enter labels for
the scroll bar date cells, and put borders around cells C2:C3.

- Select cell C2, and name
it as ScrollBarSel.
- Name cell C3 as DateSel

- Type the number 12 in cell C2 -- later, the Scroll Bar will automatically
put a number in this cell
- In cell C3, enter the following INDEX
/ MATCH formula, to pull the selected date from the list of
dates. This will find the selected number in column E, and return
the date from that row.
=INDEX(F2:F13,MATCH(ScrollBarSel,E2:E13,0))
- Format cell C3 as a date, so you can check that the correct date
is showing

Set Up the Summary Sheet
On another sheet, named Summary, set up a table where you can show
three months of data, and a total.
- You'll add formulas in the next step, and for now, just type dates
in the heading row, and put fake numbers in the value cells.
- Add SUM formulas in the Total column and Total row, to calculate
the monthly totals and region totals.
TIP: After you enter the fake numbers, select cells C6:F8,
and click the AutoSum command on the Ribbon, to automatically create
the SUM formulas. 

Add Formulas to the Table Headings
You can add formulas to the summary table headings, so they show
the selected date range.
- On the Summary sheet, in cell E5, type a formula to link to the
selected date cell:
=DateSel
- In cell C5, type a formula to calculate the previous month's end
date, and copy across to cell D5:
=DATE(YEAR(D5),MONTH(D5),1)-1

Add Formulas to the Value Cells
Next, you'll add formulas to the value cells in the summary table,
to pull data from the pivot table..
- Select cell C6 in the summary table, and type an equal sign.
- Switch to the pivot table sheet, and click on the first quantity
for the East region. A GETPIVOTDATA formula will be automatically
created. (If not, change your pivot table settings, to allow
Generate GetPivotData.)

- Press Enter, to complete the GETPIVOTDATA formula. I've added
line breaks in this example, to make the formula easier to read.
The formula refers to a specific date and region, and you'll change
those to cell references.

- In the formula, select "East", including the quote marks,
and click on cell B6, where the East label is. Add a $ in front
of the B, to make the column an absolute reference -- $B6.

- Next, change the DATE formula within the GETPIVOTDATA formula,
so it refers to the date heading in cell C5. For this reference,
use an absolute reference to the row, and a relative reference to
the column -- C$5
DATE(YEAR(C$5),MONTH(C$5),DAY(C$5))

- Next, wrap the GETPIVOTDATA formula with an ERRORIF formula, and
return a 0 if there is an error. Here is the final formula.
=IFERROR(GETPIVOTDATA("Quantity",'Region Pivot'!$B$3, "OrderMth",DATE(YEAR(C$5),MONTH(C$5),DAY(C$5)),
"Region",$B6),0)
- Finally, copy the formula across to column E, and down to row
7, to complete the table.

- The table will show the correct quantity for each month and region.

Add the Scroll Bar
Next, follow these steps to add the scroll bar, and link it to the
date cell:
- On the Ribbon's Developer tab, click Insert, and under Form Controls,
click Scroll Bar

- On the Summary sheet, above the date headings, draw a scroll bar.
- Right-click on the scroll bar, and click Format Control
- In the Format Control window, on the Control tab, change the settings
so the values are:
- Current Value: 1
- Minimum Value: 1
- Maximum Value: 12
- Incremental Change: 1
- Page Change: 3
- Cell Link: ScrollBarSel
- Click OK, to complete the settings


Use the Scroll Bar
Before you can test the Scroll bar, click on the worksheet, to unselect
the Scroll bar.
Then, to use the Scroll Bar:
- click the arrow at either end of the Scroll Bar, to go up or down
1 month
- drag the scroll box, to move quickly through the months
- click in the Scroll Bar, to go up or down a page (3 months)


Add a Dynamic Chart and Title
To enhance the report, you can add a chart, based on the three months
of data. This video shows how to create the chart, and how to add
a worksheet title that shows the selected date range.
The chart title is linked to the worksheet title cell, so it also
updates when the date range is changed. The formula in the heading
cell uses the TEXT
function to format the dates::
="Sales Summary - " & TEXT(C5,"mmm-yy") & " to " &TEXT(E5,"mmm-yy")
Get the Sample File
To download the zipped sample file, in xlsx format, click
here: Scroll Bar Date
Selector
There are no macros in the file. 
More Tutorials
INDEX
/ MATCH formula
TEXT
function
GetPivotData