Copy last column before error "N/A" in a column

RioDegenero

New Member
Joined
Mar 1, 2023
Messages
23
Office Version
  1. 365
  2. 2021
Platform
  1. Windows
  2. MacOS
Hi,

Any help will be appreciated on how to write a code to copy and past in another spreadsheet the last value before "N/A" in a column.
So in the snip below, it's the values in A5 and B8 I will like to copy and it varies every time
Thanks in advance

1677767573743.png
 

Attachments

  • 1677767514456.png
    1677767514456.png
    6.3 KB · Views: 2

Excel Facts

Can you sort left to right?
To sort left-to-right, use the Sort dialog box. Click Options. Choose "Sort left to right"
So in the snip below, it's the values in A5 and B8 I will like to copy
You do not indicate where you want to paste those values.

With the following macro you copy those values from Sheet1 to Sheet2 in column A, one value below another.

I added a condition, if #N/A does not exist then it copies the last value of that column.

VBA Code:
Sub copyvalues()
  Dim sh1 As Worksheet, sh2 As Worksheet
  Dim f As Range
  Dim i As Long
 
  Set sh1 = Sheets("Sheet1")
  Set sh2 = Sheets("Sheet2")
  For i = 1 To sh1.Cells(1, Columns.Count).End(1).Column
    Set f = sh1.Columns(i).Find("#N/A", , xlValues, xlWhole, , , False)
    If Not f Is Nothing Then
      sh2.Range("A" & Rows.Count).End(3)(2).Value = f.Offset(-1).Value
    Else
      sh2.Range("A" & Rows.Count).End(3)(2).Value = sh1.Cells(Rows.Count, i).End(3).Value
    End If
  Next
End Sub

For example:
Dante Amor
ABC
1Set 1Set 2Set 3
2254
3368
447
558
6#N/A9
7#N/A10
8#N/A11
9#N/A#N/A
10#N/A
11#N/A
12#N/A
13
Sheet1


Results:
Dante Amor
A
1Results
25
311
48
5
Sheet2
 
Upvote 0
You do not indicate where you want to paste those values.

With the following macro you copy those values from Sheet1 to Sheet2 in column A, one value below another.

I added a condition, if #N/A does not exist then it copies the last value of that column.

VBA Code:
Sub copyvalues()
  Dim sh1 As Worksheet, sh2 As Worksheet
  Dim f As Range
  Dim i As Long
 
  Set sh1 = Sheets("Sheet1")
  Set sh2 = Sheets("Sheet2")
  For i = 1 To sh1.Cells(1, Columns.Count).End(1).Column
    Set f = sh1.Columns(i).Find("#N/A", , xlValues, xlWhole, , , False)
    If Not f Is Nothing Then
      sh2.Range("A" & Rows.Count).End(3)(2).Value = f.Offset(-1).Value
    Else
      sh2.Range("A" & Rows.Count).End(3)(2).Value = sh1.Cells(Rows.Count, i).End(3).Value
    End If
  Next
End Sub

For example:
Dante Amor
ABC
1Set 1Set 2Set 3
2254
3368
447
558
6#N/A9
7#N/A10
8#N/A11
9#N/A#N/A
10#N/A
11#N/A
12#N/A
13
Sheet1


Results:
Dante Amor
A
1Results
25
311
48
5
Sheet2
Thanks for this
 
Upvote 0

Forum statistics

Threads
1,213,530
Messages
6,114,163
Members
448,554
Latest member
Gleisner2

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