VBA Code - Name Tables using a Cell's value

Spaztic

New Member
Joined
Jul 27, 2023
Messages
48
Office Version
  1. 365
Platform
  1. Windows
I have a tricky one. I have code that creates tables automatically by looking for the words "Check Item" in column B and creating a table from 'Check Item' until the row before it hits a blank. (In the image attached, it created a table for (B3:D6) and (B8:D12). There could be A LOT of tables created. Currently, the tables are named "Check1, Check2, Check3, ..." as you can see in my code.

What I'm wanting to do is automatically (using VBA code) name each of the tables with the cell value above 'Check Item' (e.g. Basement, Exterior). I guess these values would be 1 above and 1 to the left (in column A).

Not sure if it can be done or not. Would greatly appreciate any help you can give me!

Sub CreateTable()
Dim lr As Long, i As Integer
Dim cll As Range, rng As Range

With ActiveSheet
lr = .Cells(Rows.Count, 1).End(xlUp).Row
Set rng = .Range("B1:B" & lr)
i = 0
For Each cll In rng
If cll.Value = "Check Item" Then 'find header row
i = i + 1 'count table
.ListObjects.Add(xlSrcRange, .Range(cll, cll.End(xlDown).Offset(, 2)), , xlYes).Name = "Check" & i 'create table
.ListObjects("Check" & i).TableStyle = "" 'Use blank format for table
.ListObjects("Check" & i).ShowAutoFilterDropDown = False 'Remove dropdown arrows for each column in table
End If
Next cll
End With
End Sub
 

Attachments

  • Picture1.png
    Picture1.png
    93 KB · Views: 19

Excel Facts

How to calculate loan payments in Excel?
Use the PMT function: =PMT(5%/12,60,-25000) is for a $25,000 loan, 5% annual interest, 60 month loan.
Shouldn't you be establishing the last row from column B rather than A ?

Try this
VBA Code:
Sub CreateTables()
    Dim lr As Long, i As Integer
    Dim cll As Range, rng As Range

With ActiveSheet
    lr = .Cells(Rows.Count, "B").End(xlUp).Row  '<-- changed to column B
    Set rng = .Range("B1:B" & lr)
    
    For Each cll In rng
        If cll.Value = "Check Item" Then 'find header row
            i = i + 1
            .ListObjects.Add(xlSrcRange, .Range(cll, cll.End(xlDown).Offset(, 2)), , xlYes).Name = cll.Offset(-1, -1).Value
            .ListObjects(i).TableStyle = ""            'Use blank format for table
            .ListObjects(i).DataBodyRange.AutoFilter   'Remove dropdown arrows for each column in table
        End If
    Next cll
End With
End Sub
 
Upvote 0
Solution

Forum statistics

Threads
1,223,896
Messages
6,175,259
Members
452,626
Latest member
huntinghunter

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