Most Valuable Professional


View Jan Karel Pieterse's profile on LinkedIn subscribe to rss feed
Subscribe in a reader

Subscribe to our mailing list

* indicates required

Audit !!!

Check out our RefTreeAnalyser
the ultimate Excel formula auditing tool.

Trainings

Excel VBA Masterclass (English)
Excel VBA for Financials (Dutch)

Third party tools

Speed up your file

FastExcel
The best tool to optimise your Excel model!

Repair your file

Stellar Phoenix Excel Repair
Best tool to repair corrupt Excel sheets and objects
Home > English site > Articles > Treeview control

An MSForms (all VBA) treeview

Introduction

If you have ever used the Treeview control from the "Additional controls" section, then you know what a versatile control this is to show hierarchically organized data. There are a couple of problems with this Treeview control:

  1. Compile errors due to a difference in how the control libraries are registered in 32 bits Windows' System32 and 64 bit Windows' SysWOW64 folders. If you distribute a file that was saved in 64 bit Windows, containing one of the "Microsoft Windows Common Controls 6.0" (The Treeview control is one of them) and with the reference set to "mscomctl.ocx", people using 32 bit Windows will almost certainly have problems. At best it could entail removing both the control and the reference and replacing both, but at worst the user's Excel can crash when trying to load the file and run the app.
  2. The standard Treeview control, like all non built-in ActiveX controls, cannot be used in 64 bit versions of Office.

Especially the second point convinced me it is time to develop a custom-made Treeview "control", that only uses the native Office forms controls. I started building this a couple of weeks ago and after some time I tricked Peter Thornton into helping me with it

The screenshot below shows both our new Treeview (left) and the Windows one (right) side-by-side in their simplest display mode (read on, there are even prettier screenshots further down the page):

Treeview controls
Two treeviews, left: VBA tree, right: Common controls tree

In the following pages I'll show what our treeview can do and explain how to put it to use in your own VBA project.

MAC Office and 64 bit Office Compatible!

Our treeview was tested (and works) on 64 bit Office. It also works on MAC office. Tested applications include:

Excel 2000
Excel 2003
Excel 2010
Excel 2010 (64 bit)
Excel 2011 (MAC Office)
Excel 2013 (32 bit)

Access 2003
Access 2010 (32 bit)
Access 2010 (64 bit)

Windows screenshot:

Treeview demo on Windows Excel
Treeview demo on Windows Excel

Mac screenshot:

MAC screenshot of our treeview demo form
Screenshot of treeview on Mac Excel 2011

Acknowledgements

The basic plumbing and code structure of this treeview control was devised by me. However, without the help of my friend and fellow MVP Peter Thornton, lots of functionality would not have been available now. For that I sincerely thank Peter!

Furthermore, Access MVP Ben Clothier was kind enough to make the necessary adjustments to incorporate the treeview in an Access form

Also: Fellow Excel MVP Ron De Bruin ensured the treeview also works on MAC Office 2011, Thanks Ron!

Copyright and Licensing

All code in the treeview is (c) JKP Application Development Services and Peter Thornton (the Authors). It remains our sole intellectual property.

However, we're offering this treeview to you at no cost. You get an unrestricted license for use in any VBA project you like. You're free to modify any part of the code at will.

We do have some rules:

And please mention the source of the treeview (including a link to this page) in your helpfile, manual and/or on your about screen.

We're always interested to see how people have implemented the VBA Treeview. So please feel free to send a screenshot with a brief description or relevant details.

Disclaimer

You use this control at your own risk: The authors accept no liability whatsoever for any damages which may arise due to the use of our treeview.

Donations

Many, many hours were spent developing this treeview. Although we developed it for use in our own projects, we are giving it away for free!

Nevertheless, we would really be pleased if you actually express your appreciation in a more "tangible" form. So here is a paypal donation button at your disposal:

Download

The Excel workbook contains most of the documentation (on the tabs of the workbook), so I recommend you to at least download the Excel version. The Access version has instructions on its main form (click the "How do I...?" button) on how to implement the treeview in your own projects.

Download the treeview sample Excel workbook (including documentation) (build 026, 15 Oct 2015, downloaded 32,094 times)

Download the treeview sample Word document (build 026, 15 Oct 2015, downloaded 9,977 times)

Download the treeview sample Access database (build 025, 16 Oct 2013, downloaded 26,010 times)

‘Pro’ Treeview and ListGrid VBA controls

The professional version of the treeview control has exceptional performance. Even with tens of thousands of nodes it will load quickly and remain highly responsive. It also has several new features including drag and drop.

Our new ListGrid combines most of the functionality of the ActiveX Listview and Flexgrid controls with many extra useful features. It is the result of extensive beta testing by some of our treeview users, thanks guys!

The screenshot of the demo below gives an idea of just some of its capability.

Professional ListGrid control

The Pro Treeview and ListGrid are available for 32/64 bit Excel and Access. The Excel version will also work in Mac, one or two features are disabled for Mac but we’re working on it. Unlike our free treeview they are self contained in their own files and designed to work more like real controls.

For more details and if interested to try either of these ‘controls’ please contact us:

Pro Treeview enquiry

Pro Listgrid enquiry

Please note that the pro versions are paid versions. Pricing available upon request by using the links above.

Content

 

Other controls

