VBA reading cell value not formula

ClaireLou

New Member
Joined
Nov 14, 2020
Messages
10
Office Version
  1. 365
Platform
  1. Windows
Hi

I have the code attached, its an auto sheet event script

How do I get the vba code to read the value and not the formula? I need it to move the rows depending on the status in column A and that changes based on the values in other columns.
I’ve put the code I’m using below. It works perfectly if I actually type in the phrase I’m using.
Thanks for any help 😁
Claire

Private Sub Worksheet_Change(ByVal Target As Range)
If Not Intersect(Target, Range("A:A")) Is Nothing Then
If Target.Cells.Count > 1 Or IsEmpty(Target) Then Exit Sub
Application.ScreenUpdating = False
Dim Lastrow As Long
Dim Lastrowa As Long
Lastrow = Sheets("Sheet2").Cells(Rows.Count, "A").End(xlUp).Row + 1
Lastrowa = Sheets("Sheet3").Cells(Rows.Count, "A").End(xlUp).Row + 1
If Target.Value = "To be Booked" Then
Rows(Target.Row).Copy Destination:=Sheets("Sheet2").Rows(Lastrow)
Application.EnableEvents = False
Rows(Target.Row).Delete
Application.EnableEvents = True
Exit Sub
End If
Application.EnableEvents = True
If Target.Value = "Booked" Then
Rows(Target.Row).Copy Destination:=Sheets("Sheet3").Rows(Lastrowa)
Application.EnableEvents = False
Rows(Target.Row).Delete
End If
Application.EnableEvents = True
Application.ScreenUpdating = True
End If
End Sub
 

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
55,574
Office Version
  1. 365
Platform
  1. Windows
Ok, how about
VBA Code:
Sub ClaireLou()
   With Sheets("Sheet1")
      .Range("A1").AutoFilter 1, "To be Booked"
      .AutoFilter.Range.Offset(1).EntireRow.Copy Sheets("Sheet2").Range("A" & Rows.Count).End(xlUp).Offset(1)
      .AutoFilter.Range.Offset(1).EntireRow.Delete
      .Range("A1").AutoFilter 1, "Booked"
      .AutoFilter.Range.Offset(1).EntireRow.Copy Sheets("Sheet3").Range("A" & Rows.Count).End(xlUp).Offset(1)
      .AutoFilter.Range.Offset(1).EntireRow.Delete
      .AutoFilterMode = False
   End With
End Sub
This assumes that you have a header in row 1 & that there are no blank rows within the data.
 
Solution

Some videos you may like

Excel Facts

What does custom number format of ;;; mean?
Three semi-colons will hide the value in the cell. Although most people use white font instead.

ClaireLou

New Member
Joined
Nov 14, 2020
Messages
10
Office Version
  1. 365
Platform
  1. Windows
Ok, how about
VBA Code:
Sub ClaireLou()
   With Sheets("Sheet1")
      .Range("A1").AutoFilter 1, "To be Booked"
      .AutoFilter.Range.Offset(1).EntireRow.Copy Sheets("Sheet2").Range("A" & Rows.Count).End(xlUp).Offset(1)
      .AutoFilter.Range.Offset(1).EntireRow.Delete
      .Range("A1").AutoFilter 1, "Booked"
      .AutoFilter.Range.Offset(1).EntireRow.Copy Sheets("Sheet3").Range("A" & Rows.Count).End(xlUp).Offset(1)
      .AutoFilter.Range.Offset(1).EntireRow.Delete
      .AutoFilterMode = False
   End With
End Sub
This assumes that you have a header in row 1 & that there are no blank rows within the data.
You are amazing!! Thank you so much 😁😁
 

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
55,574
Office Version
  1. 365
Platform
  1. Windows
You're welcome & thanks for the feedback.
 

Watch MrExcel Video

Forum statistics

Threads
1,127,653
Messages
5,626,105
Members
416,161
Latest member
David1966Lewis

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
Top