[AccessD] Manipulating Excel Cells

John Colby jwcolby at ColbyConsulting.com
Wed Feb 1 11:02:30 CST 2006


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 


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

Is this what you are looking for?

'flip sign on vendor rebates
    '---------------------------
     .Sheets("misc").Select
       
        For i = 6 To 11
            .Cells(25, i) = -(.Cells(25, i))
        Next i
Or something like this?
Jim Hale

Function loadData_Excel(Dept As Integer, Co As Integer, ModelName As String,
XcelWS As String, PlGroup As String, qryStr As String) Dim qdfTemp As
QueryDef, dbs As Database, rs As Recordset Dim intRow As Integer, intBmonth
As Integer, strWorksheet As String 'load data from recordset into
spreadsheet Set dbs = CurrentDb Set qdfTemp = dbs.QueryDefs(qryStr)
    qdfTemp.Parameters("Deptnum") = Dept
    qdfTemp.Parameters("Co") = Co
    qdfTemp.Parameters("Model") = ModelName
    qdfTemp.Parameters("Worksheet") = XcelWS
    qdfTemp.Parameters("PlGroup") = PlGroup
    
    Set rs = qdfTemp.OpenRecordset()
     If Not (rs.BOF And rs.EOF) Then
        strWorksheet = rs("fldWorksheet")
     appexcel.Sheets(strWorksheet).Select
   
        Do While Not rs.EOF
            intBmonth = rs("Bmonth") + rs("fldColumnoffset")
            intRow = rs("fldRowno")
           appexcel.Cells(intRow, intBmonth) = rs("amt")
            rs.MoveNext
        Loop
    End If
The_End:
    If Not (qdfTemp Is Nothing) Then qdfTemp.Close: Set qdfTemp = Nothing
    If Not (rs Is Nothing) Then rs.Close: Set rs = Nothing
    If Not (dbs Is Nothing) Then dbs.Close: Set dbs = Nothing End Function


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


I'm baaaack.  ;-)

Here's the deal.  I am working with a spreadsheet that has columns of
systems and rows of documents.  Therefore each cell represents a
system-document.  BTW, this was a "source" for me to build a pair of tables
- tblSystem and tblDocument.  I then added a field to tblDocument called
SpreadsheetRow and a field to tblSystem called SpreadsheetColumn.  


We are tracking the receipt of these documents.  The client now wants to
see, back in his original spreadsheet, the "status" of a given system
document using colors to express the status - white = not assigned, red =
not received, yellow = partial receipt, green = received.

So... I have to go "poke colors" out into the spreadsheet.  I have
discovered the "area" property which has a color attribute.  What I need now
is a translation from the column LETTERS to a column number since for some
bizarre reason the columns have letter names but cells are referenced by
column numbers.  "Brain damaged children" as Bill Cosby would say.

Does anyone have code for manipulating cells by cell(intRowNumbers,
strColNames)?

John W. Colby
www.ColbyConsulting.com 


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




More information about the AccessD mailing list