How to Copy and paste selected row from a listbox to a sheet

hilfesucher

New Member
Joined
Dec 27, 2015
Messages
3
Hi all,

I have a listbox in a userform with several columns.
I’m trying to set up a code for transfer button, which allow me to copy the selected rows in a listbox and to past them in the excel sheet.
With the following code I can transfer all the rows in listbox, but I want to transfer only the selected rows. For example I highlight the first rows and click the transfer button to copy the rows in the excel sheet "results" and then the second row etc..

Any help will be grateful

Thank you in advance

Code:
Private Sub TransferButton_Click()
    Dim ws As Worksheet
    Set ws = Sheets("Results")
  Dim nextAvailableRow As Long
    Dim i As Long
    For i = 0 To ListBox1.ListCount - 1
        nextAvailableRow = ws.Range("A" & Rows.Count).End(xlUp).Row + 1
        ws.Range("A" & nextAvailableRow) = ListBox1.Column(0, i)
        ws.Range("B" & nextAvailableRow) = ListBox1.Column(1, i)
        ws.Range("C" & nextAvailableRow) = ListBox1.Column(2, i)
        ws.Range("D" & nextAvailableRow) = ListBox1.Column(3, i)
        ws.Range("E" & nextAvailableRow) = ListBox1.Column(4, i)
        ws.Range("F" & nextAvailableRow) = ListBox1.Column(5, i)
        ws.Range("G" & nextAvailableRow) = ListBox1.Column(6, i)
        ws.Range("H" & nextAvailableRow) = ListBox1.Column(7, i)
        ws.Range("I" & nextAvailableRow) = ListBox1.Column(8, i)
        ws.Range("J" & nextAvailableRow) = ListBox1.Column(9, i)
        ws.Range("K" & nextAvailableRow) = ListBox1.Column(10, i)
        ws.Range("L" & nextAvailableRow) = ListBox1.Column(11, i)
        ws.Range("M" & nextAvailableRow) = ListBox1.Column(12, i)
        ws.Range("N" & nextAvailableRow) = ListBox1.Column(13, i)
        ws.Range("O" & nextAvailableRow) = ListBox1.Column(14, i)
        ws.Range("P" & nextAvailableRow) = ListBox1.Column(15, i)
        ws.Range("Q" & nextAvailableRow) = ListBox1.Column(16, i)
        ws.Range("R" & nextAvailableRow) = ListBox1.Column(17, i)
        ws.Range("S" & nextAvailableRow) = ListBox1.Column(18, i)
         ws.Range("T" & nextAvailableRow) = ListBox1.Column(19, i)
         ' ws.Range("U" & nextAvailableRow) = ListBox1.Column(20, i)
'           ws.Range("V" & nextAvailableRow) = ListBox1.Column(21, i)
           ' ws.Range("W" & nextAvailableRow) = ListBox1.Column(22, i)
    Next i
 
End Sub
 

Excel Facts

Which came first: VisiCalc or Lotus 1-2-3?
Dan Bricklin and Bob Frankston debuted VisiCalc in 1979 as a Visible Calculator. Lotus 1-2-3 debuted in the early 1980's, from Mitch Kapor.
Hi,

You can use the Selected property of the ListBox object to check whether a row has been selected. Here's an approach that first transfers the selected rows to an array, and then transfers the contents of the array back to the worksheet.

Code:
[COLOR=darkblue]Private[/COLOR] [COLOR=darkblue]Sub[/COLOR] TransferButton_Click()
    [COLOR=darkblue]Dim[/COLOR] wksDest [COLOR=darkblue]As[/COLOR] Worksheet
    [COLOR=darkblue]Dim[/COLOR] aData() [COLOR=darkblue]As[/COLOR] [COLOR=darkblue]Variant[/COLOR]
    [COLOR=darkblue]Dim[/COLOR] NextRow [COLOR=darkblue]As[/COLOR] [COLOR=darkblue]Long[/COLOR]
    [COLOR=darkblue]Dim[/COLOR] r [COLOR=darkblue]As[/COLOR] [COLOR=darkblue]Long[/COLOR]
    [COLOR=darkblue]Dim[/COLOR] c [COLOR=darkblue]As[/COLOR] [COLOR=darkblue]Long[/COLOR]
    [COLOR=darkblue]Dim[/COLOR] i [COLOR=darkblue]As[/COLOR] [COLOR=darkblue]Long[/COLOR]
    [COLOR=darkblue]Set[/COLOR] wksDest = Sheets("Results")
    [COLOR=darkblue]With[/COLOR] Me.ListBox1
        [COLOR=darkblue]ReDim[/COLOR] aData(1 [COLOR=darkblue]To[/COLOR] .ColumnCount, 1 [COLOR=darkblue]To[/COLOR] .ListCount)
        i = 0
        [COLOR=darkblue]For[/COLOR] r = 0 [COLOR=darkblue]To[/COLOR] .ListCount - 1
            [COLOR=darkblue]If[/COLOR] .Selected(r) [COLOR=darkblue]Then[/COLOR]
                i = i + 1
                [COLOR=darkblue]For[/COLOR] c = 0 [COLOR=darkblue]To[/COLOR] .ColumnCount - 1
                    aData(c + 1, i) = .Column(c, r)
                [COLOR=darkblue]Next[/COLOR] c
            [COLOR=darkblue]End[/COLOR] [COLOR=darkblue]If[/COLOR]
        [COLOR=darkblue]Next[/COLOR] r
    [COLOR=darkblue]End[/COLOR] [COLOR=darkblue]With[/COLOR]
    [COLOR=darkblue]If[/COLOR] i = 0 [COLOR=darkblue]Then[/COLOR]
        MsgBox "No items were selected.", vbInformation
        [COLOR=darkblue]Exit[/COLOR] [COLOR=darkblue]Sub[/COLOR]
    [COLOR=darkblue]End[/COLOR] [COLOR=darkblue]If[/COLOR]
    [COLOR=darkblue]ReDim[/COLOR] [COLOR=darkblue]Preserve[/COLOR] aData(1 [COLOR=darkblue]To[/COLOR] [COLOR=darkblue]UBound[/COLOR](aData, 1), 1 [COLOR=darkblue]To[/COLOR] i)
    [COLOR=darkblue]With[/COLOR] wksDest
        NextRow = .Cells(.Rows.Count, "A").End(xlUp).Row + 1
        .Cells(NextRow, "A").Resize(UBound(aData, 2), UBound(aData, 1)).Value = Application.Transpose(aData)
    [COLOR=darkblue]End[/COLOR] [COLOR=darkblue]With[/COLOR]
