VBA fails to add data to "all" of the required cells

Anniema

New Member
Joined
Mar 20, 2024
Messages
8
Office Version
  1. 2016
Platform
  1. Windows
Per the attached image, I have a sheet which is auto filled from another. The layout has been modified - original version was C3-AC81, new version is C3-AO81. It works perfectly picking up the data in the original parameters (see image), however refuses to do so for the added columns. The relevant code is below. There are multiple macros in the workbook and I have checked through them all for references to this sheet in case there was another with the original range - however, none of the other macros were relevant in this instance. Can anyone advise what the issue may be? or indeed how I can have these additional columns picked up? Thanks.
Code in question:
Sub updatePobArr()

Dim a, b, c As Integer
Dim cll, xcll, ycll, xrng, yrng As Range
Dim el, et, xarr As Variant
Dim ccabin As String
Dim cabinarr, pobarr, d, f As Variant

'On Error GoTo ending

c = Worksheets("dB").Range("S2")

'Worksheets("CABIN LIST").Range("AG1") = Sheets(c).Range("G2")
Worksheets("CABIN LIST").Range("V1") = Sheets(c).Range("G2")

a = Worksheets("db").Range("C" & Rows.Count).End(xlUp).Row

Set xrng = Worksheets("dB").Range("C3:L" & a)
pobarr = xrng

Set yrng = Worksheets("CABIN LIST").Range("C3:AO81") - these are the parameters I changed
cabinarr = yrng
tempsnip.png
 

Excel Facts

Is there a shortcut key for strikethrough?
Ctrl+S is used for Save. Ctrl+5 is used for Strikethrough. Why Ctrl+5? When you use hashmarks to count |||| is 4, strike through to mean 5.
You need to show the rest of the code, in particular any loops using cabinarr and where it writes cabinarr back to the sheet.
 
Upvote 0
The full code for the macro(s) in question:

Sub realBusiness()
Application.ScreenUpdating = False
generalCabinsOverview
clearPOB
updatePobArr
Application.ScreenUpdating = True
End Sub

Sub updatePobArr()

Dim a, b, c As Integer
Dim cll, xcll, ycll, xrng, yrng As Range
Dim el, et, xarr As Variant
Dim ccabin As String
Dim cabinarr, pobarr, d, f As Variant



'On Error GoTo ending

c = Worksheets("dB").Range("S2")

'Worksheets("CABIN LIST").Range("AG1") = Sheets(c).Range("G2")
Worksheets("CABIN LIST").Range("V1") = Sheets(c).Range("G2")


a = Worksheets("db").Range("C" & Rows.Count).End(xlUp).Row

Set xrng = Worksheets("dB").Range("C3:L" & a)
pobarr = xrng

Set yrng = Worksheets("CABIN LIST").Range("C3:AO81")
cabinarr = yrng


For el = LBound(pobarr) To UBound(pobarr)
If pobarr(el, 10) = "x" Then
ccabin = Replace(pobarr(el, 6), "D", "") & pobarr(el, 7)

For f = 1 To 79 Step 10
For d = 1 To 27 Step 3


If cabinarr(f, d) <> "" Then
If Trim(cabinarr(f, d) & cabinarr(f + 1, d)) = Trim(ccabin) Then