Another often used control is the calendar control. This control has the added problem that it has been deprecated with Office 2010 (where we're supposed to use the date picker control). Frankens Team created an all-vba alternative using very similar techniques to what we've done here.

Ron de Bruin created a Date Picker control for MAC Excel.

We are currently developing a listgrid/listview control. Contact us if you would like to participate in the beta program. Note that this control will not be made available as freeware.

 


Comments

Showing last 8 comments of 667 in total (Show All Comments):

 


Comment by: Eduardo Bernal (11/17/2018 12:54:01 PM)

Hi Filipe!,
¿any idea for your code to use treeview with data from table (your post 10/12/2018 11:47:30 AM) with a recordset with a parameter query (or a recordset filer with a criteria clause (WHERE) in SQL sentence?
Thank you!

 


Comment by: Eduardo Bernal (11/18/2018 5:55:49 PM)

Hi!
I keep on trying with Filipe`s code to display data from tables (access), and the problem starts with treeviews with just one root node. For instance, a table with just one root and three levels:

ID | Parent | Designation
1 | 0     | Root1
2 | 1     | Root1_Child1
3 | 2     | Root1_Child1_Child1
4 | 2     | Root1_Child1_Child2
5 | 1     | Root1_Child2
6 | 5     | Root1_Child2_Child1

Treeview only displays:
Root1 (1st level)
Root1_Child1 (2nd level)
Root1_Child2 (2nd level)

But, the same table with two nodes root o more:

ID | Parent | Designation
1 | 0     | Root1
2 | 0     | Root2
3 | 1     | Root1_Child1
4 | 3     | Root1_Child1_Child1
5 | 3     | Root1_Child1_Child2
6 | 2     | Root2_Child1
1 | 6     | Root2_Child1_Child1

Treeview will display all levels:

Root1 (1st level)
     Root1_Child1 (2nd level)
         Root1_Child1_Child1 (3nd level)
         Root1_Child1_Child2 (3nd level)
Root2 (1st level)
     Root2_Child1 (2nd level)
Root2_Child1_Child1 (3rd level)

¿any idea to solve this?
thanks!!





 


Comment by: Jan Karel Pieterse (11/19/2018 10:34:21 AM)

Hi Eduardo,

This should work:

Private Function GetDataFromTable()


    Dim rst As DAO.Recordset

    Dim cNode As clsNode
    Dim cNodeExists As clsNode
    Dim bNodeExists As Boolean
    Dim lNewNodes As Long
    Dim bNodeExists As Boolean

    Set rst = CurrentDb.OpenRecordset("qryMenu")

    Set mcTree = Me.subTreeView.Form.pTreeview
    With mcTree
        .NodesClear
        'Add Root nodes
        If rst.RecordCount > 0 Then
            While Not rst.EOF
                If rst.Fields("Parent") = 0 Then
                    Set cNode = .AddRoot(rst.Fields("ID"), rst.Fields("Designation"))
                    cNode.Bold = True
                End If
                rst.MoveNext
            Wend

            'Add Child nodes
            Do
                lNewNodes = 0

                For Each cNode In .Nodes
                    rst.movefirst
                    While Not rst.EOF
                        If rst.Fields("Parent") > 0 Then
                            If cNode.Key = rst.Fields("Parent") Then
                                bNodeExists = False
                                For Each cNodeExists In mcTree.Nodes
                                    If cNodeExists.Key = rst.Fields("ID") Then
                                        bNodeExists = True
                                        Exit For
                                    End If
                                Next
                                If bNodeExists = False Then
                                    cNode.AddChild rst.Fields("ID"), rst.Fields("Designation")
                                    lNewNodes = lNewNodes + 1
                                End If
                            End If
                        End If
                        rst.MoveNext
                    Wend
                Next

            Loop Until lNewNodes = 0

        End If
        'Display the tree
        .Refresh
    End With
    rst.Close
    Set rst = Nothing

End Function

 


Comment by: Eduardo Bernal (11/19/2018 5:49:02 PM)

Great Jan!
it works perfectly!, I´m very grateful,
Thanks a lot.
Regards

 


Comment by: Harun KILIÇ (12/9/2018 6:52:41 PM)

Hi. I'm trying to develope an assembly duplicator for Autodesk Inventor, I used your codes for custonm treeview control. You have mentioned that mouse wheel scroll hook is available with in paid version.
How much is it? Thanks.

 


Comment by: Jan Karel Pieterse (12/10/2018 9:37:08 AM)

Hi Harun,

You mention Autodesk, are you planning to use the treeview in Excel VBA or in another program? The pro controls are only available in Excel and Access.

 


Comment by: Harun KILIÇ (12/10/2018 6:28:12 PM)

Hi Jan, I already used your treeview codes in Inventor VBA.
This is the screen capture of userform;

May be you can create a dll only for wheel scroll hook methods; for a fee; if possible. Thanks.

 


Comment by: Jan Karel Pieterse (12/11/2018 10:25:52 AM)

Hi Harun,

Your image URL leads to a site which displays as "Forbidden", so I have removed it from your post.
In which application did you implement the treeview precisely?

 


Have a question, comment or suggestion? Then please use this form.

If your question is not directly related to this web page, but rather a more general "How do I do this" Excel question, then I advise you to ask your question here: www.eileenslounge.com.

Please enter your name (required):

Your e-mail address (optional, will only be used to inform you when your comment is published or to respond to your question directly):

Your request or comment (max 2000 characters):

To post VBA code in your comment, use [VB] tags, like this: [VB]Code goes here[/VB].

I give permission to process this data and display my name and my comment on this website accoring to our Privacy Policy.