[AccessD] Export to Excel via VBA, Naming Cells

Gustav Brock Gustav at cactus.dk
Fri Mar 17 11:04:54 CST 2006


Hi Larry

Yes, a 'dynamic named range' is every bit as much a 'named range' as a static one; the only difference is that instead of the Refers To formula looking like:

    =Sheet1!$A$1:$D$100

it looks more like:

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

or some other formula whose result is a range.
However, you cannot link to a dynamic range as a table in Access as Excel needs to be open to get the coordinates of the range.
But via code you can do that calculation in many other ways and then create a static named range.

/gustav


>>> lmrazek at lcm-res.com 17-03-2006 17:37:27 >>>
Hi: 

I'm working on a fairly complex routine that exports sales data from Access
into Excel. 

Basically, the Excel report will have multiple worksheets, each containing a
salesman's summary sales data (about 15-20 salesmen), plus one worksheet
with company totals. 

The client wants all calculations to happen in Excel, and since I can't
predict where the data will end up in Excel, I can't really hard code any
formulas that refer to the sales data. 

I haven't had any trouble creating the worksheets/exporting the raw data via
a VBA routine, but I'm stuck on the calculation front.

Can I dynamically name cells/ranges as build the Excel report? I I'd like to
be able to use named ranges for these calculations, as I'll need to refer to
them to build my totals, but have been having a bit of trouble getting them
to work. 

I'd like to be able to assign the names as I build the spreadsheet, but I'm
not quite "getting" the syntax of the naming convention or something.

I've added a sample below:

                While Not rsSales.EOF
                    xlWs.Cells(rownum, 1) = rsSales.Fields("SalesRP")
                    xlWs.Cells(rownum, 2) = rsSales.Fields("salesrepName")
                    xlWs.Cells(rownum, 3) = rsSales.Fields("ProductGroup")
                    xlWs.Cells(rownum, 4) = rsSales.Fields("Item")
                    xlWs.Cells(rownum, 5) =
rsSales.Fields("itemdescription")
                    xlWs.Cells(rownum, 6) = rsSales.Fields("month")
                    RangeName = rsSales.Fields("SalesRP") &
rsSales.Fields("item") & rsSales.Fields("month")
                    CellLocation = rownum & 6 & ":" & rownum & 6
' Just testing to see if I can get the naming working.                   
xlWb.Names.Add Name:=RangeName, RefersTo:=CellLocation, Visible:=True    '
"=" & "!$" & rownum & "$" & 6 & ":" & rownum & "$" & 6
                    xlWs.Cells(rownum, 7) = rsSales.Fields("KGsLastYr")
                    xlWs.Cells(rownum, 8) = rsSales.Fields("KgsCurrYr")
                    xlWs.Cells(rownum, 9) = rsSales.Fields("SalesCurrYr")
                    xlWs.Cells(rownum, 10) = rsSales.Fields("SalesLastYr")
                    xlWs.Cells(rownum, 11) = rsSales.Fields("marginCurrYr")
                    xlWs.Cells(rownum, 12) = rsSales.Fields("MarginLastYr")
                    rownum = rownum + 1
                    rsSales.MoveNext
                Wend

Any suggestions? Also, if anyone specializes in this sort of thing (Access to Excel automation), I might need to farm this out. 

Thanks in advance. 

Larry Mrazek
LCM Research, Inc.
www.lcm-res.com 
lmrazek at lcm-res.com 
ph. 314-432-5886
fx. 314-432-3304





More information about the AccessD mailing list