Make mandatory depending on other column value

inokam

New Member
Joined
Apr 9, 2018
Messages
12
Hi,
In my excel sheet there are 10 columns. If column "E" cell values are equal to "contract" or "permanent", I need to make column "F" and "G" respective raw values are mandatory.

Ex: If E5 value is equal to "contract", I should enter "F5" and "G5" values.

Highly appreciate , if you can provide a VBA code for this functionality.
 

Excel Facts

Format cells as currency
Select range and press Ctrl+Shift+4 to format cells as currency. (Shift 4 is the $ sign).
Copy and paste this macro into the worksheet code module. Do the following: right click the tab name for your sheet and click 'View Code'. Paste the macro into the empty code window that opens up. Close the code window to return to your sheet. Enter a value in column E and press the RETURN key.
Code:
Private Sub Worksheet_Change(ByVal Target As Range)
    If Intersect(Target, Range("E:E")) Is Nothing Then Exit Sub
    Dim val As String, rng As Range
    Select Case Target.Value
        Case "contract"
            For Each rng In Range("F" & Target.Row & ":G" & Target.Row)
                If rng = "" Then
                    Do
                        val = InputBox("Please enter a value for cell " & rng.Address(0, 0))
                        If val <> "" Then
                            rng = val
                            Exit Do
                        ElseIf val = "" Then
                            MsgBox "You must enter a value for cell " & rng.Address(0, 0), vbOKOnly
                        End If
                    Loop
                End If
            Next rng
    End Select
End Sub
 
Last edited:
Upvote 0
Thank you so much mumps,
Without prompting message box at each time, is there any other way to make this columns as mandatory based on "E"column value.
Because, in the practical scenario we have more than 1000 rows. Then, it is more difficult to add into the message box. can it allow to add into the respective cell.
 
Upvote 0
The only way that I can think of to ensure that columns F and G are mandatory is to use the macro I suggested in Post #2 . I understand that a message pops up each time, but you simply enter the value in the pop up instead of directly into the cell. The macro below is an alternative and a message pops up only if a value is entered in column F or column G without "contract" having been entered in column E. I've tried to take every possibility into account, however, columns F and G can still be left blank if a user presses the RETURN key without entering a value in F or G. Assuming that the file has to be saved or printed at some point, another alternative would be to not allow the file to be saved or printed unless all the cells in columns F and G are populated for every cell that contains "contract" in column E. By the way, do you also want the same to happen if "permanent" is entered in column E?
Code:
Private Sub Worksheet_Change(ByVal Target As Range)
    If Intersect(Target, Range("E:E,F:F,G:G")) Is Nothing Then Exit Sub
    Application.EnableEvents = False
    Select Case Target.Column
        Case Is = 5
            If Target = "contract" Then
                If Target.Offset(0, 1) = "" Then
                    Target.Offset(0, 1).Select
                ElseIf Target.Offset(0, 2) = "" Then
                    Target.Offset(0, 2).Select
                End If
            End If
        Case Is = 6
            If Target.Offset(0, -1) = "contract" Then
                If Target.Offset(0, 1) = "" Then
                    Target.Offset(0, 1).Select
                End If
            Else
                MsgBox ("Cell " & Target.Offset(0, -1).Address(0, 0) & " does not contain 'contract'.")
                Target.ClearContents
                Target.Offset(0, -1).Select
                Application.EnableEvents = True
                Exit Sub
            End If
        Case Is = 7
            If Target.Offset(0, -2) = "contract" Then
                If Target.Offset(0, -1) = "" Then
                    Target.ClearContents
                    Target.Offset(0, -1).Select
                End If
            Else
                MsgBox ("Cell " & Target.Offset(0, -2).Address(0, 0) & " does not contain 'contract'.")
                Target.ClearContents
                Target.Offset(0, -2).Select
                Application.EnableEvents = True
                Exit Sub
            End If
    End Select
    Application.EnableEvents = True
End Sub
 
Upvote 0

Forum statistics

Threads
1,223,893
Messages
6,175,241
Members
452,622
Latest member
Laura_PinksBTHFT

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