[COLOR=darkblue]End[/COLOR] [COLOR=darkblue]Sub[/COLOR]

Hope this helps!
 
Upvote 0
Hi Domenic,
I thank you for the quick reply.
I used the code and it works very nice,but when I click the button I get only the first 10 column , I have usually 17 column in Listbox.
How can I get all the columns?
thanks
 
Upvote 0
The number of columns you'll get is based on the ColumnCount property. Is your ColumnCount property set to 10? And, if so, you want to get all 17 columns? If so, replace each instance of

Code:
.ColumnCount

with

Code:
17
 
Upvote 0
Hi,

You can use the Selected property of the ListBox object to check whether a row has been selected. Here's an approach that first transfers the selected rows to an array, and then transfers the contents of the array back to the worksheet.

Code:
[COLOR=darkblue]Private[/COLOR] [COLOR=darkblue]Sub[/COLOR] TransferButton_Click()
    [COLOR=darkblue]Dim[/COLOR] wksDest [COLOR=darkblue]As[/COLOR] Worksheet
    [COLOR=darkblue]Dim[/COLOR] aData() [COLOR=darkblue]As[/COLOR] [COLOR=darkblue]Variant[/COLOR]
    [COLOR=darkblue]Dim[/COLOR] NextRow [COLOR=darkblue]As[/COLOR] [COLOR=darkblue]Long[/COLOR]
    [COLOR=darkblue]Dim[/COLOR] r [COLOR=darkblue]As[/COLOR] [COLOR=darkblue]Long[/COLOR]
    [COLOR=darkblue]Dim[/COLOR] c [COLOR=darkblue]As[/COLOR] [COLOR=darkblue]Long[/COLOR]
    [COLOR=darkblue]Dim[/COLOR] i [COLOR=darkblue]As[/COLOR] [COLOR=darkblue]Long[/COLOR]
    [COLOR=darkblue]Set[/COLOR] wksDest = Sheets("Results")
    [COLOR=darkblue]With[/COLOR] Me.ListBox1
        [COLOR=darkblue]ReDim[/COLOR] aData(1 [COLOR=darkblue]To[/COLOR] .ColumnCount, 1 [COLOR=darkblue]To[/COLOR] .ListCount)
        i = 0
        [COLOR=darkblue]For[/COLOR] r = 0 [COLOR=darkblue]To[/COLOR] .ListCount - 1
            [COLOR=darkblue]If[/COLOR] .Selected(r) [COLOR=darkblue]Then[/COLOR]
                i = i + 1
                [COLOR=darkblue]For[/COLOR] c = 0 [COLOR=darkblue]To[/COLOR] .ColumnCount - 1
                    aData(c + 1, i) = .Column(c, r)
                [COLOR=darkblue]Next[/COLOR] c
            [COLOR=darkblue]End[/COLOR] [COLOR=darkblue]If[/COLOR]
        [COLOR=darkblue]Next[/COLOR] r
    [COLOR=darkblue]End[/COLOR] [COLOR=darkblue]With[/COLOR]
    [COLOR=darkblue]If[/COLOR] i = 0 [COLOR=darkblue]Then[/COLOR]
        MsgBox "No items were selected.", vbInformation
        [COLOR=darkblue]Exit[/COLOR] [COLOR=darkblue]Sub[/COLOR]
    [COLOR=darkblue]End[/COLOR] [COLOR=darkblue]If[/COLOR]
    [COLOR=darkblue]ReDim[/COLOR] [COLOR=darkblue]Preserve[/COLOR] aData(1 [COLOR=darkblue]To[/COLOR] [COLOR=darkblue]UBound[/COLOR](aData, 1), 1 [COLOR=darkblue]To[/COLOR] i)
    [COLOR=darkblue]With[/COLOR] wksDest
        NextRow = .Cells(.Rows.Count, "A").End(xlUp).Row + 1
        .Cells(NextRow, "A").Resize(UBound(aData, 2), UBound(aData, 1)).Value = Application.Transpose(aData)
    [COLOR=darkblue]End[/COLOR] [COLOR=darkblue]With[/COLOR]
[COLOR=darkblue]End[/COLOR] [COLOR=darkblue]Sub[/COLOR]

Hope this helps!

Hello Domenic, can you pls help me about the same code but i want delete the original values in original sheet. Where add the delete code ?


Thank you
 
Upvote 0

Forum statistics

Threads
1,215,896
Messages
6,127,626
Members
449,391
Latest member
Kersh82

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