"variable not defined" error with "sub" highlighted

jalberthenet

New Member
Joined
Jul 6, 2015
Messages
2
Hi all,

I have a loop code as per below, which works fine in the original spreadsheet for which it was written. Although the row containing "Sub Matrix2DB()" is highlighted yellow.
BUT when copying to a new spreadsheet, with all of the sheets, columns and rows set out as required in the macro, the error message "compile error: variable not defined" is returned. Again, the row containing "Sub Matrix2DB()" is highlighted yellow. It looks like my sub needs to be declared as a variable but I don't know how to do this, how do I fix this one please ?

Option Explicit
Dim rx, cx, cxDeliverable, cxLoc, rxCode, rz, czDeliverable, czLoc, czCode, czSubtotal As Integer
Dim shx, shz As Worksheet

Sub Matrix2DB()

Set shx = Sheet7
Set shz = Sheet9

cxDeliverable = 1
cxLoc = 2
rxCode = 7
rz = 1
czDeliverable = 1
czLoc = 2
czCode = 3
czSubtotal = 4

For rx = 9 To 613
For cx = 3 To 54
If shx.Cells(rx, cx) > 0 Then
shz.Cells(rz, czDeliverable) = shx.Cells(rx, cxDeliverable)
shz.Cells(rz, czLoc) = shx.Cells(rx, cxLoc)
shz.Cells(rz, czCode) = shx.Cells(rxCode, cx)
shz.Cells(rz, czSubtotal) = shx.Cells(rx, cx)
rz = rz + 1
End If
Next cx
Next rx

End Sub
 

Excel Facts

Format cells as date
Select range and press Ctrl+Shift+3 to format cells as date. (Shift 3 is the # sign which sort of looks like a small calendar).
Welcome to the Forum!

Does you new workbook have sheets with codenames Sheet7 and Sheet9?
 
Upvote 0
MAybe this
Rich (BB code):
Option Explicit
Dim rx, cx, cxDeliverable, cxLoc, rxCode, rz, czDeliverable, czLoc, czCode, czSubtotal As Integer
Dim shx, shz As Worksheet

Sub Matrix2DB()

Set shx = Sheets("Sheet7")
Set shz = Sheets("Sheet9")

cxDeliverable = 1
cxLoc = 2
rxCode = 7
rz = 1
czDeliverable = 1
czLoc = 2
czCode = 3
czSubtotal = 4

For rx = 9 To 613
For cx = 3 To 54
If shx.Cells(rx, cx) > 0 Then
shz.Cells(rz, czDeliverable) = shx.Cells(rx, cxDeliverable)
shz.Cells(rz, czLoc) = shx.Cells(rx, cxLoc)
shz.Cells(rz, czCode) = shx.Cells(rxCode, cx)
shz.Cells(rz, czSubtotal) = shx.Cells(rx, cx)
rz = rz + 1
End If
Next cx
Next rx

End Sub
 
Upvote 0
sweet jesus it looks like that worked. thankyou stephencrump and Michael m.

I renamed the relevant sheets to "sheet 7" and "sheet 9" as suggested, saved, re-opened and re-ran the macro and she seems to be up and running.

May I ask if anyone knows why it initially suggested my "sub" needed to be declared as a variable ???
 
Upvote 0
Because you have Option Explicit (good coding practice!) execution won't proceed with an undefined variable.

So execution stops at the first line Sub Matrix2DB() which will show yellow.

However, the first offending undefined variable should also be highlighted?
 
Upvote 0
@jalberthenet, you might also want to review how you declare your variables.

As you have it currently written

rx, cx, cxDeliverable, cxLoc, rxCode, rz, czDeliverable, czLoc, czCode and shx are all declared as Variant in VBA, which I don't think is what you intended.

In VBA if you omit the As Type clause in a variable declaration then it is declared as Variant, Variant is the default type.
 
Upvote 0
Ah MARK858 has beaten me to the punch, but just to add,

The way you're declaring your variables only the last one is being declared as the type you define as an integer or worksheet. To see this run this simple code which shows the variable type (
click here for a list of variable types and their associated number) from this:

Code:
MsgBox VarType(rx)
MsgBox TypeName(czSubtotal)

rx is actually a variant variable - the most expensive type of variable. You need "As Integer" after each of the other nine variables in that row (assuming you want them all to be integers).

Regards,

Robert
 
Upvote 0

Forum statistics

Threads
1,214,942
Messages
6,122,367
Members
449,080
Latest member
Armadillos

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top