[AccessD] Manipulating Excel Cells

Hale, Jim Jim.Hale at FleetPride.com
Wed Feb 1 11:33:28 CST 2006


John,
You do not have to reference columns by letters in a range object. Stmts
like
.Range(.Cells(2, intCopycol), .Cells(47, intCopycol)) work and can be used
in loops.
Jim Hale

-----Original Message-----
From: John Colby [mailto:jwcolby at colbyconsulting.com]
Sent: Wednesday, February 01, 2006 11:03 AM
To: 'Access Developers discussion and problem solving'
Subject: Re: [AccessD] Manipulating Excel Cells


Gustav, Jim,

Nope, what I was looking for was

.Range(strRange).Interior.ColorIndex = rst!DS_ExcelColorIndex

In this case at least, strRange can be in the form "B23", referencing column
B, row 23.

I have a query that pulls the system column (a letter), the Document Row (a
number) and the document status color index (a number)

With my existing Excel class to open the spreadsheet, make a copy, and hand
me back a worksheet, the entire code snippet runs in ~50 seconds, coloring
11783 cells - 91 systems with 159 documents.

The code looks like:

Function TestExcelColors()
On Error GoTo Err_TestExcelColors
Dim db As DAO.Database
Dim rst As DAO.Recordset
Dim strRange As String
Dim lclsTimer As clsTimer
    Set lclsTimer = New clsTimer
    lclsTimer.StartTimer
	'
	'Get the recordset used to populate the colors in the spreadsheet
	'
    Set db = CurrentDb
    Set rst = db.OpenRecordset("qDoc2ContractorBase")
    ExcelInit
    With cExc
	'
	'Get the spreadsheet and copy it to a new location
	'
        .mXLWBOpen
"X:\BuildingCommissioning\RFD\UpdateTopMatrixReported.xls",
"X:\BuildingCommissioning\RFD\UpdateTopMatrix.xls", True
        rst.MoveFirst
        While Not rst.EOF
		'
		'Turn the column/row info into a string
		'
            strRange = rst!SYS_SpreadsheetColumn & rst!DOC_SpreadsheetRow
		'		
		'set the colorindex for that cell
		'
            .cWS.Range(strRange).Interior.ColorIndex =
rst!DS_ExcelColorIndex
            rst.MoveNext
        Wend
    End With
    Debug.Print "Time to Color Spreadsheet: " & lclsTimer.EndTimer
Exit_TestExcelColors:
Exit Function
Err_TestExcelColors:
        MsgBox Err.Description, , "Error in Function
basExcelInit.TestExcelColors"
        Resume Exit_TestExcelColors
    Resume 0    '.FOR TROUBLESHOOTING
End Function 


John W. Colby
www.ColbyConsulting.com 



***********************************************************************
The information transmitted is intended solely for the individual or
entity to which it is addressed and may contain confidential and/or
privileged material. Any review, retransmission, dissemination or
other use of or taking action in reliance upon this information by
persons or entities other than the intended recipient is prohibited.
If you have received this email in error please contact the sender and
delete the material from any computer. As a recipient of this email,
you are responsible for screening its contents and the contents of any
attachments for the presence of viruses. No liability is accepted for
any damages caused by any virus transmitted by this email.


More information about the AccessD mailing list