Upon selection of item in table row, need msg box to appear and have resulting number entered in table

dpaton05

Well-known Member
Joined
Aug 14, 2018
Messages
2,352
Office Version
  1. 365
  2. 2016
Platform
  1. Windows
I have a table called npss_quote. The header row is A10:M10 with the data starting in row 11. Column B for each row in the table has a data validation list referring to a list of 7 items. Upon the selection of one of the items, Activities, I want a pop up msg box to appear. This allows you to enter a figure and when you press ok, it puts the figure into column M of the table row. Can someone help me with the vba code please?
 

Excel Facts

Last used cell?
Press Ctrl+End to move to what Excel thinks is the last used cell.
This is sheet code for a change event. Right-click the sheet tab, choose "View Code" and paste the code below into the VBE window that opens.
Rich (BB code):
Private Sub Worksheet_Change(ByVal Target As Range)
Dim LO As ListObject, c As Range, x As Variant, Prompt As String
Set LO = Me.ListObjects("npss_quote")
If Not Intersect(Target, LO.Range.Columns(2)) Is Nothing Then
    Application.EnableEvents = False
    For Each c In Intersect(Target, LO.Range.Columns(2))
        If c.Value = "Activities" Then
            Prompt = "Enter a figure for cell: " & c.Offset(0, 11).Address
            x = Application.InputBox(Prompt, Type:=1)
            If x = False Then
                Application.EnableEvents = True
                Exit Sub
            Else
                c.Offset(0, 11).Value = x
            End If
        End If
    Next c
End If
Application.EnableEvents = True
End Sub
 
Upvote 0
Thanks Joe, I already had this code that someone helped me with and I forgot that I already had the code. It adds a new column on to the end instead of putting the activity cost into the column called Activities. Can you help me change the code please so when you press ok on the message box, it puts the figure in the activity column for the current row in the table please?
 
Upvote 0
Sorry, I forgot to include the code:

Code:
Private Sub Worksheet_Change(ByVal Target As Range)
'ActiveSheet.Unprotect
  Dim ans As String
  'I suggest this go to the start before turning off the events.
  If Target.Count > 1 Or IsEmpty(Target) Then Exit Sub
  '
  On Error GoTo App_Events
  If Not Intersect(Target, Range("A:A,B:B")) Is Nothing Then
    Application.EnableEvents = False
    Select Case Target.Column
      Case 1
        If Target.Value < Date Then
          If MsgBox("This input is older than today !....Are you sure that is what you want ???", vbYesNo) = vbNo Then
            Target.Value = ""
          End If
        End If
      Case 2
        If LCase(Target.Value) = LCase("Activities") Then
          Do
            ans = InputBox("Please enter the Activities cost." & _
              vbCrLf & "************************************" & vbCrLf & _
              "To change an activity cost, select Activities from the Service list again.")
            If ans <> "" Then
              Cells(Target.Row, "N") = ans
              Exit Do
            Else
              MsgBox ("You must enter a Activities cost.")
            End If
          Loop
        End If
    End Select
  End If
App_Events:
  Application.EnableEvents = True
  'ActiveSheet.Protect
End Sub
 
Upvote 0
Hi Dave
Doesn't this part do that ??

Code:
If ans <> "" Then
   Cells(Target.Row, "N") = ans
   Exit Do
End If
 
Upvote 0

Forum statistics

Threads
1,213,546
Messages
6,114,253
Members
448,556
Latest member
peterhess2002

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