Dynamic Stock Chart

N

Nick Krill

How can I create "Name" that will enable a dynamic stock chart in Excel 2003.
I have been able to create single series dynamic charts using "Name", but no
luck in creating a dynamic stock chart.
 
J

Jon Peltier

1. The hard way: Define a name for dates and one name for each series in the
chart (Open, High, Low, Close). Create the chart using static data, then
replace the static addresses with the names, either in the series formulas
or in the Source Data > Series dialog.

2. The easy way: Put Date, Open, High, Low, Close into a table. Go to Data
menu > List > Create List. Make your chart based on this list. As the list
expands, any formulas (including chart series formulas) update to include
all rows in the list.

- Jon
 
N

Nick Krill

My database of stock prices contracts as well as expands. I haven't been able
to get either method to adjust it's range to fit the number of data rows. Any
ideas?
 
J

John Mansfield

As Jon noted you can use range names to automatically expand or contract your
data set. The article below explain how:

http://office.microsoft.com/en-us/excel/HA011098011033.aspx

From the article, the series formulas to expand or contract your data set
look like this:

Date =OFFSET(Sheet1!$A$1,1,0,COUNTA($A:$A)-1)

Price =OFFSET(Sheet1!$B$1,1,0,COUNTA($B:$B)-1)

John Walkenbach also walks through the steps:

http://spreadsheetpage.com/index.php/tip/update_charts_automatically_when_you_enter_new_data/

These articles might help too:

http://pubs.logicalexpressions.com/Pub0009/LPMArticle.asp?ID=518

http://pubs.logicalexpressions.com/Pub0009/LPMArticle.asp?ID=535
 
N

Nick Krill

Those methods work well with single line charts - I've been using them for
some time now, but I haven't been able to get them to work with a stock chart?
 
J

Jon Peltier

These methods do work for stock charts and for any other charts with
multiple series. Is it a stock chart with HLC or OHLC? Put the data into a
List and plot using the list. Your descriptions don't explain what isn't
working, or how you set up the list or names.

- Jon
 
N

Nick Krill

Thanks - I'm using OHLC stock charts. Excel will only accept the range name
for the first series: Open price. When I attempt to enter the range name for
the second series (High) it says that there is an error in my formula, which
isn't true: I test that formula by using it in a single line chart and it
works just fine. Weird huh?As a workaround I created a macro that edits the
data range:

ActiveChart.SetSourceData Source:=Sheets("Data").Range("j10:M" &
DataCount), PlotBy:= _
xlColumns

Where DataCount is found as:
DataCount = DataSheet.Cells(Rows.Count, 3).End(xlUp).Row

The incoming data is variable in number of rows. I wansn't able to create a
list that contract as well as expand, so I need to get series names or data
range working.
 
N

Nick Krill

Jon Peltier said:
These methods do work for stock charts and for any other charts with
multiple series. Is it a stock chart with HLC or OHLC? Put the data into a
List and plot using the list. Your descriptions don't explain what isn't
working, or how you set up the list or names.

- Jon
-------
Jon Peltier, Microsoft Excel MVP
Peltier Technical Services, Inc.
http://PeltierTech.com/WordPress/
_______
 
J

Jon Peltier

This isn't how you define names. You don't need to use any VBA at all. Try
it this way.

Say your data starts in A1, where cell A1 itself is blank, but you have
dates from A2 downward. O, H, L, and C are in columns B through E. (If your
data is elsewhere, adjust the steps below.)

Use the Insert menu > Names > Define dialog to create the following names:

Name: TheDates
Refers To: =OFFSET(A1,1,0,COUNT(A:A),1)

Name: TheOpen
Refers To: =OFFSET(TheDates,0,1)

Name: TheHigh
Refers To: =OFFSET(TheDates,0,2)

Name: TheLow
Refers To: =OFFSET(TheDates,0,3)

Name: TheClose
Refers To: =OFFSET(TheDates,0,4)

Select the data range you currently have and make your chart. The series
formula for the Open series looks like:

=SERIES(Sheet1!$B$1,Sheet1!$A$2:$A$20,Sheet1!$B$2:$B$20,1)

Edit this so it reads:

=SERIES(Sheet1!$B$1,Sheet1!TheDates,Sheet1!TheOpen,1)

Similarly:

=SERIES(Sheet1!$B$1,Sheet1!TheDates,Sheet1!TheHigh,2)
=SERIES(Sheet1!$B$1,Sheet1!TheDates,Sheet1!TheLow,3)
=SERIES(Sheet1!$B$1,Sheet1!TheDates,Sheet1!TheClose,4)

Now if you have done this correctly, it will update whether data is added or
removed.

Actually, as I stated, creating a List is even easier, but you didn't seem
to want to try that.

- Jon
 
N

Nick Krill

Thanks Jon - Actually, way back on 1/31/09 I replied that I had tried both
methods. Method #1, the list method worked beautifully as long as the data
kept expanding, but charting would not contract to fit a smaller database
once it had been enlarged.
 
J

Jon Peltier

If the list itself contracts, which has to happen by deleting rows of the
list, not just emptying cells, the chart would contract.

- Jon
 

Ask a Question

Want to reply to this thread or ask your own question?

You'll need to choose a username for the site, which only take a couple of moments. After that, you can post your question and our members will help you out.

Ask a Question

Top