Want to be able to transfer/insert data from a listbox to a specific row in a table on sheet

Paulo H

Board Regular
Joined
Jun 10, 2020
Messages
106
Office Version
  1. 2016
Platform
  1. Windows
Hi

I have created a listbox and can transfer data from it to a table ion a sheet but it will only populate the last row of the table. Sometimes it may be require do insert/transfer the data to a row mid table ie if something had been forgotten and needed to be added later. I can drag the the row up but I would prefer to add at the specific row. Can't fid a way to do it.

eg Table is populated to row 10. I then want to transfer an item from the list box and insert it in row 5, but this code only allows it to go to row 11

here is my code


Private Sub Transfer_Click()
ActiveSheet.Unprotect Password:="123"
Dim wrksht As Worksheet
Dim objListObj As ListObject


Dim i As Long
Dim listObj As ListObject
Set listObj = Sheets("Quote Form").ListObjects("Table1")
listObj.ListRows.Add , 1

listObj.DataBodyRange(listObj.ListRows.Count, 1) = ListBox1.List(ListBox1.ListIndex)


For i = 0 To Me.ListBox1.ListCount - 1
If Me.ListBox1.Selected(i) = True And Me.ListBox1.List(i, 1) <> "" Then
'Sheet1.Range("A12345").End(xlUp).Offset(1, 0) = Me.ListBox1.List(i, 0)
Sheet1.Range("A12345").End(xlUp).Offset(0, 3) = Me.ListBox1.List(i, 1)
Sheet1.Range("A12345").End(xlUp).Offset(0, 4) = Me.ListBox1.List(i, 3)
Sheet1.Range("A12345").End(xlUp).Offset(0, 2) = Me.ListBox1.List(i, 2)
Sheet1.Range("A12345").End(xlUp).Offset(0, 6) = Me.ListBox1.List(i, 4)
For x = 1 To 4
'Sheet1.Range("A123").End(xlUp).Offset(0, 1) = Me.ListBox1.List(i, x)
'Sheet1.Range("Table1").End(xlUp).Offset(3, 3) = Me.ListBox1.List(i, 3)

Next x

End If
Next i

End Sub


Many thanks
 
Replace all your code for this:

VBA Code:
Private Sub Transfer_Click()
  Dim listObj As ListObject

  ActiveSheet.Unprotect Password:="123"
  Set listObj = Sheets("Quote Form").ListObjects("Table1")
  listObj.ListRows.Add (ActiveCell.Row)
  With ListBox1
    listObj.DataBodyRange(ActiveCell.Row, 1) = .List(.ListIndex, 0)
    listObj.DataBodyRange(ActiveCell.Row, 3) = .List(.ListIndex, 1)
    listObj.DataBodyRange(ActiveCell.Row, 4) = .List(.ListIndex, 3)
    listObj.DataBodyRange(ActiveCell.Row, 2) = .List(.ListIndex, 2)
    listObj.DataBodyRange(ActiveCell.Row, 6) = .List(.ListIndex, 4)
  End With
End Sub
Hi thanks for this but I am still gett
Replace all your code for this:

VBA Code:
Private Sub Transfer_Click()
  Dim listObj As ListObject
 
  ActiveSheet.Unprotect Password:="123"
  Set listObj = Sheets("Quote Form").ListObjects("Table1")
  listObj.ListRows.Add (ActiveCell.Row)
  With ListBox1
    listObj.DataBodyRange(ActiveCell.Row, 1) = .List(.ListIndex, 0)
    listObj.DataBodyRange(ActiveCell.Row, 3) = .List(.ListIndex, 1)
    listObj.DataBodyRange(ActiveCell.Row, 4) = .List(.ListIndex, 3)
    listObj.DataBodyRange(ActiveCell.Row, 2) = .List(.ListIndex, 2)
    listObj.DataBodyRange(ActiveCell.Row, 6) = .List(.ListIndex, 4)
  End With
End Sub
Hi, thanks for this. I have replaced the code but still getting the runtime error 9, subscript out of range when I run debbug it highlights the line listObj.ListRows.ADD(ActiveCell.Row)
Thanks
Paul
 
Upvote 0

Excel Facts

Lock one reference in a formula
Need 1 part of a formula to always point to the same range? use $ signs: $V$2:$Z$99 will always point to V2:Z99, even after copying
Which cell do you have selected at the time of execution?

You could share your file in the cloud.

You could upload a copy of your file to a free site such www.dropbox.com or google drive. Once you do that, mark it for 'Sharing' and you will be given a link to the file that you can post here. If the workbook contains confidential information, you could replace it with generic data.
 
Upvote 0
Which cell do you have selected at the time of execution?

You could share your file in the cloud.

