[AccessD] Manipulating Excel Cells

Charlotte Foust cfoust at infostatsystems.com
Wed Feb 1 13:14:30 CST 2006


LOL!  You must never have worked with MultiPlan, John.  It took me
forever to get used to column letters in Excel ... Especially when the
macro language still used the numeric row and column designators!

Charlotte Foust


-----Original Message-----
From: accessd-bounces at databaseadvisors.com
[mailto:accessd-bounces at databaseadvisors.com] On Behalf Of John Colby
Sent: Wednesday, February 01, 2006 10:41 AM
To: 'Access Developers discussion and problem solving'
Subject: Re: [AccessD] Manipulating Excel Cells


Jim,

When you look in a spreadsheet you do not "SEE" column numbers, you see
letters.  I have columns e through CM or something like that.  For some
odd reason Z is not used, az,bz etc.  No se por que.  

So what I was looking for (and found) was a syntax for using column
letters instead of the silly cell(31,29).  What column is 29?  What
"number" is column BA?  Why do we "see" a column letter but address the
cell with 31,22? And of course I know the answer to the last, so that
they can be manipulated with counters in code, but in this case I have a
column LETTER, not a column NUMBER.

worksheet.Range(strRange)

is the answer.  I can use a string "B3" using that syntax.

John W. Colby
www.ColbyConsulting.com 


-----Original Message-----
From: accessd-bounces at databaseadvisors.com
[mailto:accessd-bounces at databaseadvisors.com] On Behalf Of Hale, Jim
Sent: Wednesday, February 01, 2006 12:33 PM
To: 'Access Developers discussion and problem solving'
Subject: Re: [AccessD] Manipulating Excel Cells

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.
--
AccessD mailing list
AccessD at databaseadvisors.com
http://databaseadvisors.com/mailman/listinfo/accessd
Website: http://www.databaseadvisors.com

-- 
AccessD mailing list
AccessD at databaseadvisors.com
http://databaseadvisors.com/mailman/listinfo/accessd
Website: http://www.databaseadvisors.com



More information about the AccessD mailing list