Message box popup using if statement after sending ActiveX control entries to a different worksheet

mb123

New Member
Joined
Aug 30, 2021
Messages
5
Office Version
  1. 365
Platform
  1. Windows
I have a spreadsheet where the first sheet is a form using ActiveX controls (ComboBox, TextBox, and CommandButton). The ComboBox is a part number and the TextBox is a quantity. Once these are filled and the CommandButton is pressed, the information is sent to a master sheet with all entries (ComboBox entry sent to A, TextBox sent to B).

When the CommandButton is pressed and the information is sent to the master sheet, I would like the quantity entered to be compared to a value in D1. If the quantity entered is less than D1 I would like a message box to pop up on the first sheet saying "Quantity too low." If the quantity entered is greater than or equal to D1 then there will be no message box. The person entering the information should never see the master sheet, only the first sheet with the form.

Please let me know if anyone has a solution or if more information is needed.

Thank you!
 

Excel Facts

Round to nearest half hour?
Use =MROUND(A2,"0:30") to round to nearest half hour. Use =CEILING(A2,"0:30") to round to next half hour.
Guessing you mean BEFORE sending ActiveX control entries to a different worksheet,
and guessing the D1 you refer to is on the same sheet as the Command Button,
and guessing the values are to be written to the next blank row on the Master sheet,
you could try something along the lines of this
VBA Code:
Private Sub CommandButton1_Click()
    Dim lr As Long
    
If CLng(ActiveSheet.TextBox1.Value) < ActiveSheet.Range("d1").Value Then
    MsgBox "Quantity too low."
    Exit Sub
End If

With Sheets("Master")
    lr = .Range("A" & .Rows.Count).End(xlUp).Row
    .Range("A" & lr + 1) = ActiveSheet.ComboBox1.Value
    .Range("B" & lr + 1) = CLng(ActiveSheet.TextBox1.Value)
End With

End Sub
 
Upvote 0
Thanks for the reply. I see what you have there and it is good. I should have explained better and I left some information out.

In the master sheet the quantity entered actually gets calculated into earned hours. So 5 at .5 hours a unit earns 2.5 hours. I need to compare the earned hours to the expected earned hours which is a set 7.5 hours. This is located in the master sheet. So once the earned hours are calculated I need a message box if they have not met the earned hour goal.
 
Upvote 0
Perhaps
VBA Code:
Private Sub CommandButton1_Click()
    Dim lr As Long
    Dim earnedhrs As Single
    Dim expectedhrs As Single

With Sheets("Master")
    lr = .Range("A" & .Rows.Count).End(xlUp).Row
    .Range("A" & lr + 1) = ActiveSheet.ComboBox1.Value
    .Range("B" & lr + 1) = CSng(ActiveSheet.TextBox1.Value)
    expectedhrs = .Range("D1").Value
    earnedhrs = .Range("B" & lr + 1).Value * 0.5
End With

If earnedhrs < expectedhrs Then
    MsgBox "Quantity too low."
End If

End Sub
 
Upvote 0
Solution

Forum statistics

Threads
1,223,880
Messages
6,175,152
Members
452,615
Latest member
bogeys2birdies

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