By using this site, you agree to our updated Privacy Policy and our Terms of Use. Manage your Cookies Settings.
434,933 Members | 1,223 Online
Bytes IT Community
+ Ask a Question
Need help? Post your question and get tips & solutions from a community of 434,933 IT Pros & Developers. It's quick & easy.

Method 'Cells' of Object' _Global' failed ACCESS to EXCEL with VBA

P: 1
hi...
i have an access application in which i need to open an existing excel sheet, find a date (already in the sheet) and populate a row (with the date cell column) with either 1 or 0

this means i have to convert the datecell.column to the alphabet equivalent before i can set a cell to be populated.

I used a function, which i have used in excel before (as seen below)

Expand|Select|Wrap|Line Numbers
  1. Function Col_Letter(lngcol) As String
  2. Dim vArr
  3. vArr = Split(Cells(1, lngcol).Address(True, False), "$")
  4. Col_Letter = vArr(0)
  5. End Function
  6.  
when called, this runs fine on first run, gives an error (Method 'Cells' of Object' _Global' failed) the second run, runs fine the third run, and gives same error the fourth run...etc

i have tried more explicit methods of referring to the cell... seeing as i am working with excel from assess, but non has worked.
i tried


Expand|Select|Wrap|Line Numbers
  1. Function Col_Letter(lngcol) As String
  2. Dim vArr
  3. With Worksheets("August2013")
  4. vArr = Split(Cells(1, lngcol).Address(True, False), "$")
  5. Col_Letter = vArr(0)
  6. End With
  7. End Function
  8.  
Expand|Select|Wrap|Line Numbers
  1. Function Col_Letter(lngcol) As String
  2. Dim vArr
  3. With Worksheets(1)
  4. vArr = Split(Cells(1, lngcol).Address(True, False), "$")
  5. Col_Letter = vArr(0)
  6. End With
  7. End Function  
Expand|Select|Wrap|Line Numbers
  1. Function Col_Letter(lngcol) As String
  2. Dim vArr
  3. With Sheets(1)
  4. vArr = Split(Cells(1, lngcol).Address(True, False), "$")
  5. Col_Letter = vArr(0)
  6. End With
  7. End Function
  8.  
Expand|Select|Wrap|Line Numbers
  1. Function Col_Letter(lngcol) As String
  2. Dim vArr
  3. vArr = Split(Sheets(1).Cells(1, lngcol).Address(True, False), "$")
  4. Col_Letter = vArr(0)
  5. End Function
  6.  
(these act in a similar way to the first issue)


Expand|Select|Wrap|Line Numbers
  1. Function Col_Letter(lngcol) As String
  2. Dim vArr
  3. Dim app As New Excel.Application
  4. app.Visible = True
  5. Dim Book As Excel.Workbook
  6. Set Book = app.Workbooks.Add("D:\...\timesheeteng.xlsm")
  7. With Book.Worksheets("August2013")
  8. vArr = Split(Cells(1, lngcol).Address(True, False), "$")
  9. Col_Letter = vArr(0)
  10. End With
  11. End Function
  12.  
(this returns an object required error)

Any idea what i doing wrong?
Feb 11 '14 #1
Share this Question
Share on Google+
4 Replies


Expert 100+
P: 634
Hi

I cannot simulate you error, as this works
Expand|Select|Wrap|Line Numbers
  1. Function Col_Letter(lngcol) As String
  2.     Dim vArr() As String
  3.     vArr = Split(Cells(1, lngcol).Address(True, False), "$")
  4.     Col_Letter = vArr(0)
  5. End Function
  6.  
  7. Sub test()
  8.     Dim i As Integer
  9.     For i = 25 To 30
  10.         MsgBox Col_Letter(i)
  11.     Next i
  12. End Sub
However, I would like to know why you need to find out what the column letter is, as you do not need to know this to write info to that coulmn when you have the index already??


MTB
Feb 11 '14 #2

zmbd
Expert Mod 5K+
P: 5,397
Expand|Select|Wrap|Line Numbers
  1. Set Book = app.Workbooks.Add("D:\...\timesheeteng.xlsm") 
Is malformed.
"\...\" should be the full path such as
"D:\username\usersubfolder1\usersubfolder2\timeshe eteng.xlsm"

Expand|Select|Wrap|Line Numbers
  1. app.Workbooks.Add
Normally, I would not use this method, change "add" to "open"

Also You should look at the following insights article on applicaition automation.


In fact I borrowed the code from there and another source for the following to transfer a query I use from time to time, you should be able to modify this to your application.

You can of course modify this for latebinding.

