Return multiple data from excel sheet using vba

De Bruce

New Member
Joined
May 23, 2019
Messages
30
Good day all,
Please, I have a slight problem. I created a userform with 40 textboxes that submits its contents to sheet1. The userform generates a time stamp in a label (label2) using Format(Now(), "H:MM"). When I click the submit button upon filling the form, each filled textbox is submitted to Column 1 sheet1 alongside the time stamp in Column 2 sheet1. See code below
Dim Emptyrow As Long
Emptyrow = Worksheetfunction.CountA(Range(A:A)) + 1

Cell(Emptyrow, 1) = textbox1.Value
Cell(Emptyrow, 2) = label2.Value

Cell(Emptyrow + 1, 1) = textbox2.Value
Cell(Emptyrow + 1, 2) = label2.Value

Cell(Emptyrow + 2, 1) = textbox3.Value
Cell(Emptyrow + 2, 2) = label2.Value

Cell(Emptyrow + 3, 1) = textbox4.Value
Cell(Emptyrow + 3, 2) = label2.Value

Cell(Emptyrow + 4, 1) = textbox5.Value
Cell(Emptyrow + 4, 2) = label2.Value
.
.
.
.
Cell(Empty row + 39, 1) = textbox40.Value
Cell(Empty row + 39, 2) = label2.Value

All filled textboxes submitted at an instance will have the same time stamp in Column 2.
Please, I want a situation where I can recall all contents submitted to sheet1 back to the textboxes using the time stamp as my filter.
I would like to achieve this by placing a recall textbox at the top of the userform and then filling the desired time stamp as my search criteria to recall contents from Column 1 sheet1.
I know this is possible, but I don't know how to go about it. Thanks in advance.
 

Excel Facts

Back into an answer in Excel
Use Data, What-If Analysis, Goal Seek to find the correct input cell value to reach a desired result
Here is how I would write your original code
Code:
Private Sub CommandButton1_Click()
'Modified  8/5/2019  11:06:57 AM  EDT
Dim i As Long
Dim Lastrow As Long
Lastrow = Cells(Rows.Count, "A").End(xlUp).Row
    For i = 1 To 40
        Cells(Lastrow + i, 1).Value = Controls("TextBox" & i).Value
        Cells(Lastrow + i, 2).Value = Label2.Caption
    Next
End Sub
[LEFT][COLOR=#222222][FONT=Verdana]
[/FONT][/COLOR][/LEFT]
And here is how I would write the new code you want to reload values back into UserForm Text Boxes

Assuming you have a Text Box named Recall

Code:
Private Sub CommandButton3_Click()
'Recall
Dim x As Long
x = 1
Dim i As Long
Dim Lastrow As Long
Lastrow = Cells(Rows.Count, "B").End(xlUp).Row
For i = 1 To Lastrow
    If Cells(i, 2).Text = Recall.Text Then
        Me.Controls("TextBox" & x).Value = Cells(i, 1).Value
        x = x + 1
    End If
    Next
    
End Sub
 
Upvote 0
Here is how I would write your original code
Code:
Private Sub CommandButton1_Click()
'Modified  8/5/2019  11:06:57 AM  EDT
Dim i As Long
Dim Lastrow As Long
Lastrow = Cells(Rows.Count, "A").End(xlUp).Row
    For i = 1 To 40
        Cells(Lastrow + i, 1).Value = Controls("TextBox" & i).Value
        Cells(Lastrow + i, 2).Value = Label2.Caption
    Next
End Sub
[LEFT][COLOR=#222222][FONT=Verdana]
[/FONT][/COLOR][/LEFT]
And here is how I would write the new code you want to reload values back into UserForm Text Boxes

Assuming you have a Text Box named Recall

Code:
Private Sub CommandButton3_Click()
'Recall
Dim x As Long
x = 1
Dim i As Long
Dim Lastrow As Long
Lastrow = Cells(Rows.Count, "B").End(xlUp).Row
For i = 1 To Lastrow
    If Cells(i, 2).Text = Recall.Text Then
        Me.Controls("TextBox" & x).Value = Cells(i, 1).Value
        x = x + 1
    End If
    Next
    
End Sub

Thanks alot, I tried yours and it worked. You're a genius bro. Thanks once again
 
Upvote 0

Forum statistics

Threads
1,223,703
Messages
6,173,977
Members
452,540
Latest member
haasro02

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