Move to next row and repeat

eviehc123

New Member
Joined
Jan 21, 2019
Messages
32
Hi,

How can I edit this code to repeat the check on the next row? I would like the code to check ranges B3:B9, B12:B18, B21:B27, B30:B36, L3:L9 before closing to ensure that the user cannot close the form before editing all cells.

I should note that usually only one row will be completed at a time before closing.

Thanks!

Code:
Private Sub Workbook_BeforeClose(Cancel As Boolean)
    If ActiveSheet.Range("B3") <> "" And _
    ActiveSheet.Range("C3") = "" And _
    ActiveSheet.Range("D3") = "" And _
    ActiveSheet.Range("E3") = "" And _
    ActiveSheet.Range("F3") = "" And _
    ActiveSheet.Range("G3") = "" And _
    ActiveSheet.Range("H3") = "" Then
        Cancel = True
        MsgBox "All cells must be completed"
    Else
        ActiveWorkbook.Close SaveChanges:=True
    End If
End Sub
 

Excel Facts

Test for Multiple Conditions in IF?
Use AND(test, test, test, test) or OR(test, test, test, ...) as the logical_test argument of IF.
Hi,
try

Code:
Private Sub Workbook_BeforeClose(Cancel As Boolean)
    Dim rng As Range
    
    Set rng = Range("B3:B9,B12:B18,B21:B27,B30:B36,L3:L9")
    
    Cancel = CBool(Application.CountA(rng) <> rng.Cells.Count)
    
    If Cancel Then MsgBox "All cells must be completed", 48, "Entry Required"


End Sub

Note Range is unqualified & assumes sheet being tested is the activesheet.

Dave
 
Last edited:
Upvote 0
Hi thank you! This works on each line as I wanted. However, it wants every row in that range to be completed. If possible I want it to be able to close if the last line entered is completed.

For example if the last data entered is into cell B3 and the rest of the cells C3:H3 are completed then the workbook can close even with the other rows blank.
 
Upvote 0
I would like the code to check ranges B3:B9, B12:B18, B21:B27, B30:B36, L3:L9 before closing to ensure that the user cannot close the form before editing all cells.

Hi,
Solution was base on your post

To do what you want will require another approach.

One approach that may do what you want

Standard Module

Code:
Function IsNotComplete() As Boolean
    Dim Cell As Range, Rng As Range
    Dim Target As Range
    
    Set Target = Range("B3:B9,B12:B18,B21:B27,B30:B36,L3:L9")
    
    For Each Cell In Target.Cells
        Set Rng = Cell.Resize(, 7)


        With Application
            If .CountA(Rng) > 0 Then
                IsNotComplete = CBool(.CountA(Rng) <> Rng.Cells.Count)
            End If
        End With
        
        If IsNotComplete Then
            MsgBox "All cells must be completed", 48, "Entry Required"
            Rng.Select
            Exit Function
        End If
        Set Rng = Nothing
    Next Cell
End Function

note: the range is unqualified and assumes the sheet is the activesheet when workbook is closed.

Thisworkbook Event

Code:
Private Sub Workbook_BeforeClose(Cancel As Boolean)
    
    Cancel = IsNotComplete()
    
End Sub

Dave
 
Upvote 0
The function alone does not stop the workbook from closing. Where do I place the Before Close sub in order to stop the workbook closing based on the function?
 
Upvote 0
The function alone does not stop the workbook from closing. Where do I place the Before Close sub in order to stop the workbook closing based on the function?

I did state above the code.



Thisworkbook Event

which meant place event in the Thisworkbook code page.

The function can either go in same place or standard module

Dave
 
Upvote 0

Forum statistics

Threads
1,223,228
Messages
6,170,871
Members
452,363
Latest member
merico17

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