Take ListBox Data and put it on spreadsheet

marksc92

New Member
Joined
Sep 4, 2014
Messages
10
I have a UserFrom with a ListBox that allows users to custom rearrange the order of items in the list box. I would then like for the items in the ListBox to be dumped into a specified location on a spreadsheet when the user presses a button in the UserForm. The line items in the list box are populated whenever they open it and the number of items in the list box is variable, so the output list size can also vary.


Before:

29ZIyd.png


After:

sRsChI.png



Ideal Result:

ZiYZ06.png
 

Excel Facts

Create a chart in one keystroke
Select the data and press Alt+F1 to insert a default chart. You can change the default chart to any chart type
My understanding is that you'd like to transfer the items from your ListBox to your worksheet. If this is correct, assuming that you'd like to transfer the items to Column B, starting at B2, in Sheet1, try...

Code:
[COLOR=darkblue]Private[/COLOR] [COLOR=darkblue]Sub[/COLOR] CommandButton1_Click()

    [COLOR=darkblue]Dim[/COLOR] LastRow [COLOR=darkblue]As[/COLOR] [COLOR=darkblue]Long[/COLOR]
    
    [COLOR=darkblue]With[/COLOR] Worksheets("Sheet1")
        LastRow = .Cells(.Rows.Count, "B").End(xlUp).Row
        [COLOR=darkblue]If[/COLOR] LastRow > 1 [COLOR=darkblue]Then[/COLOR]
            .Range("B2:B" & LastRow).ClearContents
        [COLOR=darkblue]End[/COLOR] [COLOR=darkblue]If[/COLOR]
    [COLOR=darkblue]End[/COLOR] [COLOR=darkblue]With[/COLOR]
    
    [COLOR=darkblue]With[/COLOR] Me.ListBox1
        Worksheets("Sheet1").Range("B2").Resize(.ListCount).Value = .List
    [COLOR=darkblue]End[/COLOR] [COLOR=darkblue]With[/COLOR]
    
[COLOR=darkblue]End[/COLOR] [COLOR=darkblue]Sub[/COLOR]

Change the references, accordingly.

Hope this helps!
 
Upvote 0
Besides the code provided by Domenic, if you also need a code to rearrange the items i suggest that you use a SpinButton control instead of two buttons,

Something like this
(adapted from Daily Dose of Excel » Blog Archive » Move Up/Move Down in a ListBox)

Code:
Private Sub SpinButton1_SpinDown()
     
     With Me.ListBox1
        If .ListIndex < .ListCount - 1 Then
            MoveItem 1
            .ListIndex = .ListIndex + 1
        Else
            Beep
        End If
    End With
End Sub

Private Sub SpinButton1_SpinUp()
    
    With Me.ListBox1
        If .ListIndex > 0 Then
            MoveItem -1
            .ListIndex = .ListIndex - 1
        Else
            Beep
        End If
    End With
End Sub

Private Sub MoveItem(lOffset As Long)
    Dim aTemp() As String, i As Long
    
    With Me.ListBox1
        If .ListIndex > -1 Then
            ReDim aTemp(0 To .ColumnCount - 1)
            For i = 0 To .ColumnCount - 1
                 aTemp(i) = .List(.ListIndex + lOffset, i)
                .List(.ListIndex + lOffset, i) = .List(.ListIndex, i)
                .List(.ListIndex, i) = aTemp(i)
            Next i
        End If
    End With
End Sub

Hope this helps

M.
 
Last edited:
Upvote 0

Forum statistics

Threads
1,214,523
Messages
6,120,028
Members
448,940
Latest member
mdusw

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