You could upload a copy of your file to a free site such www.dropbox.com or google drive. Once you do that, mark it for 'Sharing' and you will be given a link to the file that you can post here. If the workbook contains confidential information, you could replace it with generic data.
 
Upvote 0
I had some problems with your table to insert rows and to identify the fields to insert each data, I only identified 4 fields.
Try the following:

VBA Code:
Private Sub Transfer_Click()
  Dim listObj As ListObject, sh As Worksheet
  Dim nRow As Long, i As Long, j As Long
  
  'ActiveSheet.Unprotect Password:="123"
  
  Set sh = Sheets("Quote Form")
  Set listObj = sh.ListObjects("Table1")
  With ListBox1
    If .ListIndex > 0 Then
      If listObj.Range.Cells(2, 1) = "" Then
        nRow = 2
      Else
        i = listObj.HeaderRowRange.Row
        j = listObj.Range.Rows.Count
        sh.Rows(i + j).Insert
        listObj.ListRows.Add , False
        nRow = listObj.Range.Rows.Count
      End If
      listObj.Range.Cells(nRow, 1) = .List(.ListIndex, 0) 'item
      listObj.Range.Cells(nRow, 4) = .List(.ListIndex, 1) 'desc
      listObj.Range.Cells(nRow, 6) = .List(.ListIndex, 3) 'cost
      listObj.Range.Cells(nRow, 7) = .List(.ListIndex, 4) 'link
    End If
  End With
End Sub
 
Upvote 0
I had some problems with your table to insert rows and to identify the fields to insert each data, I only identified 4 fields.
Try the following:

VBA Code:
Private Sub Transfer_Click()
  Dim listObj As ListObject, sh As Worksheet
  Dim nRow As Long, i As Long, j As Long
 
  'ActiveSheet.Unprotect Password:="123"
 
  Set sh = Sheets("Quote Form")
  Set listObj = sh.ListObjects("Table1")
  With ListBox1
    If .ListIndex > 0 Then
      If listObj.Range.Cells(2, 1) = "" Then
        nRow = 2
      Else
        i = listObj.HeaderRowRange.Row
        j = listObj.Range.Rows.Count
        sh.Rows(i + j).Insert
        listObj.ListRows.Add , False
        nRow = listObj.Range.Rows.Count
      End If
      listObj.Range.Cells(nRow, 1) = .List(.ListIndex, 0) 'item
      listObj.Range.Cells(nRow, 4) = .List(.ListIndex, 1) 'desc
      listObj.Range.Cells(nRow, 6) = .List(.ListIndex, 3) 'cost
      listObj.Range.Cells(nRow, 7) = .List(.ListIndex, 4) 'link
    End If
  End With
End Sub
Hi this I am afraid still only adds the data to the end of the table and not at the that is highlighted. so if row 20 is highlighted ready to insert the data from the list box it actually adds to the next available row further down the table

Thank you I realise you have spent a lot of time with this already
 
Upvote 0
I don't understand why you want to do that, it's bad practice.
But you must have your reasons and if it is appropriate for you I have no problems.

For that, only the following is necessary:

VBA Code:
Private Sub Transfer_Click()
  Cells(ActiveCell.Row, 1) = ListBox1.List(ListBox1.ListIndex, 0) 'item
  Cells(ActiveCell.Row, 4) = ListBox1.List(ListBox1.ListIndex, 1) 'desc
  Cells(ActiveCell.Row, 6) = ListBox1.List(ListBox1.ListIndex, 3) 'cost
  Cells(ActiveCell.Row, 7) = ListBox1.List(ListBox1.ListIndex, 4) 'link
End Sub
 
Upvote 0
I don't understand why you want to do that, it's bad practice.
But you must have your reasons and if it is appropriate for you I have no problems.

For that, only the following is necessary:

VBA Code:
Private Sub Transfer_Click()
  Cells(ActiveCell.Row, 1) = ListBox1.List(ListBox1.ListIndex, 0) 'item
  Cells(ActiveCell.Row, 4) = ListBox1.List(ListBox1.ListIndex, 1) 'desc
  Cells(ActiveCell.Row, 6) = ListBox1.List(ListBox1.ListIndex, 3) 'cost
  Cells(ActiveCell.Row, 7) = ListBox1.List(ListBox1.ListIndex, 4) 'link
End Sub
Yes This is perfect thank you so much for you effort and help. I understand why you say it is bad practice but I have a situation were to be able to insert at any point is really useful. Thank you again
 
Upvote 0
I'm glad to help you. Thanks for the feedback.
 
Upvote 0

Forum statistics

Threads
1,215,054
Messages
6,122,895
Members
449,097
Latest member
dbomb1414

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