''' double cabins

If pobarr(el, 9) = "D" Then
cabinarr(f + 1, d + 1) = "DAY"
ElseIf pobarr(el, 9) = "N" Then
cabinarr(f + 1, d + 1) = "NIGHT"
End If


If Application.Proper(pobarr(el, 4)) = "Vanquish" Or Application.Proper(pobarr(el, 4)) = "RAG" Or _
Application.Proper(pobarr(el, 4)) = "Slate" Or Application.Proper(pobarr(el, 4)) = "Larimar" Or Application.Proper(pobarr(el, 4)) = "Envier" Then
cabinarr(f + 2, d + 1) = pobarr(el, 5)
Else
cabinarr(f + 2, d + 1) = pobarr(el, 4)
End If

cabinarr(f + 3, d + 1) = pobarr(el, 2)
' ycll.Offset(4, 2) = Worksheets(Worksheets("dB").Range("R2")).Range("G2")

GoTo nextxcll
'Debug.Print Trim(ycll & ycll.Offset(5, 0))
'Debug.Print ccabin & xcll.Offset(0, 1)
ElseIf Trim(cabinarr(f, d) & cabinarr(f + 5, d)) = Trim(ccabin) Then

If pobarr(el, 9) = "D" Then
cabinarr(f + 5, d + 1) = "DAY"
ElseIf pobarr(el, 9) = "N" Then
cabinarr(f + 5, d + 1) = "NIGHT"
End If

If Application.Proper(pobarr(el, 4)) = "Valaris" Or Application.Proper(pobarr(el, 4)) = "Agr" Or _
Application.Proper(pobarr(el, 4)) = "Atlas" Or Application.Proper(pobarr(el, 4)) = "Drillmar" Or Application.Proper(pobarr(el, 4)) = "Entier" Then
cabinarr(f + 6, d + 1) = pobarr(el, 5)
Else
cabinarr(f + 6, d + 1) = pobarr(el, 4)
End If

cabinarr(f + 7, d + 1) = pobarr(el, 2)
' ycll.Offset(4, 2) = Worksheets(Worksheets("dB").Range("R2")).Range("G2")

GoTo nextxcll

End If

End If

Next d
Next f

End If
nextxcll:
Next el
Worksheets("CABIN LIST").Unprotect
yrng = cabinarr
Worksheets("CABIN LIST").Protect
ending:
Erase pobarr
Erase cabinarr
End Sub

Sub clearPOB()
Dim yrng, ycll As Range

On Error Resume Next

Set yrng = Union(Worksheets("CABIN LIST").Range("R3:AM3"), Worksheets("CABIN LIST").Range("C13:F13"), _
Worksheets("CABIN LIST").Range("C23:AD23"), Worksheets("CABIN LIST").Range("C33:U33"), _
Worksheets("CABIN LIST").Range("F43:U43"), Worksheets("CABIN LIST").Range("C53:AM53"), _
Worksheets("CABIN LIST").Range("C63:AM63"), Worksheets("CABIN LIST").Range("C73:AM73"))



For Each ycll In yrng
If ycll <> "" Then

ycll.Offset(1, 1) = ""
ycll.Offset(2, 1) = ""
ycll.Offset(3, 1) = ""
ycll.Offset(4, 0) = ""
ycll.Offset(4, 2) = ""
ycll.Offset(5, 1) = ""
ycll.Offset(6, 1) = ""
ycll.Offset(7, 1) = ""
ycll.Offset(8, 0) = ""
ycll.Offset(8, 2) = ""

GoTo nextycll
End If
nextycll:
Next

End Sub


Sub updatePobDep()

Dim a, b As Integer
Dim xcll, ycll, xrng, yrng As Range
Dim el, xarr As Variant
Dim ccabin As String
Dim crewarr, mdsarr, catarr, winarr, winsarr, pobarr As Variant


On Error GoTo ending

a = Worksheets("db").Range("C" & Rows.Count).End(xlUp).Row

Set xrng = Worksheets("dB").Range("C3:L" & a)
pobarr = xrng

Set yrng = Union(Worksheets("CABIN LIST").Range("S4:AN4"), Worksheets("CABIN LIST").Range("D14:G14"), _
Worksheets("CABIN LIST").Range("D24:AE24"), Worksheets("CABIN LIST").Range("D34:V34"), _
Worksheets("CABIN LIST").Range("G44:V44"), Worksheets("CABIN LIST").Range("D54:AN54"), _
Worksheets("CABIN LIST").Range("D64:AN64"), Worksheets("CABIN LIST").Range("D74:AN74"))

For el = LBound(pobarr) To UBound(pobarr)
If pobarr(el, 10) = "x" Then

ccabin = Replace(pobarr(el, 6), "D", "") & pobarr(el, 7)

For Each ycll In yrng
If ycll <> "" Then
If Trim(ycll & ycll.Offset(1, 0)) = Trim(ccabin) Then

''' double cabins

Application.EnableEvents = False

ycll.Offset(1, 1) = ""
ycll.Offset(2, 1) = ""
ycll.Offset(3, 1) = ""
ycll.Offset(4, 0) = ""
ycll.Offset(4, 2) = ""


Application.EnableEvents = True
GoTo nextxcll
' Debug.Print Trim(ycll & ycll.Offset(5, 0))
' Debug.Print ccabin & xcll.Offset(0, 1)
ElseIf Trim(ycll & ycll.Offset(5, 0)) = Trim(ccabin) Then


Application.EnableEvents = False

ycll.Offset(5, 1) = ""
ycll.Offset(6, 1) = ""
ycll.Offset(7, 1) = ""
ycll.Offset(8, 0) = ""
ycll.Offset(8, 2) = ""

Application.EnableEvents = True
GoTo nextxcll

End If

End If
Next
End If
nextxcll:
Next el
ending:
Erase pobarr
End Sub
 
Upvote 0
Given that Column AC is Column 29 and you were using a loop to 27 in this
For d = 1 To 27 Step 3

Try using either of these instead of that line. (AO being column 41)
For d = 1 To 39 Step 3
or
For d = 1 To ubound(cabinarr,2) - 2 Step 3

PS: Please use code tags when you post code it makes it much easier for us to read. The button VBA is the simplest one to use.
 
Upvote 0
Solution
Given that Column AC is Column 29 and you were using a loop to 27 in this
For d = 1 To 27 Step 3

Try using either of these instead of that line. (AO being column 41)
For d = 1 To 39 Step 3
or
For d = 1 To ubound(cabinarr,2) - 2 Step 3

PS: Please use code tags when you post code it makes it much easier for us to read. The button VBA is the simplest one to use.
Thank you so much, the first option worked. the Unbound one caused an error, but I will have a look at that later.
I realised after I had posted the whole code that I should hae used the VBA option and did look to edit, however, not enough posts under my belt to do so, so apologies for post.
 
Upvote 0

Forum statistics

Threads
1,223,887
Messages
6,175,199
Members
452,617
Latest member
Narendra Babu D

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