Expand|Select|Wrap|Line Numbers
  1. Sub zj_excel_query2sheet_2()
  2. '
  3. 'You must set a reference to the EXCEL Library for the following to work
  4. '
  5.     Dim xlApp As Excel.Application
  6.     Dim xlWB As Excel.Workbook
  7.     Dim xlWS As Excel.Worksheet
  8.     Dim acRng As Variant
  9.     Dim xlRow As Integer
  10.     Dim qry As QueryDef
  11.     Dim rst As Recordset
  12.     Set xlApp = New Excel.Application
  13.     Set xlWB = xlApp.Workbooks.Open("C:\Documents and Settings\All Users\Workbook1.xlsx")
  14.     Set xlWS = xlWB.Worksheets("BBData")
  15.  
  16.     'first empty cell in the worksheet.
  17.     ' or hardcode to example xlRow = 3 to always startin the third row...
  18.     xlRow = (xlWS.Columns("A").End(xlDown).row)
  19.  
  20.     Set qry = CurrentDb.QueryDefs("QueryA")
  21.     Set rst = qry.OpenRecordset
  22.  
  23.     Dim c As Integer
  24.     'column 1 = a
  25.     c = 1
  26.     xlRow = xlRow + 1
  27.  
  28.     Do Until rst.EOF
  29.         For Each acRng In rst.Fields
  30.             'starting in the first empty cell in the column indicated....
  31.             'index with the loop.
  32.             xlWS.Cells(xlRow, c).Formula = acRng
  33.             c = c + 1
  34.         Next acRng
  35.  
  36.         xlRow = xlRow + 1
  37.         c = 1
  38.         rst.MoveNext
  39.         If xlRow > 25 Then GoTo rq_Exit
  40.     Loop
  41.  
  42. rq_Exit:
  43.     rst.Close
  44.     Set rst = Nothing
  45.     Set xlWS = Nothing
  46.     xlWB.Close acSaveYes
  47.     Set xlWB = Nothing
  48.     xlApp.Quit
  49.     Set xlApp = Nothing
  50.     Exit Function
  51. End Sub
Feb 11 '14 #3

NeoPa
Expert Mod 15k+
P: 31,492
The code is good, but it suffers from being run from Access. See Application Automation for how and why this happens. It's basically down to the fact that each application has a set of defaults. Thus, Cells in Excel refers automatically to Excel.Application.ActiveSheet.Cells. When referring from foreign applications this must be stated explicitly.

Your last posted attempt was nearer, but assuming the code up to line #7 works as expected you still have a problem in that you have used With ... on line #7 but when you reference Cells on line #8 you do so without the ".". It should say .Cells(... instead.
Feb 13 '14 #4

ADezii
Expert 5K+
P: 8,638
Why not use the Range Object instead? The following Code will:
  1. Open an Excel Spreadsheet via Automation.
  2. Loop through every Cell in a specified Range.
  3. Check the Cell Value for a valid Date.
  4. If the Date is valid, print the Cell's Address along with the Column designator.
    Expand|Select|Wrap|Line Numbers
    1. Dim appExcel As New Excel.Application
    2. Dim wb As Excel.Workbook
    3. Dim ws As Excel.Worksheet
    4. Dim rng1 As Excel.Range
    5. Dim rng2 As Excel.Range
    6.  
    7. appExcel.Visible = False
    8.  
    9. Set wb = appExcel.Workbooks.Open("C:\Security\Test2.xlsm")
    10. Set ws = wb.Worksheets("Sheet1")
    11.  
    12. ws.Activate
    13.  
    14. Set rng1 = ws.Range("A1:CC100")
    15.  
    16. For Each rng2 In rng1
    17.   If IsDate(rng2.Value) Then
    18.     Debug.Print rng2.Address, Split(rng2.Address, "$")(1)
    19.   End If
    20. Next
    21.  
    22. appExcel.Quit
    23.  
  5. OUTPUT
    Expand|Select|Wrap|Line Numbers
    1. $D$1          D
    2. $D$2          D
    3. $D$3          D
    4. $CA$7         CA
    5. $B$12         B
    6. $AG$12        AG
    7. $AW$14        AW
    8. $H$24         H
    9. $K$28         K
    10. $U$44         U
    11. $E$48         E
    12. $AB$56        AB
    13. $BC$75        BC
    14. $O$78         O
    15. $L$90         L
    16. $T$90         T
    17. $AB$94        AB
    18. $X$100        X
    19.  
  6. The rest should be easy to figure out.
Feb 14 '14 #5

Post your reply

Sign in to post your reply or Sign up for a free account.