SparklineHeader3

In my last post on Excel Sparklines with VBA, I demonstrated:

  • Dynamically determine a data range on a worksheet
  • Add a Sparkline Group to the next available column
  • Format the Sparkline Group for line and Spark Points
  • Add the appropriate Axis to each Sparkline Group to be used as a reference to compare actual values to target values

But followers of this blog (both of you) know that I loves me some Pivot Tables! Today, I’ll see if I can create a Pivot Table with Slicers and Sparklines that update as the user is working with the Slicers. For today, I’ll add everything up through Slicers manually and use VBA just for creating the Sparklines.

As the user clicks on slicer items, the old Sparklines are deleted and new Sparklines are created
.


 

Create Some Sample Data

First, I’ll need some data. I’d like some QA data for some Reps for each month of 2013. I demonstrated how to create this test data previously using Cartesian Products in MS Access – so I won’t go through all of those steps again. Make sure you check out the link to understand the steps for creating the test data.

QASparklineData2

  1. I created a Cartesian Query to join all data from tblDates, tblRegions and tblReps. I added a calculated field to the query to generate sample QAScores.
  2. I converted the query to a Make Table Query and ran the query thus creating the table: tblSampleData.
  3. I created a new select query to get all records from the new table.

Connect To Access From Excel

Now that I have a Select Query in the Access Database, I’ll connect to the Query from Excel

ConnectToAccess

  1. Click on the Data Tab on the Ribbon
  2. In the Get External Data Group
  3. Click on “From Access” icon

NavigateToDatabase

In the Select Data Source Dialog, navigate to and select the database.

AccessSelectQuery

In the Select Table Dialog, choose the Select Query you created in the Access database.

ImportDataDialog

In the Import Data Dialog, accept the defaults to View The Data as a Table in the Workbook and to return the data to $A$1 in the existing worksheet.

DataImportExcelAccess

The data will be returned from the Access Query to Excel as an Excel Table (a.k.a ListObject Object)

InitialPivotWithSlicers

Lastly, I added a Pivot Table and 2 Slicers.

Pivot Table – Replace Data Warning

Recall from my last post, I added Sparklines to the next available blank column adjacent to a Range Object so I need to do the same this time – only I have a Pivot Table that can expand and contract based on Slicer Item selections. This means that if there is anything in the next adjacent column, and the Pivot Table needs to expand, I’ll receive a warning message:

DataReplaceDialog

That is not very friendly for the end-user, so I’ll need to figure out a way to handle that.

Clean The Worksheet

I need to begin with a little cleanup on the Worksheet to make sure there is nothing on the Worksheet except for the Pivot Table. The Slicers don’t count since they are Shape Objects that float on a layer above the Worksheet. I also need to unhide any hidden columns:

    'Ensure all columns on the worksheet are visible
        ws.Cells.Columns.EntireColumn.Hidden = False

    'Clear the Worksheet
        ClearAllExceptPivotTable pt:=pt
Public Sub ClearAllExceptPivotTable(pt As PivotTable)

    '=========================================================================================
    'Parameters
    'pt                 Required. A Pivot Table.

    'This Sub() clears all cells in the used range of the worksheet except for the Pivot Table
    '==========================================================================================

    'Declare objects
        Dim ws As Worksheet
        Dim slg As SparklineGroup
        Dim rngPT As Range
        Dim rngClear As Range
        Dim C As Range

    'Error handler
        On Error GoTo ErrHandler

    'Initialize objects
        Set ws = pt.Parent
        Set rngPT = pt.TableRange1

    'Check each Cell in the used range to determine if the Cell is part of the Pivot Table
    'If the Cell is not Part of the Pivot Table, clear the Cell of all contents and formats
        For Each C In ws.UsedRange
            If Intersect(C, rngPT) Is Nothing Then
                If rngClear Is Nothing Then Set rngClear = C Else Set rngClear = Union(C, rngClear)
            End If
        Next C

        If Not rngClear Is Nothing Then rngClear.Clear

    'Check if there are any Sparkline Groups on the worksheet - if there are, clear them
    'Sometimes these are not included in the UsedRange
        ws.Cells.SparklineGroups.Clear

ErrHandler:
        If Err.Number > 0 Then _
            MsgBox Err.Description, vbMsgBoxHelpButton, "Clear Pivot Table Sparkline Range", Err.HelpFile, Err.HelpContext

    'Tidy up
        Set C = Nothing
        Set rngClear = Nothing
        Set rngPT = Nothing
        Set ws = Nothing

End Sub

The money shot here is to check if a cell in the TableRange1 of the PivotTable Intersects with the cells of the UsedRange of the Worksheet. If it does intersect, then do nothing, otherwise, clear the cell. The odd part, is that it seems that, at least sometimes, the Sparkline Groups are not included in the UsedRange, so I added the bit to clear any Sparkline Groups.

Handle One Slicer Item

I need to be able to handle the instance where the user might only choose one slicer item for the month. I only want to create a Sparkline if the user selected 2 or more months from the month slicer since a single month is rather meaningless in terms of a Sparkline. So I created a bit of code to get the visible slicer item count and if less than or equal to 1, I’ll return a friendly message to the user and exit the Sub().

    'Get the count of the visible slicer items
        lngSlicerItemCount = wb.SlicerCaches("Slicer_MonthRecord").VisibleSlicerItems.Count

    'If visible slicer count is not greater than 1, then no Sparklines are needed
        If lngSlicerItemCount <= 1 Then
            MsgBox "There are not enough months of data included in the analysis to generate Sparklines. Exiting"
            Exit Sub
        End If

NotEnoughData

Sparkline Group Source Data

One item needed for creating a Sparkline Group, is the source data. For this post, I have a Pivot Table that can expand and contract so the data source will expand and contract based on the slicer items selected by the user. Fortunately, Excel Pivot Tables have Special VBA Range Names. For the data source for the sparklines, I’ll use the DataBodyRange of the Pivot Table.


 

Check out Jon Peltier’s blog for more on the Special VBA Range Names of Pivot Tables here

 


    'Create a Range Object as the source for the Sparkline Group
        Set rngDataBodyRange = pt.DataBodyRange

Does the DataBodyRange Include Grand Totals

If the Grand Totals for Rows is on (True) for the PivotTable, I need to Resize the DataBodyRange by -1 column because I don’t want the Grand Total Column included as part of the data source

    'Check if the Range Object needs to be resized due to Grand Total Rows
        Set rngSparklineDataSource = GetDataBodyRange(rng:=rngDataBodyRange, _
                                                      pt:=pt)
Public Function GetDataBodyRange(pt As PivotTable) As Range

    '===============================================================================================
    'Parameters
    'pt                             Required. A Pivot Table.

    'Returns                        A Range Object.

    'The function returns a Range Object that represents the DataBodyRange of a Pivot Table
    'If Grand Totals are displayed, the Range is Resized to exclude the Grand Total Rows
    '================================================================================================

    'Declare objects
        Dim rng As Range
        Dim rngFirstCell As Range
        Dim rngData As Range

    'Declare variables
        Dim r As Long
        Dim c As Long

    'Error handler
        On Error GoTo ErrHandler

    'Initialize objects
        Set rng = pt.DataBodyRange

    'Get rows and columns of Pivot Table Range
        With rng
            r = .Rows.Count
            c = .Columns.Count
        End With

    'Check if Grand Totals are displayed for Rows.
    'If they are, decrease the the column count of the Range by 1
        With pt
            If .RowGrand = True Then c = c - 1
        End With

    'Create the Data Range without Grand Totals
        Set rngFirstCell = rng.Cells(1, 1)
        Set rngData = rngFirstCell.Resize(r, c)

    'Pass the Range to the Function
        Set GetDataBodyRange = rngData

ErrHandler:
        If Err.Number > 0 Then _
            MsgBox Err.Description, vbMsgBoxHelpButton, "Pivot Table Data Source For Sparklines", Err.HelpFile, Err.HelpContext

    'Tidy up
        Set rng = Nothing
        Set rngFirstCell = Nothing
        Set rngData = Nothing

End Function

Where To Put The Sparkline Group

As I stated earlier, in my last post on Sparklines, I was able to position the Sparkline Group immediately adjacent to the Range of data. I cannot do that this time, since the Pivot Table needs room to expand to columns to the right based on which slicer items the user chooses. So I need to place the Sparkline Group somewhere away from the Pivot Table and then hide all empty columns. In the code below< I used an offset of 12 columns from the last column of the DataBodyRange.

    'Create a Range Object as the destination for the Sparkline Group
        Set rngSparklinePlaceHolder = GetRangeForSparklinePlaceHolder(rng:=rngSparklineDataSource, _
                                                                      pt:=pt)
Public Function GetRangeForSparklinePlaceHolder(rng As Range, _
                                                pt As PivotTable)

    '=========================================================================================
    'Parameters
    'rng                Required. A DataBodyRange of a Pivot Table
    'pt                 Required. A Pivot Table.

    'Returns            A Range Object.

    'The function returns a Range Object which represents a placeholder for a Sparkline Group
    '=========================================================================================

    'Declare objects
        Dim ws As Worksheet
        Dim rngSparklineBegin As Range
        Dim rngSparklineEnd As Range
        Dim rngSparklineTotal As Range

    'Error handler
        On Error GoTo ErrHandler

    'Get Worksheet
        Set ws = pt.Parent

    'Get first cell and last cell of column adjacent to Pivot Table
    'Offset Columns allows Pivot Table to expand without warning of overwriting data
        With rng
            Set rngSparklineBegin = .End(xlToRight).Offset(0, 12)
            Set rngSparklineEnd = .End(xlToRight).End(xlDown).Offset(0, 12)
        End With

    'Create Range for Sparkline Group
        Set rngSparklineTotal = ws.Range(rngSparklineBegin, rngSparklineEnd)

    'Pass the Range to the Function
        Set GetRangeForSparklinePlaceHolder = rngSparklineTotal

ErrHandler:
        If Err.Number > 0 Then _
            MsgBox Err.Description, vbMsgBoxHelpButton, "Get Range For Sparkline Group", Err.HelpFile, Err.HelpContext

    'Tidy up
        Set rngSparklineTotal = Nothing
        Set rngSparklineEnd = Nothing
        Set rngSparklineBegin = Nothing
        Set ws = Nothing
End Function

Plot Variances To Target – Not Actual Values

Recall from my first post on Sparklines with VBA, I went through several machinations to calculate variances to a target value and plotted those variances, not the actual values. This allow me to add a Horizontal Axis as a reference line. Go back and review the first post if you need to review the walk-through of the process.

    'Add a worksheet for horizontal axis value calculations
        AddWorksheet wb:=wb, _
                     strSheetName:="SparklineData"

        Set wsSparklineData = wb.Worksheets("SparklineData")

    'Create a Range on the Sparkline Data Worksheet
    'The Range should be the same size as the Source Data Range
        With rngSparklineDataSource
            lngRowFirstSource = .Row
            lngColFirstSource = .Column
            lngRowsSource = .Rows.Count
            lngColsSource = .Columns.Count
        End With

        With wsSparklineData
            Set rngData = .Cells(lngRowFirstSource, lngColFirstSource)
            Set rngData = rngData.Resize(lngRowsSource, lngColsSource)
        End With

    'Add a formula to the Data Range to determine the difference between Target and Actual
        For j = 1 To lngColsSource
            For i = 1 To lngRowsSource
                rngData.Cells(i, j).Value = rngSparklineDataSource.Cells(i, j).Value - lngTARGET
            Next i
        Next j
Option Explicit

Public Function AddWorksheet(wb As Workbook, _
                             strSheetName As String) As Object

    'Declare variables
        Dim ws As Worksheet

    'Error handler
        On Error GoTo ErrHandler

    'Add worksheet
        With wb
            On Error Resume Next
            .Worksheets(strSheetName).Delete
            Set ws = .Sheets.Add(After:=.Sheets(wb.Sheets.Count))
            ws.Name = strSheetName
        End With

    'Pass object to function
        Set AddWorksheet = ws

ErrHandler:
    If Err.Number > 0 Then _
        MsgBox Err.Description, vbMsgBoxHelpButton, "Add a worksheet", Err.HelpFile, Err.HelpContext

    'Tidy up
        Set ws = Nothing

End Function

Add Sparkline Group

Now that I have a range and a data source, I can add the Sparkline Group:

    'Add SparkLine Group
        Set slg = GetSparkLineGroup(rngSparklinePlacement:=rngSparklinePlaceHolder, _
                                    rngSparklineSourceData:=rngData)

Option Explicit

Public Function GetSparkLineGroup(rngSparklinePlacement As Range, _
                                  rngSparklineSourceData As Range) As SparklineGroup

        'Declare objects
            Dim slg As SparklineGroup

        'Delare variables
            Dim strSourceData As String

        'Error handler
            On Error GoTo ErrHandler

        'Source data address as qualified string
            strSourceData = rngSparklineSourceData.Parent.Name & _
                            "!" & _
                            rngSparklineSourceData.Address

        'Add SparkLine Group
             Set slg = rngSparklinePlacement.SparklineGroups.Add(Type:=xlSparkLine, _
                                                               SourceData:=strSourceData)

        'Pass object to function
            Set GetSparkLineGroup = slg

ErrHandler:
        If Err.Number > 0 Then _
            MsgBox Err.Description, vbMsgBoxHelpButton, "Create SparkLine Group", Err.HelpFile, Err.HelpContext

        'Tidy up
            Set slg = Nothing

End Function

SLGAdded3

The Sparkline Group has been added. Note the 11 blank columns.


 

Format The Sparklines

Now that I have Sparklines, I would like to add a bit of formatting for the line, and the low, high and end spark points:

    'Format SparkLine Group
        FormatSparkLineGroup slg:=slg, _
                             lngColorLine:=RGB(128, 128, 128), _
                             lngColorHighpoint:=RGB(0, 0, 0), _
                             lngColorLowpoint:=RGB(255, 0, 0), _
                             lngColorLastPoint:=RGB(0, 0, 0)
Option Explicit

Public Sub FormatSparkLineGroup(slg As SparklineGroup, _
                                lngColorLine As Long, _
                                lngColorHighpoint As Long, _
                                lngColorLowpoint As Long, _
                                lngColorLastPoint As Long, _
                                Optional ByVal blnVisHighpoint As Boolean = True, _
                                Optional ByVal blnVisLowpoint As Boolean = True, _
                                Optional ByVal blnVisLastpoint As Boolean = True)

    'Error handler
        On Error GoTo ErrHandler

    'Line Settings:
        With slg
            .LineWeight = 1.3
            .SeriesColor.Color = lngColorLine
        End With

    ' High point settings:
        With slg.Points.Highpoint
            .Visible = blnVisHighpoint
            .Color.Color = lngColorHighpoint
        End With

    ' Low point settings:
        With slg.Points.Lowpoint
            .Visible = blnVisLowpoint
            .Color.Color = lngColorLowpoint
        End With

    ' End point settings:
        With slg.Points.Lastpoint
            .Visible = blnVisLastpoint
            .Color.Color = lngColorLastPoint
        End With

ErrHandler:
        If Err.Number > 0 Then _
            MsgBox Err.Description, vbMsgBoxHelpButton, "Format SparkLines", Err.HelpFile, Err.HelpContext

End Sub

SLGFormatted2

The Sparklines have been formatted for line weight, line color, spark markers: low, high, end points
.


 

Format The Spark Axes

Now I need to format the Sparkline Axes. I need to set the correct scale type for each sparkline based on the count of the values that are greater than or less than 0. All of this has to be dynamic since I don’t know if the user selected 2 months or 12 months or somewhere in-between.

  • If all values are less than 0. then the Vertical CustomMinScaleValue is set to 0 and the Horizontal Axis will be a reference line above the Sparkline.
  • If all values are greater than 0. then the Vertical CustomMaxScaleValue is set to 0 and the Horizontal Axis will be a reference line below the Sparkline.
  • If values are a mix of less than, greater than and equal to 0, then I do not need to specify a scale value and the Horizontal Axis will be a reference line between the SparkPoints.
Option Explicit

Public Sub FormatSparklineAxes(wsReport As Worksheet, _
                               wsSparklineData As Worksheet, _
                               rngSparklineSourceData As Range, _
                               lngValueForComparison As Long, _
                               lngColorHorizontalAxis As Long, _
                               Optional ByVal blnVisHorizontalAxis As Boolean = True)

    'Declare objects
        Dim rngFirstCellSparklineGroup As Range
        Dim sg As SparklineGroup

    'Declare variables
        Dim i As Long                               'Loop through data source rows
        Dim j As Long                               'Loop through data source columns
        Dim lngColumnDataSourceBegin As Long        'Column number of beginning of data source
        Dim lngColumnDataSourceEnd As Long          'Column number of end of data source
        Dim lngColumnsDataSource As Long            'Number of columns in SparkLine Group data source
        Dim lngRowSparkLineGroup As Long            'Row number of individual sparkline
        Dim lngValueGreater As Long                 'Counter - number of values in source greater than target
        Dim lngValueLesser As Long                  'Counter - number of values in source lesser than target

    'Initialize objects and variables
        With rngSparklineSourceData
            lngColumnDataSourceBegin = .Cells(1, 1).Column
            lngColumnDataSourceEnd = .End(xlToRight).Column
        End With

        lngColumnsDataSource = wsSparklineData.UsedRange.Columns.Count

    'Get cell of Sparkline group
        Set rngFirstCellSparklineGroup = wsReport.Cells.SparklineGroups.item(1).Location.Cells(1, 1)

    'Ungroup Sparkline Group
        wsReport.Cells.SparklineGroups.Ungroup

    'Determine vertical axis placement for each sparkline
        For Each sg In wsReport.Cells.SparklineGroups
            i = sg.Location.Row
            lngValueLesser = 0
            lngValueGreater = 0
            For j = lngColumnDataSourceBegin To lngColumnDataSourceEnd
                If wsSparklineData.Cells(i, j).Value < lngValueForComparison Then
                    lngValueLesser = lngValueLesser + 1
                ElseIf wsSparklineData.Cells(i, j).Value > lngValueForComparison Then
                    lngValueGreater = lngValueGreater + 1
                Else
                    'Source data value is equal to target value - axis will plot properly, no action needed
                End If
            Next j

            'Set sparkline axes based on source data values
            'If all values are greater than target value, set the Min axis value to zero
            'If all values are less than target value, set the Max axis value to zero

                With sg.Axes
                    If lngValueLesser = lngColumnsDataSource Then
                        .Vertical.MaxScaleType = xlSparkScaleCustom
                        .Vertical.CustomMaxScaleValue = 0
                    ElseIf lngValueGreater = lngColumnsDataSource Then
                        .Vertical.MinScaleType = xlSparkScaleCustom
                        .Vertical.CustomMinScaleValue = 0
                    Else
                        .Vertical.MaxScaleType = xlSparkScaleSingle
                    End If
                        .Horizontal.Axis.Visible = blnVisHorizontalAxis
                        .Horizontal.Axis.Color.Color = lngColorHorizontalAxis
                End With
        Next sg

'        'Regroup sparklines
'            ws.Cells.SparklineGroups.Group Location:=rngFirstCellSparklineGroup

    'Tidy up
        Set rngFirstCellSparklineGroup = Nothing

End Sub

SLGAxesFormatted

The Sparkline Axes have been formatted for visibility, line color and scale type
.


 

Add & Format A Header Label For The Sparkline Group

Next, I want to add a header label for the Sparkline Group and format the header so that it has the same format as the header row of the Pivot Table

    'Add Sparkline Group Header
        rngSparklinePlaceHolder.Cells(1, 1).Offset(-1, 0).Value = "Trend"

    'Format Sparkline Group Header
        FormatSparklineGroupHeader pt:=pt, _
                                   rng:=rngSparklinePlaceHolder

Public Sub FormatSparklineGroupHeader(pt As PivotTable, _
                                      rng As Range)

    '===================================================================================
    'Parameters
    'pt                 Required. A Pivot Table.
    'rng                Required. A Range object that has a header row that needs to be formatted

    'Format the header row of a Sparkline Group
    '===================================================================================

    'Declare objects
        Dim rngForFormat As Range

    'Error handler
        On Error GoTo ErrHandler

    'Create Range Object that needs to be formatted
        Set rngForFormat = rng.Cells(1, 1).Offset(-2, 0).Resize(2, 1)

    'Format the Range
        pt.DataBodyRange.End(xlToRight).End(xlUp).Copy
        rngForFormat.PasteSpecial _
                     Paste:=xlPasteFormats, _
                     Operation:=xlNone, _
                     SkipBlanks:=False, _
                     Transpose:=False
        Application.CutCopyMode = False

ErrHandler:
        If Err.Number > 0 Then _
            MsgBox Err.Description, vbMsgBoxHelpButton, "Format Sparkline Group Header", Err.HelpFile, Err.HelpContext

    'Tidy up
        Set rngForFormat = Nothing

End Sub

SLGHeader

A label has been added to the row above the Sparkline Group and it has been formatted the same as the header row of the Pivot Table
.


 

Add Borders To Sparkline Group Cells

I would like to add cell borders to each cell in the Sparkline Group Range. I think this aids in scanning horizontally from Pivot Table values to the respective Sparkline on each row.

    'Add Cell Borders to Sparkline Group
        AddRangeBorders rng:=rngSparklinePlaceHolder, _
                        lngColor:=RGB(217, 217, 217)

Public Sub AddRangeBorders(rng As Range, _
                           lngColor As Long)

    '===============================================================================
    'Parameters
    'rng                Required. A Range Object.
    'lngColor           Required. Color for Cell Borders.

    'This Sub() adds borders to the specified Range Object
    '==============================================================================

    'Declare objects
        Dim c As Range

    'Declare variables

    'Error handler
        On Error GoTo ErrHandler

    'Add borders to Range
        With rng
            .BorderAround LineStyle:=xlContinuous, _
                          Weight:=xlThin, _
                          Color:=lngColor
        End With

        With rng
            For Each c In .Cells
                With c.Borders(xlEdgeBottom)
                    .LineStyle = xlContinuous
                    .Color = lngColor
                    .Weight = xlThin
                End With
            Next c
        End With

ErrHandler:
        If Err.Number > 0 Then _
            MsgBox Err.Description, vbMsgBoxHelpButton, "Add range borders", Err.HelpFile, Err.HelpContext

    'Tidy up

End Sub

SLGBorders

Thin light borders have been added to each Cell in the Sparkline Group
.


 

Hide Empty Columns

Now I would like to hide the empty columns between the Pivot Table and the Sparkline Group so that it appears as though the Sparklines are part of the Pivot Table. This Sub finds the last column of the DataBodyRange and the column of the Sparkline Group and hides everything in-between:

    'Hide empty colums between the Pivot Table and the Sparkline Group
        HideColumnsBetweenRanges pt:=pt, _
                                 rng:=rngSparklinePlaceHolder

Public Sub HideColumnsBetweenRanges(pt As PivotTable, _
                                    rng As Range)

    '=========================================================================================
    'Parameters
    'pt                 Required. A Pivot Table.
    'rng                Required. A Range Object.

    'This Sub() hides all colums between a Pivot Table and a related Range Object
    '==========================================================================================

    'Declare objects
        Dim ws As Worksheet
        Dim rngHide As Range

    'Declare variables
        Dim lngColPivotTable As Long
        Dim lngColRange As Long

    'Error handler
        On Error GoTo ErrHandler

    'Initialize objects and variables
        Set ws = pt.Parent
        lngColPivotTable = pt.DataBodyRange.End(xlToRight).Column
        lngColRange = rng.Column

    'Create a range of columns between the 2 columns
        With ws
            Set rngHide = .Range(.Cells(1, lngColPivotTable + 1), .Cells(1, lngColRange - 1))
        End With

    'Hide the range of columns
        rngHide.EntireColumn.Hidden = True

ErrHandler:
        If Err.Number > 0 Then _
            MsgBox Err.Description, vbMsgBoxHelpButton, "Clear Pivot Table Sparkline Range", Err.HelpFile, Err.HelpContext

    'Tidy up
        Set rngHide = Nothing
        Set ws = Nothing

End Sub

SLGHiddenColumns

All columns between the DataBodyRange of the Pivot Table and the Sparkline Group have been hidden
.


 

Event Driven

The final step, is to wire the Main Procedure to an Event so that as the user clicks on slicer items, all previous data is cleared, the Pivot Table is updated, and new Sparklines are created.
The Worksheet_PivotTableUpdate event is the best event to be used in this case:

Option Explicit

Private Sub Worksheet_PivotTableUpdate(ByVal Target As PivotTable)

    'Declare objects
        Dim pt As PivotTable

    'Excel environment
        With Application
            .ScreenUpdating = False
            .DisplayAlerts = False
        End With

    'Initialize objects
        Set pt = Me.PivotTables(1)

    'Clear all Cells on the Worksheet except the Pivot Table
        ClearAllExceptPivotTable pt:=pt

    'Create Sparklines for Pivot Table
        CreateSparkLinesForPivotTable wb:=Me.Parent, _
                                      ws:=Me, _
                                      pt:=Me.PivotTables(1)
    'Set focus on the report tab
        Me.Activate
        Me.Range("C2").Select

    'Tidy up
        With Application
            .ScreenUpdating = True
            .DisplayAlerts = True
        End With
End Sub

The Main Procedure

Here is the main procedure that calls all other Subs() and Functions():

Option Explicit

Public Sub CreateSparkLinesForPivotTable(wb As Workbook, _
                                         ws As Worksheet, _
                                         pt As PivotTable)

    'Declare objects
        Dim wsSparklineData As Worksheet
        Dim rngSparklineGroup As Range
        Dim rngDataBodyRange As Range
        Dim rngSparklineDataSource As Range
        Dim rngSparklinePlaceHolder As Range
        Dim rngData As Range
        Dim rngHeader As Range
        Dim slg As SparklineGroup

    'Declare variables
        Dim lngSparkLineColumn As Long
        Dim lngSparkLineFirstRow As Long
        Dim lngSparkLineLastRow As Long
        Dim lngRowsSource As Long
        Dim lngColsSource As Long
        Dim lngRowFirstSource As Long
        Dim lngColFirstSource As Long
        Dim i As Long
        Dim j As Long
        Dim lngSlicerItemCount As Long

    'Declare constants
        Const lngTARGET As Long = 98
        Const lngTARGETAXIS As Long = 0

    'Error handler
        On Error GoTo ErrHandler

    'Get the count of the visible slicer items
        lngSlicerItemCount = wb.SlicerCaches("Slicer_MonthRecord").VisibleSlicerItems.Count

    'Ensure all columns on the worksheet are visible
        ws.Cells.Columns.EntireColumn.Hidden = False

    'Clear the Worksheet
        ClearAllExceptPivotTable pt:=pt

    'If visible slicer count is not greater than 1, then no Sparklines are needed
        If lngSlicerItemCount <= 1 Then
            MsgBox "There are not enough months of data included in the analysis to generate Sparklines. Exiting"
            Exit Sub
        End If

    'Create a Range Object as the source for the Sparkline Group
        Set rngDataBodyRange = pt.DataBodyRange

    'Check if the Range Object needs to be resized due to Grand Total Rows
        Set rngSparklineDataSource = GetDataBodyRange(pt:=pt)

    'Create a Range Object as the destination for the Sparkline Group
        Set rngSparklinePlaceHolder = GetRangeForSparklinePlaceHolder(rng:=rngSparklineDataSource, _
                                                                      pt:=pt)

    'Add a worksheet for horizontal axis value calculations
        AddWorksheet wb:=wb, _
                     strSheetName:="SparklineData"

        Set wsSparklineData = wb.Worksheets("SparklineData")

    'Create a Range on the Sparkline Data Worksheet
    'The Range should be the same size as the Source Data Range
        With rngSparklineDataSource
            lngRowFirstSource = .Row
            lngColFirstSource = .Column
             lngRowsSource = .Rows.Count
            lngColsSource = .Columns.Count
        End With

        With wsSparklineData
            Set rngData = .Cells(lngRowFirstSource, lngColFirstSource)
            Set rngData = rngData.Resize(lngRowsSource, lngColsSource)
        End With

    'Add a formula to the Data Range to determine the difference between Target and Actual
        For j = 1 To lngColsSource
            For i = 1 To lngRowsSource
                rngData.Cells(i, j).Value = rngSparklineDataSource.Cells(i, j).Value - lngTARGET
            Next i
        Next j

    'Add SparkLine Group
        Set slg = GetSparkLineGroup(rngSparklinePlacement:=rngSparklinePlaceHolder, _
                                    rngSparklineSourceData:=rngData)

    'Format SparkLine Group
        FormatSparkLineGroup slg:=slg, _
                             lngColorLine:=RGB(128, 128, 128), _
                             lngColorHighpoint:=RGB(0, 0, 0), _
                             lngColorLowpoint:=RGB(255, 0, 0), _
                             lngColorLastPoint:=RGB(0, 0, 0)

    'Format SparkLine Group Axes
         FormatSparklineAxes wsReport:=ws, _
                            wsSparklineData:=wsSparklineData, _
                            rngSparklineSourceData:=rngData, _
                            lngValueForComparison:=lngTARGETAXIS, _
                            lngColorHorizontalAxis:=RGB(128, 128, 128)

    'Add Sparkline Group Header
        rngSparklinePlaceHolder.Cells(1, 1).Offset(-1, 0).Value = "Trend"

    'Format Sparkline Group Header
        FormatSparklineGroupHeader pt:=pt, _
                                   rng:=rngSparklinePlaceHolder

    'Add Cell Borders to Sparkline Group
        AddRangeBorders rng:=rngSparklinePlaceHolder, _
                        lngColor:=RGB(217, 217, 217)

    'Hide empty colums between the Pivot Table and the Sparkline Group
        HideColumnsBetweenRanges pt:=pt, _
                                 rng:=rngSparklinePlaceHolder

ErrHandler:
    If Err.Number > 0 Then _
        MsgBox Err.Description, vbMsgBoxHelpButton, "Create Sparkline Group", Err.HelpFile, Err.HelpContext
        Err.Clear

    'Tidy up
        Set rngSparklineGroup = Nothing
        Set rngData = Nothing
        Set rngDataBodyRange = Nothing
        Set rngSparklineDataSource = Nothing
        Set rngSparklinePlaceHolder = Nothing
        Set slg = Nothing
        Set wsSparklineData = Nothing

        With Application
            .DisplayAlerts = True
        End With

End Sub

Tidy Up

This was a good project, I haven’t seen any posts on Sparklines with Pivot Tables as of yet, so hopefully this is helpful. I’m not a big fan of using the blank columns the way I did and then hiding them. I tried calling the ClearWorksheet Routine first from the PivotTableUpdate Event, but I still received the error warning that I was about to overwrite data on the worksheet. I tried a few other Pivot Table Events, but nothing gave me the right outcome. I think the solution would be for Microsoft to add some Events to Slicer Objects or SlicerItem Objects, such as on Mouse Hover or on SlicerItem_Click.

Downloads

You may download the Excel Workbook, the Access Database and/or the code modules (.bas files) from OneDrive.

Download

  • M_CreateSparklinesForPivotTable.bas
  • M_ExportModules.bas
  • M_FormatSparklineAxes.bas
  • M_FormatSparkLines.bas
  • M_RangeObject.bas
  • M_SparklinesAdd.bas
  • M_SparklinesDelete.bas
  • M_Worksheet.bas

Additional Resources – Sparklines

, , , , , , ,

SparkHeaderFinal

A sparkline is a small intense, simple, word-sized graphic with typographic resolution. – Edward Tufte

Today, I’ll look at how I might be able to :

  • Dynamically find a Range of data by finding the first and last Cells of data
  • Add a SparkLine Group for the data Range
  • Format the Sparklines and add markers for various SparkPoints
  • Add appropriate SparkAxes to be used as reference lines for visualizing actual values vs target values

 

The Data

First, I’ll need some data. I’d like some QA data for some Reps for each month of 2014. I demonstrated how to create this test data previously using Cartesian Products in MS Access – so I won’t go through all of those steps again. Make sure you check out the link to understand the steps for creating the test data.

SparklineData3

Here is the final data summarized by Rep and by Month:

SparklineData4

Delete Existing SparkLine Groups

First, I’ll need to delete any existing SparkLine Groups from previous runs:

Option Explicit

Public Sub DeleteSparklines(ws As Worksheet)

    ''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''
    'DeleteSparklines
    'Deletes any Sparkline Groups from the specified worksheet
    '
    'Parameters        :
    'ws                :   Required, A Woksheet Object.
    '
    '''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''

    'Declare objects
        Dim rng As Range
        Dim sg As SparklineGroup

    'Error handler
        On Error Resume Next

    'Initialize
        Set rng = ws.UsedRange

    'Delete Sparkline Groups if any exist
        With rng
            For Each sg In rng.SparklineGroups
                sg.Delete
            Next sg
        End With

ErrHandler:
    If Err.Number > 0 Then _
        MsgBox Err.Description, vbMsgBoxHelpButton, "Delete SparkLine Group", Err.HelpFile, Err.HelpContext
        Err.Clear

    'Tidy up
        Set rng = Nothing
End Sub

Find Last Cell With Data

Next, I’ll need to find the last cell with data on the worksheet:

Public Function GetLastCell(ws As Worksheet, _
                            rngBegin As Range) As Range

    ''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''
    'GetLastCell
    'Returns a Range Object as a Cell.
    '
    'Parameters        :
    'ws                :   Required, A Woksheet Object.
    'rng               :   Required, A Range Object.
    '                      Use xlPrevious when searching for the last used Cell.
    '                      Use xlNext when searching or the first used cell.
    '''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''

    'Declare objects
        Dim rng As Range

    'Get range as a single cell
        With ws
            Set rng = .Cells.Find(What:="*", _
                                  After:=rngBegin, _
                                  LookIn:=xlFormulas, _
                                  LookAt:=xlPart, _
                                  SearchOrder:=xlByRows, _
                                  SearchDirection:=xlPrevious, _
                                  MatchCase:=False)
        End With

    'Pass the range to the function
        Set GetLastCell = rng

    'Tidy up
        Set rng = Nothing

End Function

Find First Cell With Data

Now that I have the last cell with data, I can find the first cell with data. Note in the function below, I added a third parameter to include labels or not:

SparkLineRemoveLabels

Public Function GetFirstCell(ws As Worksheet, _
                             rngBegin As Range, _
                             IncludeLabels As Long) As Range

    ''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''
    'GetFirstCell
    'Returns a Range Object as a Cell.
    '
    'Parameters        :
    'ws                :   Required, A Woksheet Object.
    'rng               :   Required, A Range Object.
    '                      Use xlPrevious when searching for the last used Cell.
    '                      Use xlNext when searching or the first used cell.
    '''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''

    'Declare objects
        Dim rng As Range

    'Declare variables
        Dim r As Long
        Dim c As Long

    'Get range as a single cell
        With ws
            Set rng = .Cells.Find(What:="*", _
                                  After:=rngBegin, _
                                  LookIn:=xlFormulas, _
                                  LookAt:=xlPart, _
                                  SearchOrder:=xlByRows, _
                                  SearchDirection:=xlNext, _
                                  MatchCase:=False)
        End With

    'Remove row and column labels if needed
        Select Case IncludeLabels
            Case 2                          'Do not include labels
                With rng
                    r = .Row + 1
                    c = .Column + 1
                End With

                With ws
                    Set rng = .Cells(r, c)
                End With
            Case Else
                'Do nothing
        End Select

    'Pass the range to the function
        Set GetFirstCell = rng

    'Tidy up
        Set rng = Nothing

End Function

Create A Range For The Data Source

Next, I’ll create a Range to be used as the data source for the SparkLine Group using the last cell and the first cell on the worksheet:

Set rngSparkLineSource = ws.Range(firstcell, lastcell)

Create A Range For The SparkLine Group

Now that I have the first and last cell of the data source Range, I can create a Range for the SparkLine Group:

 lngSparkLineColumn = lastcell.Column + 1                                    'Move to next blank column
        lngSparkLineLastRow = lastcell.Row
        lngSparkLineFirstRow = firstcell.Row
        With ws
            Set rngSparkLineDestination = .Range(.Cells(lngSparkLineFirstRow, lngSparkLineColumn), _
                                                 .Cells(lngSparkLineLastRow, lngSparkLineColumn))
         End With

Create The SparkLine Group

One of the required parameters of the SparkLine Group Object is source data as a string. I have the source data as a Range, so I need to create a string from the Range in the form of Worksheet!Range.Address:

Option Explicit

Public Function GetSparkLineGroup(rngSparkLinePlacement As Range, _
                                  rngSparkLineSourceData As Range) As SparklineGroup

        'Declare objects
            Dim slg As SparklineGroup

        'Delare variables
            Dim strSourceData As String

        'Error handler
            On Error GoTo ErrHandler

        'Source data address as qualified string
            strSourceData = rngSparkLineSourceData.Parent.Name & _
                            "!" & _
                            rngSparkLineSourceData.Address

        'Add SparkLine Group
             Set slg = rngSparkLinePlacement.SparklineGroups.Add(Type:=xlSparkLine, _
                                                               SourceData:=strSourceData)

        'Pass object to function
            Set GetSparkLineGroup = slg

ErrHandler:
        If Err.Number > 0 Then _
            MsgBox Err.Description, vbMsgBoxHelpButton, "Create SparkLine Group", Err.HelpFile, Err.HelpContext

        'Tidy up

            Set slg = Nothing

End Function

SparkLineGroup2

SparkLine Group Formatting

Everything is looking great so far! Next, I would like to add a little formatting to the SparkLine Group. In the Sub I created, I set the default visibility for Highpoint, Lowpoint and EndPoint to true, but I can easily change to false when I call the Sub. I’ll leave the default values for now:

Option Explicit

Public Sub FormatSparkLineGroup(slg As SparklineGroup, _
                                lngColorLine As Long, _
                                lngColorHighpoint As Long, _
                                lngColorLowpoint As Long, _
                                lngColorLastPoint As Long, _
                                Optional ByVal blnVisHighpoint As Boolean = True, _
                                Optional ByVal blnVisLowpoint As Boolean = True, _
                                Optional ByVal blnVisLastpoint As Boolean = True)

    'Error handler
        On Error GoTo ErrHandler

    'Line Settings
        With slg
            .LineWeight = 1.3
            .SeriesColor.Color = lngColorLine
        End With

    ' High point settings:
        With slg.Points.Highpoint
            .Visible = blnVisHighpoint
            .Color.Color = lngColorHighpoint
        End With

    ' Low point settings:
        With slg.Points.Lowpoint
            .Visible = blnVisLowpoint
            .Color.Color = lngColorLowpoint
        End With

    ' End point settings:
        With slg.Points.Lastpoint
            .Visible = blnVisLastpoint
            .Color.Color = lngColorLastPoint
        End With

ErrHandler:
        If Err.Number > 0 Then _
            MsgBox Err.Description, vbMsgBoxHelpButton, "Format SparkLines", Err.HelpFile, Err.HelpContext

End Sub

SparkLineGroupFormatted2

Looks better! I tried the line weight at 1.5 and thought it was too thick and made the Low, High and Endpoint Markers disappear, so I settled on a line weight of 1.3.

Horizontal Axis As A Reference Line

The Sparklines look good, but we can make them better by adding a reference line to compare actual values vs a target. To dynamically add a Horizontal Axis as a Reference Line, I’ll need to do a few things:

  • Add a Worksheet to hold all calculations for the Horizontal Axis
  • Determine the size of the range of the source data
  • Create a Range on the new Worksheet the same size as the source Range
  • Add a formula to the new Range to calculate the difference between actual and target values
  • Use the resultant Range as the source Range for the SparkLine Group
  • Determine the appropriate vertical scale

Add A Workshsheet

I’ll add a Worksheet and name it “SparklineData”. Before I can create the Worksheet, I need to check if it already exists. If it does exist, delete it and then add it:

 'Check if a worksheet named "SparklineData" already exists, if it does, delete it
        With wb
            For Each sh In .Worksheets
                If sh.Name = "SparklineData" Then sh.Delete
            Next sh
        End With

    'Add a worksheet for horizontal axis value calculations
        Call AddWorksheet(wb:=wb, _
                          strSheetName:="SparklineData")
        Set wsSparklineData = wb.Worksheets("SparklineData")

The Sub:

Option Explicit

Public Function AddWorksheet(wb As Workbook, _
                             strSheetName As String) As Object

    'Declare variables
        Dim ws As Worksheet

    'Error handler
        On Error GoTo ErrHandler

    'Add worksheet
        With wb
            Set ws = .Sheets.Add(After:=.Sheets(wb.Sheets.Count))
            ws.Name = strSheetName
        End With

    'Pass object to function
        Set AddWorksheet = ws

ErrHandler:
    If Err.Number > 0 Then _
        MsgBox Err.Description, vbMsgBoxHelpButton, "Add a worksheet", Err.HelpFile, Err.HelpContext

    'Tidy up
        Set ws = Nothing

End Function

Create A Range To Contain Calculations

Now that I have a Worksheet, I need to add a Range to hold calculations that are the difference of my target value less actual performance. I want the Range to begin in the same cell and contain the same number of Rows and Columns as the Range that contains my actual values:

'Create a Range on the Sparkline Data Worksheet
    'The Range should be the same size as the Source Data Range
        With rngSparkLineSource
            lngRowFirstSource = .Row
            lngColFirstSource = .Column
            lngRowsSource = .Rows.Count
            lngColsSource = .Columns.Count
        End With

        With wsSparklineData
            Set rngData = .Cells(lngRowFirstSource, lngColFirstSource)
            Set rngData = rngData.Resize(lngRowsSource, lngColsSource)
        End With

Add A Formula To Calculate Variance: Target Vs Actual

Now that I have a Range, I need to add a formula to each Cell in the Range to calculate the the variance between target and actual values:

    'Add a formula to the Data Range to determine the difference between Target and Actual
        For j = 1 To lngColsSource
            For i = 1 To lngRowsSource
                rngData.Cells(i, j).Value = rngSparkLineSource.Cells(i, j).Value - lngTARGET
            Next i
        Next j

Use Variance Calculations As Data Source For SparkLine Group

Now, that I have calculated variances (Target – Actual) I’ll use the resultant Range as the data source for the Sparkline Group. See the GetSparkLineGroup Function above. Take note that I am using the variance calculations as the source for the SparkLine Group, but the Sparklines are being presented next to the Actual values:

    'Add SparkLine Group
        Set slg = GetSparkLineGroup(rngSparkLinePlacement:=rngSparkLineDestination, _
                                    rngSparkLineSourceData:=rngAxis)

Add Sparkline Axes As A Horizontal Reference Line

Lastly, I would like to add a Horizontal Axis as a reference line to compare actual values to a target value. The money shot here is if all values are below the target value or if all values are above the target value – in both cases, the Vertical Axis requires a Custom Scale Value. In the code below, I loop through the columns in each row and compare the value to the target value and increment counters depending if the value is greater or less than target. Finally I determine if the lesser or greater count is equal to the number of columns in the row and set the vertical axis accordingly:

Option Explicit

Public Sub FormatSparklineAxes(ws As Worksheet, _
                               rngSparkLineGroup As Range, _
                               rngSparkLineSourceData As Range, _
                               lngValueForComparison As Long, _
                               lngColorHorizontalAxis As Long, _
                               Optional ByVal blnVisHorizontalAxis As Boolean = True)

    'rngSparkLineGroup contains a sparkline group
    'rngSparkLineSourceData contains the data that will be compared to the target value
    'Value for comparison will be used to compare

    'Declare variables
        Dim i As Long                               'Loop through data source rows
        Dim j As Long                               'Loop through data source columns
        Dim lngColumnsDataSource As Long            'Number of columns in SparkLine Group data source
        Dim lngRowSparkLineGroup As Long            'Row number of individual sparkline
        Dim lngValueGreater As Long                 'Counter - number of values in source greater than target
        Dim lngValueLesser As Long                  'Counter - number of values in source lesser than target

    'Declare objects
        Dim rngRegroupSparklines As Range
        Dim sg As SparklineGroup

    'Error handler
        On Error GoTo ErrHandler

    'Initialize objects and variables
        lngColumnsDataSource = rngSparkLineSourceData.Columns.Count
        i = 1

    'Ungroup sparklines
        rngSparkLineGroup.SparklineGroups.Ungroup

    'Determine vertical axis placement for each sparkline
        For Each sg In rngSparkLineGroup.SparklineGroups
            i = sg.Location.Row
            lngValueLesser = 0
            lngValueGreater = 0
            For j = 1 To rngSparkLineSourceData.Columns.Count
                If ws.Cells(i, j + 1).Value < lngValueForComparison Then
                    lngValueLesser = lngValueLesser + 1
                ElseIf rngSparkLineSourceData.Cells(i, j + 1).Value > lngValueForComparison Then
                    lngValueGreater = lngValueGreater + 1
                Else
                    'Source data value is equal to target value - axis will plot properly, no action needed
                End If
            Next j

            'Set sparkline axes based on source data values
            'If all values are greater than target value, set the Min axis value to zero
            'If all values are less than target value, set the Max axis value to zero

            With sg.Axes
                If lngValueLesser = lngColumnsDataSource Then
                    .Vertical.MaxScaleType = xlSparkScaleCustom
                    .Vertical.CustomMaxScaleValue = 0
                ElseIf lngValueGreater = lngColumnsDataSource Then
                    .Vertical.MinScaleType = xlSparkScaleCustom
                    .Vertical.CustomMinScaleValue = 0
                Else
                    .Vertical.MaxScaleType = xlSparkScaleSingle
                End If
                    .Horizontal.Axis.Visible = blnVisHorizontalAxis
                    .Horizontal.Axis.Color.Color = lngColorHorizontalAxis
            End With
        Next sg

ErrHandler:
    If Err.Number > 0 Then _
        MsgBox Err.Description, vbMsgBoxHelpButton, "Format sparkline axes", Err.HelpFile, Err.HelpContext
        Err.Clear

End Sub

SparklinesFinal2

The Main Sub()

Here is the main Sub() that calls all other Subs() and Functions():

Option Explicit

Sub CreateSparkLines()

    'Declare objects
        Dim wb As Workbook
        Dim ws As Worksheet
        Dim sh As Worksheet
        Dim wsSparklineData As Worksheet
        Dim slg As SparklineGroup
        Dim rngSparkLineSource As Range
        Dim rngSparkLineDestination As Range
        Dim lastcell As Range
        Dim firstcell As Range
        Dim rngData As Range

    'Declare variables
        Dim lngSparkLineColumn As Long
        Dim lngSparkLineFirstRow As Long
        Dim lngSparkLineLastRow As Long
        Dim RowHeader As Long
        Dim lngRowsSource As Long
        Dim lngColsSource As Long
        Dim lngRowFirstSource As Long
        Dim lngColFirstSource As Long
        Dim i As Long
        Dim j As Long

    'Declare constants
        Const lngTARGET As Long = 98
        Const lngTargetAxis As Long = 0

    'Excel environment
        With Application
            .DisplayAlerts = False
        End With

    'Initialize objects and variables
        Set wb = ThisWorkbook
        Set ws = wb.Worksheets(1)

    'If any previous Sparkline Groups - delete them
        Call DeleteSparklines(ws:=ws)

    'Create a Range Object as the source for the Sparkline Group
        On Error Resume Next
        Set lastcell = GetLastCell(ws:=ws, _
                                   rngBegin:=ws.Cells(1, 1))

        If Not lastcell Is Nothing Then
            Set firstcell = GetFirstCell(ws:=ws, _
                                         rngBegin:=lastcell, _
                                         IncludeLabels:=xlNo)

            Set rngSparkLineSource = ws.Range(firstcell, lastcell)
        Else
            MsgBox "No data exists on the selected sheet"
            Err.Raise 513
        End If

    'Create a Range Object as the destination for the Sparkline Group
        lngSparkLineColumn = lastcell.Column + 1
        lngSparkLineLastRow = lastcell.Row
        lngSparkLineFirstRow = firstcell.Row
        With ws
            Set rngSparkLineDestination = .Range(.Cells(lngSparkLineFirstRow, lngSparkLineColumn), _
                                                 .Cells(lngSparkLineLastRow, lngSparkLineColumn))
         End With

    'Add header
        RowHeader = rngSparkLineDestination.Row - 1
        ws.Cells(RowHeader, lngSparkLineColumn).Value = "Trend"

    'Check if a worksheet named "SparklineData" already exists, if it does, delete it
        With wb
            For Each sh In .Worksheets
                If sh.Name = "SparklineData" Then sh.Delete
            Next sh
        End With

    'Add a worksheet for horizontal axis value calculations
        Call AddWorksheet(wb:=wb, _
                          strSheetName:="SparklineData")
        Set wsSparklineData = wb.Worksheets("SparklineData")

    'Create a Range on the Sparkline Data Worksheet
    'The Range should be the same size as the Source Data Range
        With rngSparkLineSource
            lngRowFirstSource = .Row
            lngColFirstSource = .Column
            lngRowsSource = .Rows.Count
            lngColsSource = .Columns.Count
        End With

        With wsSparklineData
            Set rngData = .Cells(lngRowFirstSource, lngColFirstSource)
            Set rngData = rngData.Resize(lngRowsSource, lngColsSource)
        End With

    'Add a formula to the Data Range to determine the difference between Target and Actual
        For j = 1 To lngColsSource
            For i = 1 To lngRowsSource
                rngData.Cells(i, j).Value = rngSparkLineSource.Cells(i, j).Value - lngTARGET
            Next i
        Next j

    'Add SparkLine Group
        Set slg = GetSparkLineGroup(rngSparkLinePlacement:=rngSparkLineDestination, _
                                    rngSparkLineSourceData:=rngData)

    'Format SparkLine Group
        Call FormatSparkLineGroup(slg:=slg, _
                                  lngColorLine:=RGB(128, 128, 128), _
                                  lngColorHighpoint:=RGB(0, 0, 0), _
                                  lngColorLowpoint:=RGB(255, 0, 0), _
                                  lngColorLastPoint:=RGB(0, 0, 0))

    'Format SparkLine Group Axes
        Call FormatSparklineAxes(ws:=wsSparklineData, _
                                 rngSparkLineGroup:=rngSparkLineDestination, _
                                 rngSparkLineSourceData:=rngData, _
                                 lngValueForComparison:=lngTargetAxis, _
                                 lngColorHorizontalAxis:=RGB(217, 217, 217))

    'Return focus to the report
        ws.Activate

ErrHandler:
    If Err.Number > 0 Then _
        MsgBox Err.Description, vbMsgBoxHelpButton, "Create Sparkline Group", Err.HelpFile, Err.HelpContext
        Err.Clear

    'Tidy up
        Set lastcell = Nothing
        Set firstcell = Nothing
        Set rngSparkLineSource = Nothing
        Set rngSparkLineDestination = Nothing
        Set slg = Nothing
        Set ws = Nothing
        Set wsSparklineData = Nothing
        Set wb = Nothing

        With Application
            .DisplayAlerts = True
        End With

End Sub

Excel Sparkline Improvements Are Needed

I like sparklines, they are excellent in dashboards when screen real estate is a premium. They are also excellent for exploratory data analysis. But there is room for improvement:

  • Horizontal Axis Range I would like the reference line to have a minimum and maximum range option. For example, for purposes of this post, I used a target value of 98 and a thin grey line was plotted for each sparkline based on the actual values for each data source row. But many times, we would like to view actual QA values against a scale, say 97-98 for example.
  • Spark Markers More options are needed for formatting Spark Markers for beginning, ending, high and low data points. We need to be able to use different shapes and sizes. In the current implementation, the Spark Markers are a bit hard to visualize.

Downloads

You may download the Excel Workbook and/or the code modules (.bas files) from OneDrive.

DownloadSparklines

  • M_CreateSparklines.bas
  • M_FormatSparklineAxes.bas
  • M_FormatSparklines.bas
  • M_RangeObject.bas
  • M_SparklinesAdd,bas
  • M_SparklinesDelete.bas
  • M_Worksheet.bas

Additional Resources – Sparklines

Tidy Up

This post was about using VBA to:

  • Dynamically determine a data range on a worksheet
  • Add a Sparkline Group to the next available column
  • Format the Sparkline Group for line and Spark Points
  • Add the appropriate Axis to each Sparkline Group to be used as a reference to compare actual values to target values

In my next post on Sparklines, I will look at how we might use Sparklines with Pivot Tables…stay tuned.

, , , , ,

LawnMower_2

Ahhh, mowing the lawn. Going to William’s 66 to buy some fuel. The smell of the gas, the fresh cut grass, fighting the fly-wheel, trying to get perfectly straight lines, rushing to beat the encroaching summer storm, getting a little too close to mom’s peonies – oops!

I traded a mix of Bluegrass, Rye and Fescue of the Midwest a long time ago for the rusty reddish brown that dominates the landscape of the American Southwest. Still, at times, it is great to remember simpler days.

Today’s post, however, is not about how to maintain a 4-Cycle Briggs & Stratton engine. Rather, it is about how to push reporting to Excel.

The Debate

Push to Excel or Pull to Excel? I go back and forth. For me, it depends on my end in mind. If I am completing a corporate model/template – I am more likely to pull data into Excel from other Excel workbooks or various databases. However, if I am creating reports – especially ad hoc – then pushing to Excel might make more sense. Let’s take a look.

Is Excel Running Or Create A New Instance Of Excel

The first thing I want to do, is determine if Excel is running. If Excel is running, use the current instance of Excel, otherwise, create a new instance of Excel.

Option Explicit

Public Function GetXlApp() As Excel.Application

    'Declare objects
        Dim App As Excel.Application

    'Check if Excel is running
        On Error Resume Next
        Set App = GetObject(, "Excel.Application")
        On Error GoTo 0

    'Create Excel if it is not already running
        If App Is Nothing Then
            Set App = CreateObject("Excel.Application")
        End If

    'Pass object to function
        Set GetXlApp = App

    'Tidy up
        Set App = Nothing

End Function

Create Workbook

Now that I have an instance of Excel, I need to add a new Workbook and Worksheet to the instance of Excel

    'Add workbook object
        Set xlBook = xlApp.Workbooks.Add

    'Create worksheet object
        Set xlSheet = xlBook.Worksheets(1)

Excel New Instance

So far, I have created an instance of Excel and added a Workbook and Worksheet to that instance.

Transfer Data From Source To Destination

Now that I have a new instance of Excel and a workbook and worksheet in that instance, I can transfer the data from my source workbook to he new workbook

    'Get rows and columns of region
        With rngCurrent
            rngRows = .Rows.Count
            rngCols = .Columns.Count
        End With

    'Resize destination range
        With xlSheet
            Set xlRange = .Range("A1")
            Set xlRange = xlRange.Resize(rngRows, rngCols)
        End With

    'Transfer range values
        xlRange.Value = rngCurrent.Value

Excel New Instance_2

The data has been transferred from the source workbook to the new workbook. Note how I use rngNew.value = rngOld.value so I do not rely on copy/paste using the Windows Clipboard.

Add A ListObject To The New Range

I’m a huge fan of ListObject Objects (a.k.a. Excel Tables) Are you? Why or why not? Let’s add one to the new workbook to the range of data just transferred.

    'Add a listobject
        Set xlListObject = GetListObject(ws:=xlSheet)

Option Explicit

Public Function GetListObject(ws As Worksheet)

    'Declare objects
        Dim rng As Range
        Dim C As Range
        Dim lo As ListObject

    'Error handler
        On Error GoTo ErrHandler

    'Create range object
        Set rng = ws.UsedRange
        Set C = rng.Cells(1, 1)

    'Add listobject
        Set lo = ws.ListObjects.Add( _
                        SourceType:=xlSrcRange, _
                        Source:=rng, _
                        Destination:=C)

    'Pass the object to the function
        Set GetListObject = lo

ErrHandler:
    If Err.Number > 0 Then _
        MsgBox Err.Description, vbMsgBoxHelpButton, "Get ListObject", Err.HelpFile, Err.HelpContext

    'Tidy up
        Set lo = Nothing
        Set C = Nothing
        Set rng = Nothing

End Function

Excel New Instance_3
A ListObject Object (Excel Table) has been added, I chose to place it exactly where the Range existed previously, I could have put it anywhere. However, since the Range Object and the ListObject Object contain the same data, why keep both? I now have a ListObject which will automatically expand in case someone decides to add additional information after the data was pushed from an external data source.

Add a Pivot Cache

To add a Pivot Table, I need a Pivot Cache. I’ll use the Excel Table as the data source for the Pivot Cache.

    'Add a pivot cache
        Set xlPivotCache = GetPivotCache(wb:=xlBook, _
                                         lo:=xlListObject)

Public Function GetPivotCache(wb As Workbook, _
                              lo As ListObject)

    'Declare Objects
        Dim pc As PivotCache

    'Declare variables
        Dim strPivotCacheSource As String

    'Error handler
        On Error GoTo ErrHandler

    'Pivot cache source
        strPivotCacheSource = lo.Parent.Name & "!" & _
                                lo.Range.Address(ReferenceStyle:=xlR1C1)

    'Create pivot cache
        Set pc = wb.PivotCaches.Create( _
                        SourceType:=xlDatabase, _
                        SourceData:=strPivotCacheSource)

    'Pass object to function
        Set GetPivotCache = pc

ErrHandler:
    If Err.Number > 0 Then _
        MsgBox Err.Description, vbMsgBoxHelpButton, "Get pivot cache", Err.HelpFile, Err.HelpContext

    'Tidy up
        Set pc = Nothing

End Function

Add A Worksheet For The Pivot Table Report

Now that I have a Pivot Cache, I need to add a Worksheet for the Pivot Table Report

    'Add a sheet for the pivot table
        Set xlSheetReport = AddWorksheet(wb:=xlBook, _
                                         strSheetName:="rpt")

Public Function AddWorksheet(wb As Workbook, _
                             strSheetName As String) As Worksheet

    'Declare variables
        Dim ws As Worksheet
        Dim strMySheetName As String

    'Error handler
        On Error GoTo ErrHandler

    'Add worksheet
        With wb
            Set ws = .Sheets.Add(After:=.Sheets(wb.Sheets.Count))
            ws.Name = strSheetName
        End With

    'Pass object to function
        Set AddWorksheet = ws

ErrHandler:
    If Err.Number > 0 Then _
        MsgBox Err.Description, vbMsgBoxHelpButton, "Add a worksheet", Err.HelpFile, Err.HelpContext

    'Tidy up
        Set ws = Nothing

End Function

Excel New Instance_4
I now have a new Worksheet to hold the Pivot Table.

Add a Pivot Table

Now that I have a new Worksheet, I can add a Pivot Table

    'Add a pivot table
        Set xlPivotTable = GetPivotTable(pc:=xlPivotCache, _
                                         ws:=xlSheetReport, _
                                         strPivotTableName:="PivotTable1")

Public Function GetPivotTable(pc As PivotCache, _
                              ws As Worksheet, _
                              strPivotTableName As String, _
                              Optional ByVal lngRowPlacement As Long = 3, _
                              Optional ByVal lngColPlacement As Long = 3)

    'Declare Objects
        Dim pt As PivotTable
        Dim rng As Range

    'Declare variables
        Dim strPivotPlacement As String

    'Error handler
        On Error GoTo ErrHandler

    'Create range
        Set rng = ws.Cells(lngRowPlacement, lngColPlacement)

    'Pivot table placement
        strPivotPlacement = ws.Name & "!" & _
                            rng.Address(ReferenceStyle:=xlR1C1)

    'Create pivot table
        Set pt = pc.CreatePivotTable( _
                    TableDestination:=strPivotPlacement, _
                    TableName:=strPivotTableName)

    'Pass object to function
        Set GetPivotTable = pt

ErrHandler:
    If Err.Number > 0 Then _
        MsgBox Err.Description, vbMsgBoxHelpButton, "Get pivot table", Err.HelpFile, Err.HelpContext

    'Tidy up
        Set rng = Nothing
        Set pt = Nothing

End Function

Excel New Instance_5
Now that I have a Pivot Table, I can add Pivot Fields.

Add Pivot Fields To Pivot Table

Now that I have a Pivot Table, I need to specify which fields to use from the Excel Table and their Orientation and Order in the Pivot Table:

Private Sub AddFieldsToPivot(pt As PivotTable)

    'Error handler
        On Error GoTo ErrHandler

    'Add fields to pivot table
        With pt

            'Row fields
                .PivotFields("Region").Orientation = xlRowField
                .PivotFields("Region").Position = 1

                .PivotFields("Reps").Orientation = xlRowField
                .PivotFields("Reps").Position = 2

            'Column fields
                .PivotFields("TrxDate").Orientation = xlColumnField
                .PivotFields("TrxDate").Position = 1

            'Value fields
                .AddDataField .PivotFields("Score"), _
                    Caption:="Avgerage of Score", _
                    Function:=xlAverage
        End With

ErrHandler:
    If Err.Number > 0 Then _
        MsgBox Err.Description, vbMsgBoxHelpButton, "Get pivot table fields", Err.HelpFile, Err.HelpContext

End Sub

Excel New Instance_7

Group Dates By Month

Notice that the Pivot Table currently displays each day in a Column Field. I would prefer to group the dates based on the month. I can achieve this by using the Group Method of the Range Object. So first I will need to find the Range to group.

Get A Range From A Pivot Table

I need to get the first Cell in the PivotField “TrxDate” DataRange, so I’ll use the Pivot Item DataRange.


 

Read more on various ranges within a pivot table and their special VBA range names on Jon Peltier’s site

 


 

    'Get pivot table range to group
        Set xlPivotTableRange = GetPivotTableRange(pt:=xlPivotTable, _
                                                   strRangeType:="PivotItemDataRange", _
                                                   strPivotField:="TrxDate")

Public Function GetPivotTableRange(pt As PivotTable, _
                                   strRangeType As String, _
                                   Optional ByVal strPivotField As String = vbNullString) As Range

    'Pivot field Range type documentation:
    'http://peltiertech.com/referencing-pivot-table-ranges-in-vba/                  <-Jon Peltier

    'String range types:
        'PivotItemDataRange

    'Declare objects
        Dim rng As Range

    'Error handler
        On Error GoTo ErrHandler

    'Create pivot table range
        Select Case strRangeType
            Case "PivotItemDataRange"
                Set rng = pt.PivotFields(strPivotField).DataRange.Cells(1, 1)
            Case Else
                MsgBox "That is not an option"
                Exit Function
        End Select

    'Pass object to function
        Set GetPivotTableRange = rng

ErrHandler:
    If Err.Number > 0 Then _
        MsgBox Err.Description, vbMsgBoxHelpButton, "Get pivot table range", Err.HelpFile, Err.HelpContext

    'Tidy up
        Set rng = Nothing

End Function

Note that I set the rng object to just the first cell of the Range actually returned by the DataRange. Also, note that the Select Case statement is only the beginning of the function that handles one simple case of a special VBA range name. I will revisit this function later and update it with all of the special VBA range names of a Pivot Table as Jon documents on his site.

Group Pivot Table Dates

Now that I have the first cell of the DataRange, I am ready to group the range. Recall, I want to group dates by month. One of the optional parameters of the Group Method is Periods; which is an array of Boolean values that specify the period for the group.


 

Read more on the Group Method of the Range Object here

 


 

    'Group pivot table dates
        Periods = Array(False, False, False, False, True, False, False)
        Call GroupRange(rng:=xlPivotTableRange, _
                        varrPeriods:=Periods)

Note that I set the 5th element of the Array to “True”. This specifies that the grouping should be by months as per the documentation on MSDN. Here is the Sub() that I am calling:

Public Sub GroupRange(rng As Range, _
                      varrPeriods() As Variant)

    '=============================================================================
    'Uses the Group Method of the Range Object
    'Only works if Range Object is single cell in PivotTable field’s data range
    'https://msdn.microsoft.com/EN-US/library/office/ff839808.aspx
    'Group(Start, End, By, Periods)

    'Array element   Period
    '----------------------
        '1          Seconds
        '2          Minutes
        '3          Hours
        '4          Days
        '5          Months
        '6          Quarters
        '7          Years

    '==============================================================================

    'Declare objects
        Dim C As Range

    'Error handler
        On Error GoTo ErrHandler

    'Get first cell of range
        Set C = rng.Cells(1, 1)

    'Group range
        C.Group _
            Periods:=varrPeriods()

ErrHandler:
    If Err.Number > 0 Then _
        MsgBox Err.Description, vbMsgBoxHelpButton, "Group pivot field data range", Err.HelpFile, Err.HelpContext

    'Tidy up
        Set C = Nothing

End Sub

Excel New Instance_8

The individual dates in the Column Fields have been grouped by month and the groups have been collapsed to display just the average score for each Rep for each month.

Format DataFields

The Pivot Table is looking good, next I would like to format the DataFields to only display to the hundredths:

Private Sub FormatPivotField(pt As PivotTable)

    'Declare objects
        Dim pf As PivotField

    'Error handler
        On Error GoTo ErrHandler

    'Format datafields
        With pt
            For Each pf In .DataFields
                pf.NumberFormat = "_(* #,##0.00_);_(* (#,##0.00);_(* ""-""??_);_(@_)"
            Next pf
        End With

ErrHandler:
    If Err.Number > 0 Then _
        MsgBox Err.Description, vbMsgBoxHelpButton, "Format DataFields", Err.HelpFile, Err.HelpContext

End Sub

Excel New Instance_9_DataField Format
That looks better.

Set The Column Widths

Another way to improve readability of the Pivot Table is to set all columns to a consistent width. I can set the ColumnWidth of a Range Object, so I’ll use the Function I created earlier to get a special VBA range from the Pivot Table. This time I want to use the DataBodyRange, so first I’ll modify my function to add the new Range Type. Here if the modified function:

Public Function GetPivotTableRange(pt As PivotTable, _
                                   strRangeType As String, _
                                   Optional ByVal strPivotField As String = vbNullString) As Range

    'Pivot field Range type documentation:
    'http://peltiertech.com/referencing-pivot-table-ranges-in-vba/                  <-Jon Peltier

    'String range types:
        'PivotItemDataRange
        'DataBodyRange

    'Declare objects
        Dim rng As Range

    'Error handler
        On Error GoTo ErrHandler

    'Create pivot table range
        Select Case strRangeType
            Case "PivotItemDataRange"
                Set rng = pt.PivotFields(strPivotField).DataRange.Cells(1, 1)
            Case "DataBodyRange"
                Set rng = pt.DataBodyRange
            Case Else
                MsgBox "That is not an option"
                Exit Function
        End Select

    'Pass object to function
        Set GetPivotTableRange = rng

ErrHandler:
    If Err.Number > 0 Then _
        MsgBox Err.Description, vbMsgBoxHelpButton, "Get pivot table range", Err.HelpFile, Err.HelpContext

    'Tidy up
        Set rng = Nothing

End Function

And here is the Sub{} that calls the function to set the column width:

Public Sub PivotTableRangeColWidth(pt As PivotTable)

    'Declare objects
        Dim rng As Range

    'Error handler
        On Error GoTo ErrHandler

    'Get range oject from pivot table
        Set rng = GetPivotTableRange(pt:=pt, _
                                     strRangeType:="DataBodyRange")

    'Set column width
        rng.ColumnWidth = 15

ErrHandler:
    If Err.Number > 0 Then _
        MsgBox Err.Description, vbMsgBoxHelpButton, "Range Column Width", Err.HelpFile, Err.HelpContext

    'Tidy up
        Set rng = Nothing

End Sub

And the Pivot Table with the DataBodyRange set to a ColumnWidth of 15

Excel New Instance_10_ColumnWidth

There is a lot more I could do to format the final Pivot Table, but this post is already long enough.

The Main Sub()

Here’s the Main Sub() that calls all other Functions() and Subs()

Option Explicit
Sub PushToExcel()

    'Declare objects
        Dim wbCurrent As Workbook
        Dim wsCurrent As Worksheet
        Dim rngCurrent As Range
        Dim rng As Range
        Dim xlPivotTableRange As Range
        Dim xlRange As Range
        Dim xlApp As Object
        Dim xlBook As Object
        Dim xlSheet As Object
        Dim xlSheetReport As Object
        Dim xlListObject As Object
        Dim xlPivotCache As Object
        Dim xlPivotTable As Object

    'Declare variables
        Dim rngRows As Long
        Dim rngCols As Long
        Dim Periods() As Variant

    'Current objects
        Set wbCurrent = ActiveWorkbook
        Set wsCurrent = wbCurrent.ActiveSheet
        Set rngCurrent = wsCurrent.UsedRange

    'Get Excel app
        On Error Resume Next
        Set xlApp = GetXlApp
        If Not xlApp Is Nothing Then
            xlApp.Visible = True
        Else
            MsgBox "The application was not created. Exiting."
            Exit Sub
        End If

    'Add workbook
        Set xlBook = xlApp.Workbooks.Add

    'Create worksheet object
        Set xlSheet = xlBook.Worksheets(1)

    'Get rows and columns of region
        With rngCurrent
            rngRows = .Rows.Count
            rngCols = .Columns.Count
        End With

    'Resize destination range
        With xlSheet
            Set xlRange = .Range("A1")
            Set xlRange = xlRange.Resize(rngRows, rngCols)
        End With

    'Transfer range values
        xlRange.Value = rngCurrent.Value

    'Add a listobject
        Set xlListObject = GetListObject(ws:=xlSheet)

    'Add a pivot cache
        Set xlPivotCache = GetPivotCache(wb:=xlBook, _
                                         lo:=xlListObject)

    'Add a sheet for the pivot table
        Set xlSheetReport = AddWorksheet(wb:=xlBook, _
                                         strSheetName:="rpt")

    'Add a pivot table
        Set xlPivotTable = GetPivotTable(pc:=xlPivotCache, _
                                         ws:=xlSheetReport, _
                                         strPivotTableName:="PivotTable1")

    'Add fields to pivot table
        Call AddFieldsToPivot(pt:=xlPivotTable)

    'Get pivot table range to group
        Set xlPivotTableRange = GetPivotTableRange(pt:=xlPivotTable, _
                                                   strRangeType:="PivotItemDataRange", _
                                                   strPivotField:="TrxDate")

    'Group pivot table dates
        Periods = Array(False, False, False, False, True, False, False)
        Call GroupRange(rng:=xlPivotTableRange, _
                        varrPeriods:=Periods)

    'Format pivot table
        Call FormatPivotField(pt:=xlPivotTable)

    'Set column width pivot table data body
        Call PivotTableRangeColWidth(pt:=xlPivotTable)

    'Tidy up
        'Destroy objects
            Set rngCurrent = Nothing
            Set xlRange = Nothing
            Set xlPivotTableRange = Nothing
            Set xlListObject = Nothing
            Set xlPivotCache = Nothing
            Set xlPivotTable = Nothing
            Set wsCurrent = Nothing
            Set xlSheet = Nothing
            Set xlSheetReport = Nothing
            Set xlBook = Nothing
            Set wbCurrent = Nothing
            Set xlApp = Nothing

End Sub

Homework

There’s more I could do here, but this post is long enough and I wanted to leave some meat on the bone. Additional items to be added:

  • Additional Pivot Tables
  • Charts and/or Pivot Charts
  • Slicer Cache
  • Slicers
  • Worksheet Display Settings
  • Page Setup Settings For Printing

Downloads

You may download the workbook and/or the code modules (.bas files) from OneDrive.

  • PushToExcel_20150516_v1.xlsm
  • M_PushToExcel.bas
  • M_Worksheet.bas
  • M_Public.bas
  • M_Pivot.bas
  • M_ListObjects.bas

Excel New Instance_11_Downloads

Additional Pivot Table Resources – Around The Excel Horn

Some authors of my favorite resources for working with Pivot Tables:

Additional Pivot Table Resources – dataprose.org

Some additional resources for working with Pivot Tables on my blog

, , , , , , , , ,

NameBadgeArgumentFinal

Being the 2nd in a series of posts on “Names” in Excel.

Excel uses several “Names”. In a previous post, I wrote about Named Formulas. Today, I’ll take a look at Named Arguments.

Named Arguments

Named arguments are that descriptive tags you sometimes see in VBA code snippets. They are not required, hence, “sometimes”. Here’s a sample of a few:

NamedArguments1

In the sample snippet, I created a function to get a Cell as a Range Object from the user at run-time using the Application.InputBox Method. The InputBox Method actually has 1 required parameter and 8 optional parameters – I am only using 3 parameters – 1 required and 2 optional.


    Read more on the Application.InputBox Method here


Named Arguments Are Not Required

As I stated previously, Named Arguments are not required. Here is the Function rewritten without the Named Arguments. I also added a bit of error handling in case the user clicks the cancel button of the InputBox:

Public Function GetSelectedRangeNoNmArgs() As Range

    'Declare variables
        Dim rng                         As Range
    
    'Users - select a cell on a worksheet
        On Error Resume Next
        Set rng = Application.InputBox _
                        ("Please Select Range", _
                         "Range Select", _
                         8)
        If rng Is Nothing Then
            Exit Function
        End If
    
    'Pass the name of the worksheet to the function
        Set GetSelectedRangeNoNmArgs = rng
    
    'Tidy up
        Set rng = Nothing

End Function

Do you see the difference (other than the error handling) ? Here is a comparison of just the 4 lines of the InputBox of both snippets:

'No Named Arguments
Application.InputBox _
                        ("Please Select Range", _
                         "Range Select", _
                         8)

'Even worse - yikes!
Application.InputBox _
                        ("Please Select Range", "Range Select", 8)

'Named Arguments - Best!
Application.InputBox _
                        (Prompt:="Please Select Range", _
                         Title:="Range Select", _
                         Type:=8)

That makes the parameter values a bit more clear, doesn’t it?

Here’s A Dumb Reason

One reason given on MSDN for using Named Arguments is that you can change the order of the parameters to the function. Like this:

'Original parameter order
Application.InputBox _
                        (Prompt:="Please Select Range", _
                         Title:="Range Select", _
                         Type:=8)

'Rearranged parameters
Application.InputBox _
                        (Type:=8, _
                         Prompt:="Please Select Range", _
                         Title:="Range Select")

IMHO, that is a load of hooey. I cannot think of a single valuable reason to do that – can you?

The Real Reason

The real reason to use Named Arguments is that it makes things clearer – they are self-documenting. My example here is a little silly, maybe you are very use to the InputBox Method and you know the order of the parameters and can rattle ’em off in your sleep like I rattle off the batting order of the ’72 Cinci Reds.


    Petition to get Pete Rose reinstated to Major League Baseball here. Pete was one of the greatest to ever play the game.


Tidy Up

I’m sure you can find some Internet Breadcrumbs of mine, where I have not always used Named Arguments. My code and style have evolved and continue to evolve over time. I now always use Named Arguments – I encourage you to do the same.

, , , , , , , ,

PeleFinal

Pele was an amazing soccer (futbol) player. I’m more of an American football fan myself – but I cannot deny the art, grace and class with which Pele played futbol. Pele is pictured here executing a bicycle kick against Belgium in 1968. Maybe what sets Pele and other sports stars apart from the rest is they too begin with the end in mind as suggested by Stephen Covey in The Seven Habits of Highly Effective People.

Today’s post, however, is not about futbol or the latest book being touted by business and leadership pundits. It is about the Goal Seek Method of the Range Object of the Excel Object Model.

Goal Seek

Goal2

Here is a sample formula to calculate Net Sales using 4 inputs: Average Check, Operating Days, Population and Participation. As you see displayed from FORMULATEXT() Function, the 4 inputs are simply multiplied together.


    The FORMULATEXT() function is one of the new functions introduced with Excel 2013. Check them all out here


We can use Goal Seek manually from the Ribbon. In Excel 2013:

Goal3

  1. Click on the Data Tab of the Ribbon
  2. Go to the Data Tools Group
  3. Click on What-If Analysis
  4. Click on Goal Seek

Goal4

I launched Goal Seek. I want to know what participation would need to be to achieve Net Sales of $10K?

Goal5

Holding all other inputs constant, I would need to increase participation from 14.32% to 16.83% to get to $10K in Net Sales. All well and good so far. But what if I need to find values for 12 different months? 52 Weeks? Some other Scenario with 100’s of desired outputs? Time for some VBA!

Goal Seek VBA

Goal6

I cannot find the Goal Seek Method listed as a Member of the Range Class in the Object Explorer in the VBA Editor?


  1. Press [Alt]+[F11] to launch the VBA Editor
  2. Once in the Editor, [F2] to launch the Object Explorer


Hmmm….I’ll check documentation on MSDN:


  1. Object model reference (Excel 2013 developer reference)
  2. Object model reference (Excel 2010 developer reference)
  3. Object model reference (Excel 2003 developer reference) – Compiled Help File


I checked the Developer Reference for Excel 2013 and Excel 2010. I could not find anything on Goal Seek. I downloaded the Excel 2003 Developed Reference as a compiled help file and finally found some documentation on the Goal Seek Method.

Goal7

Goal8

Here’s a quick little snippet I wrote. Even though Goal Seek does not show as a Method of the Range Object in Excel 2013, even though the Goal Seek Method is not documented in the Excel Developer Reference for Excel 2013, it will still work with Excel 2013.

This is not the first time I have seen this. I can’t recall what the last Object and Member were.

Goal Seek Method Requirements

For the Goal Seek Method to work, I must provide the following objects and values:

  1. A Range Object (Cell) that contains a formula
  2. A goal value
  3. And the changing Cell as a Range Object

Well, that makes sense, since the Goal Seek Dialog Box prompted me to manually select or enter those items earlier.

From the requirements list, I see that one strategy would be to use a loop with the .Cells() Property of the Worksheet Object as the Range Objects. With the Cells() Property, I need to pass a Row Index and a Column Index through each iteration of the loop.

The Setup…

Goal9

I added 11 months to the existing data and randomized the participation amounts. Now I would like to find what the participation would need to be for each of the 12 months to increase sales an additional $5K each month.

Goal10

Goal Seek Method…Fixed Range

Here is a basic Goal Seek Snippet that could be used with a fixed Range where the Worksheets and Range Objects are known and do not change:

Option Explicit

Sub SetGoal()

'----------------------------------------------------------------------
'Use Goal Seek Method of the Range Object with a dictator application
'----------------------------------------------------------------------
'Author     : Winston Snyder
'Date       : 3/30/2015
'Website    : http://dataprose.org/
'----------------------------------------------------------------------

    'Declare objects
        Dim wb As Workbook
        Dim ws As Worksheet
  
    'Declare constants
        Const lngROW_SEEK As Long = 4
        Const lngROW_GOAL As Long = 10
        Const lngROW_CHANGE As Long = 5
        Const lngCOL_BEGIN As Long = 6
        Const lngCOL_END As Long = 17
    
    'Declare variables
        Dim i As Long
    
    'Initialize
        Set wb = ThisWorkbook
        Set ws = wb.Worksheets("Sheet1")
    
    'Goal Seek
        With ws
            For i = lngCOL_BEGIN To lngCOL_END
                .Cells(lngROW_SEEK, i).GoalSeek _
                    Goal:=.Cells(lngROW_GOAL, i).Value, _
                    ChangingCell:=.Cells(lngROW_CHANGE, i)
            Next i
        End With
    
    'Tidy up
        Set ws = Nothing
        Set wb = Nothing
End Sub

Goal11

My Change Row was Row 5, “Participation”. Participation has been increased to the point needed to drive Net Sales on Row 4 to the target “New Sales” on Row 10.

All well and good, but what if I want to:

  1. Choose a different set of values pre-programmed values for the the Goal?
  2. Choose a different input/driver Row

I will need something a bit more flexible.

Goal Seek Method…Dynamic Options

One way to make the code snippet a bit more flexible, is to use a Type:=8 InputBox. The Type:=8 InputBox allows the user to select a Cell on a Worksheet. I first introduced this concept in this post on the LIKE Operator.


    More on Application.InputBox Method (Excel) here


I’ll create a Function and call it 3 times to prompt the user to select a cell that begins the Range for

  1. The Range that contains the formula that I am seeking a goal for.
  2. The Range that contains the target value
  3. The Range that contains an input that is to be be changed to arrive at the target value
Public Function GetUserCell(strPrompt As String) As Range
 
    'Declare variables
        Dim rng As Range
     
    'Users - select a cell on a worksheet
        Set rng = Application.InputBox( _
                    Prompt:=strPrompt, _
                    Title:="Select a Cell", _
                    Default:=ActiveCell.Address, _
                    Type:=8) 'Range selection
                     
    'Get the parent worksheet of the selected cell
        Set GetUserCell = rng
     
    'Tidy up
        Set rng = Nothing

 End Function

Now I can create a Sub(), call the function 3 times, and load my 5 variables based on the user selections.

The final dynamic Goal Seek Sub():

Option Explicit

Sub SetGoalDynamic()

'----------------------------------------------------------------------
'Use Goal Seek Method of the Range Object allow user to choose cells in range for:
'     The formula to be used in determining a solution
'     The goal value
'     An input cell that will be altered by Goal Seek to arrive at the desired solution
'----------------------------------------------------------------------
'Author     : Winston Snyder
'Date       : 3/30/2015
'Website    : http://dataprose.org/
'----------------------------------------------------------------------

    'Declare objects
        Dim wb As Workbook
        Dim ws As Worksheet
        Dim rngRowSeek As Range
        Dim rngRowGoal As Range
        Dim rngRowChange As Range
  
    'Declare constants
        Const strROW_SEEK As String = "Please select a cell in the row that contains the formula you will use for Goal Seek."
        Const strROW_GOAL As String = "Please select a cell in the row that contains the Goal Value that you are trying to find a solution for."
        Const strROW_CHANGE As String = "Please select a cell in the row that contains an input value for the formula."
    
    'Declare variables
        Dim lngRowSeek As Long
        Dim lngRowGoal As Long
        Dim lngRowChange As Long
        Dim lngColBegin As Long
        Dim lngColEnd As Long
        Dim i As Long
    
    'Initialize
        Set wb = ThisWorkbook
        Set ws = wb.Worksheets("Sheet1")
        
    'Get user inputs
        Set rngRowSeek = GetUserCell(strPrompt:=strROW_SEEK)
        Set rngRowGoal = GetUserCell(strPrompt:=strROW_GOAL)
        Set rngRowChange = GetUserCell(strPrompt:=strROW_CHANGE)
        
    'Get variable values from user inputs
        lngRowSeek = rngRowSeek.Row
        lngRowGoal = rngRowGoal.Row
        lngRowChange = rngRowChange.Row
        lngColBegin = rngRowSeek.End(xlToLeft).Column + 1 'Offset for labels
        lngColEnd = rngRowSeek.End(xlToRight).Column
    
    'Goal Seek
        With ws
            For i = lngColBegin To lngColEnd
                .Cells(lngRowSeek, i).GoalSeek _
                    Goal:=.Cells(lngRowGoal, i).Value, _
                    ChangingCell:=.Cells(lngRowChange, i)
            Next i
        End With
    
    'Tidy up
        Set rngRowSeek = Nothing
        Set rngRowGoal = Nothing
        Set rngRowChange = Nothing
        Set ws = Nothing
        Set wb = Nothing
        
End Sub

Tidy Up

That’s it for today, hopefully something helpful for you in this post. I use Goal Seek a bit when forecasting and budgeting and my supervisor asks me for some options to achieve certain desired targets or we get push back upstream.

How do you use Goal Seek?

Btw, as of today, Monday, March 30,2015, the first NFL Preseason game is only 132 days away. Sunday night, August 9, 2015. Hang in there!

, , , , , , , , , ,

1940MercuryFinal

Here is another 1940 Ford Mercury. I cannot get enough of these cars – simply awesome! I think it is some of the details shown here that were incorporated into the Chrysler 300 that lead to the immense popularity of the Chrysler 300. Hopefully car manufacturers will take note and follow suit with stronger attention to design details.

In my last post, I showed you how to work with Excel Table TableStyles and how to customize them. However, followers of this blog (both of you) know that I’m a VBA guy. Let’s take a look how we might use VBA to work with Excel Table TableStyles.

TableStyles Property

The Workbook Object has a TableStyles Collection so we can work with TableStyles in a Workbook.

Option Explicit

Sub ListTableStyles()

    Dim wb As Workbook
    Dim ts As TableStyle
    Dim i As Long
    
    Set wb = ThisWorkbook
    i = 1
    
    With wb
        For Each ts In .TableStyles
            Debug.Print ts.Name
            i = i + 1
        Next ts
    End With
    
    Debug.Print "Number of TableStyles = ", i
    
    Set wb = Nothing
End Sub

Results (truncated for brevity):

  • TableStyleMedium2
  • PivotStyleLight1
  • SlicerStyleLight1
  • TimeSlicerStyleLight1
  • tsDataProse3
  • Number of TableStyles = 174

That’s interesting. PivotStyles, SlicerStyles and TimeSlicerStyles are part of the TableStlyes Collection as well as TableStyles. That means as soon as we learn how to work with TableStyles, we can apply that knowledge PivotStyles, SlicerStyles and TimeSlicerStyles as well! 4 for the price of 1 – no charge!

However, for today, I’m only interested in Table Styles, so I’ll use the ShowAsAvailableTableStyle Property of the TableStyle Object to limit the Styles returned to only those related to Excel Tables:

ObjectExplorerShowAsAvailableTableStyleFin

Option Explicit

Sub ListTableStyles()

    Dim wb As Workbook
    Dim ts As TableStyle
    Dim i As Long
    
    Set wb = ThisWorkbook
    i = 1
    
    With wb
        For Each ts In .TableStyles
            If ts.ShowAsAvailableTableStyle Then
                Debug.Print ts.Name
                i = i + 1
            End If
            Next ts
    End With
    
    Debug.Print "Number of TableStyles = ", i
    
    Set wb = Nothing
End Sub

Results (truncated for brevity):

  • TableStyleLight1
  • TableStyleMedium1
  • TableStyleDark1
  • tsDataProse
  • Number of TableStyles = 64

Delete Then Add

In my last post on TableStyles, I duplicated an existing TableStyle and saved the duplicate TableStyle with a new name. When adding a TableStyle with VBA, we have to be careful when adding an item to any collection. If the item already exists, we will receive an error message.

First, I’ll just try to add a TableStyle without deleting it beforehand:

Option Explicit

Sub TestAddTableStyle()

    Dim wb As Workbook
    Dim ts As TableStyle
    
    Set wb = ThisWorkbook
    
    With wb
        For Each ts In .TableStyles
            If ts.ShowAsAvailableTableStyle Then
                If ts.Name Like "*Medium*" Then
                    ts.Duplicate ("tsCustom" & ts.Name)
                End If
            End If
        Next ts
    End With
    
    Set wb = Nothing
End Sub

TableStyleError

As you see, since the TableStyle already exists, I receive the “Application-defined error message” and the error message is not very helpful at that. I like to handle adding Objects to Collections by trying to delete them first

I’ll delete the TableStyles I added in my last post. I named each of those Styles “ts…” so I can use use so safely loop through all TableStyles and delete any that begin with ts:

Option Explicit

Sub DeleteTableStyles()

    Dim wb As Workbook
    Dim ts As TableStyle
    
    Set wb = ThisWorkbook
    
    With wb
        For Each ts In .TableStyles
            If ts.ShowAsAvailableTableStyle Then
                If Left(ts.Name, 2) = "ts" Then
                    ts.Delete
                End If
            End If
        Next ts
    End With
    
    Set wb = Nothing
End Sub

Now when I check all TableStyles, I only have 61 whereas before I had 64. Now, I can modify the code to duplicate an existing style and save it with a new name safely as I have the code to delete the Style first.

Recall from my first post on TableStyles, I prefer the “Medium” Styles as opposed to the Light or Dark Styles. So I will only concern myself with making copies of the Medium Styles:

Option Explicit

Sub TestElements()

    Dim wb As Workbook
    Dim ts As TableStyle
    
    Set wb = ThisWorkbook
    
    With wb
        For Each ts In .TableStyles
            If Left(ts.Name, 2) = "ts" Then
                ts.Delete
            End If
        Next ts
            
        For Each ts In .TableStyles
            If ts.Name Like "*Medium*" Then
                ts.Duplicate ("tsCustom" & ts.Name)
            End If
        Next ts
    End With
    
    Set wb = Nothing
End Sub

Now when I list out the TableStyles I find that I added 29 Custom Table Styles, far more than I really need:

Option Explicit

Sub ListTableStyles()

    Dim wb As Workbook
    Dim ts As TableStyle
    Dim i As Long
    
    Set wb = ThisWorkbook
    i = 1
    
    With wb
        For Each ts In .TableStyles
            If ts.ShowAsAvailableTableStyle Then
                If ts.Name Like "*Custom*" Then
                    Debug.Print ts.Name
                    i = i + 1
                End If
            End If
        Next ts
    End With
    
    Debug.Print "Number of TableStyles = ", i
    
    Set wb = Nothing
End Sub

I’ll try to modify the code a bit o just add the Custom Styles I like. I like Medium TableStyles 2-7, so I should only add 6 Custom TableStyles.

Option Explicit

Sub AddCustomTableStyles()

    Dim wb As Workbook
    Dim ts As TableStyle
    
    Set wb = ThisWorkbook
    
    With wb
    
        'If custom table style already exists - delete it
            For Each ts In .TableStyles
                If Left(ts.Name, 2) = "ts" Then
                    ts.Delete
                End If
            Next ts
        
        'Add custom table styles
            For Each ts In .TableStyles
                If ts.ShowAsAvailableTableStyle Then
                    If ts.Name Like "*Medium*" Then
                        If CLng(Right(ts.Name, 1)) >= 2 And _
                           CLng(Right(ts.Name, 1)) <= 7 Then
                           ts.Duplicate ("tsCustom" & ts.Name)
                        End If
                    End If
                End If
            Next ts
    End With
    
    Set wb = Nothing
End Sub

Getting closer, that only added 18 Custom TableStyles. One more try:

Option Explicit

Sub AddCustomTableStyles()

    Dim wb As Workbook
    Dim ts As TableStyle
    
    Set wb = ThisWorkbook
    
    With wb
    
        'If custom table style already exists - delete it
            For Each ts In .TableStyles
                If Left(ts.Name, 2) = "ts" Then
                    ts.Delete
                End If
            Next ts
        
        'Add custom table styles
            For Each ts In .TableStyles
                If ts.ShowAsAvailableTableStyle Then
                    If ts.Name Like "*Medium*" Then
                        If Not IsNumeric(Right(ts.Name, 2)) Then
                            If CLng(Right(ts.Name, 1)) >= 2 And _
                               CLng(Right(ts.Name, 1)) <= 7 Then
                               ts.Duplicate ("tsCustom" & ts.Name)
                            End If
                        End If
                    End If
                End If
            Next ts
    End With
    
    Set wb = Nothing
End Sub

Results:

  • tsCustomTableStyleMedium2
  • tsCustomTableStyleMedium3
  • tsCustomTableStyleMedium4
  • tsCustomTableStyleMedium5
  • tsCustomTableStyleMedium6
  • tsCustomTableStyleMedium7
  • Number of TableStyles = 6

http://dataprose.org/wp-admin/admin.php?page=wp101

Great! That’s what I was looking for. Now I need to modify the assorted elements of the Custom Table Styles as I did manually in my previous post.

Table Style Elements

There are 45 different Elements in the xlTableStyleElements Enumeration. Check them out here

Recall from my post on manually customizing TableStyles, I duplicated an existing Style and only modified:

  • the Inside Vertical Border of the Header Row
  • the Inside Vertical Border of the First Row Stripe
Option Explicit

Sub CustomizeTableStyleElements()

    Dim wb As Workbook
    Dim ts As TableStyle
    Dim lngGrey As Long

    Set wb = ThisWorkbook
    lngGrey = RGB(217, 217, 217)
    
    With wb
        For Each ts In .TableStyles
            If ts.Name Like "*Custom*" Then
                'Customize header row
                    With ts.TableStyleElements(xlHeaderRow).Borders(xlInsideVertical)
                       .Color = vbWhite
                       .Weight = xlThin
                    End With
                
                'Customize data body range
                    With ts.TableStyleElements(xlRowStripe1).Borders(xlInsideVertical)
                       .Color = lngGrey
                       .Weight = xlThin
                    End With
            End If
        Next ts
    End With
    
    Set wb = Nothing
End Sub

I used the enumeration of the Table Style Elements to locate the names of the elements I wanted to customize and then set the properties according to my preferences.

I’ll check the results back in the Excel Workbook:

CustomTableStylesGroup


CustomTableStylesElementHeaderRowFinal


CustomTableStylesElementFirstRowStripeFinal


CustomTableStylesVBAAppliedFinal

We can also loop through the Excel Tables in the Workbook to apply the new Custom Style:

Option Explicit

Sub ApplyCustomStyle()

    Dim wb As Workbook
    Dim ws As Worksheet
    Dim lo As ListObject
    Dim ts As TableStyle
    Dim strTableStyle As String

    Set wb = ThisWorkbook
 
    'Assign a workbook default to the string variable
        With wb
            For Each ts In .TableStyles
                If ts.ShowAsAvailableTableStyle Then
                    If ts.Name Like "*Medium*" Then
                        strTableStyle = ts.Name
                        Exit For
                    End If
                End If
            Next ts
        End With
    
    'If a cutom style exists, overwrite the value of the string variable
        With wb
            For Each ts In .TableStyles
                If ts.ShowAsAvailableTableStyle Then
                    If ts.Name Like "tsCustom*" Then
                        strTableStyle = ts.Name
                        Exit For
                    End If
                End If
            Next ts
        End With
        
    'Assign the TableStyle to each Table in the Workbook
        With wb
            For Each ws In .Worksheets
                For Each lo In ws.ListObjects
                    lo.TableStyle = strTableStyle
                Next lo
            Next ws
        End With

    Set wb = Nothing
End Sub

Tidy up

That’s it for today. Hopefully you found something here about using the LIKE Operator, the CLNG Function, the RGB Function and the Exit Statement as well as working with TableStyles and TableStyleElements.

Other Excel Table Articles At dataprose.org

Other Excel Table Articles Around The Horn

, , , , , , , , , , ,

CharlieBrownFinal

Here in the States – All Hallows’ Eve (Halloween) is quickly approaching. One of my favorite times of the year with leaves changing color, daylight getting shorter, a crispness in the air, football season is in full swing, and the Fall Classic (Major League Baseball) begins in a few weeks.

All Hallows’ Eve is a time for hobgobblery and apparitions of all sorts as with Charlie Brown and the Peanuts gang pictured here. Excel too has a ghost. In this post I’ll take a look at one and how we might put it to rest.

Worksheet UsedRange Property

The Worksheet Object has a UsedRange Property. Normally, we should be able to use this property so that we can quickly identify the entire UsedRange on the Worksheet without having to jump through a lot of hoops.

UsedRange1

Here is a Range of Cells with some data. We can quickly find the address of the UsedRange on the Worksheet:

Option Explicit

Sub GetUsedRangeAddress()

    Dim wb As Workbook
    Dim ws As Worksheet
    Dim rng As Range
    
    Set wb = ThisWorkbook
    Set ws = wb.ActiveSheet
    Set rng = ws.UsedRange
    
    Debug.Print rng.Address
    
    Set rng = Nothing
    Set ws = Nothing
    Set wb = Nothing
End Sub

Output:

$A$1:$J$10

Great – that is what I expected. But what happens if I delete some data?

UsedRange…False/Positive

A false positive occurs when we test for data and Excel tells us that there is data when in fact there is not.

UsedRange2

Here is the same data as before, but I deleted the data from Columns $H:$J. Now I’ll respin the code and check results:

$A$1:$J$10

Hmmm…same results – that is not good – therefore:


    we cannot rely on the UsedRange Property of the Worksheet Object. We need a better way to find the TRUE used range of data


The Last Used Cell

We can use the Find Method of the Range Object to get the last cell on the Worksheet that contains any data:

Sub GetLastCell()

    Dim wb As Workbook
    Dim ws As Worksheet
    Dim rng As Range
    
    Set wb = ThisWorkbook
    Set ws = wb.ActiveSheet

    With ws
        Set rng = .Cells.Find(What:="*", _
                              After:=.Cells(1, 1), _
                              LookIn:=xlFormulas, _
                              LookAt:=xlPart, _
                              SearchOrder:=xlByRows, _
                              SearchDirection:=xlPrevious, _
                              MatchCase:=False)
    End With
                                
    Debug.Print rng.Address
    
    Set rng = Nothing
    Set ws = Nothing
    Set wb = Nothing
End Sub

Output:

$G$10

Great – that’s what I was looking for. What happens if there is nothing on the Worksheet? I moved to a new worksheet in the Workbook and tried the code again:

UsedRangeError1

That’s not good. I need to revise my code a bit to handle cases where there is no data on the worksheet:

Sub GetLastCellHandleNoData()

    Dim wb As Workbook
    Dim ws As Worksheet
    Dim rng As Range
    
    Set wb = ThisWorkbook
    Set ws = wb.ActiveSheet

    With ws
        Set rng = .Cells.Find(What:="*", _
                              After:=.Cells(1, 1), _
                              LookIn:=xlFormulas, _
                              LookAt:=xlPart, _
                              SearchOrder:=xlByRows, _
                              SearchDirection:=xlPrevious, _
                              MatchCase:=False)
    End With
    
    If Not rng Is Nothing Then
        Debug.Print rng.Address
    Else
        Debug.Print "There is no data on worksheet ", ws.Name
    End If
    
    Set rng = Nothing
    Set ws = Nothing
    Set wb = Nothing
End Sub

I tested the code on a Worksheet with data in $A$1:$G$10. Results:

$G$10

Great – that’s what I expected.

Next I tested on a Worksheet with no data. Results:

There is no data on worksheet Sheet2

Great – that’s what I expected.


    I tested the code on a wide variety of scenarios for data placement on the Worksheet. It appears to work for any possible scenario. Please let me know if your tests return unexpected results or errors.


I now have the last used Cell on the Worksheet. Now I need the first used Cell on the Worksheet.

The First Used Cell

For the first used Cell, I tested Cell(1,1) first and then the remainder of the Worksheet. When data was in Cell $A$1, beginning at $A$1 and searching was returning the next Cell address.

Sub GetFirstCell()

    Dim wb As Workbook
    Dim ws As Worksheet
    Dim rng As Range
    
    Set wb = ThisWorkbook
    Set ws = wb.ActiveSheet

    With ws
        If Not IsEmpty(ws.Cells(1, 1)) Then
            Set rng = ws.Cells(1, 1)
        Else
            Set rng = .Cells.Find(What:="*", _
                                  After:=.Cells(1, 1), _
                                  LookIn:=xlFormulas, _
                                  LookAt:=xlPart, _
                                  SearchOrder:=xlByRows, _
                                  SearchDirection:=xlNext, _
                                  MatchCase:=False)
        End If
    End With
    
    If Not rng Is Nothing Then
        Debug.Print rng.Address
    Else
        Debug.Print "There is no data on worksheet ", ws.Name
    End If
    
    Set rng = Nothing
    Set ws = Nothing
    Set wb = Nothing
End Sub

Final Functions() and Subs()

The stuff above is fine, but it would be cool if we could develop a function to return the True Used Range. I developed a few Functions() and Subs() to that end.

Function..GetUserSelectedCell

I would like to prompt the user to select a cell and test if there is any data on the worksheets the cell is located on. This makes my code more efficient before I continue processing.

Here I am using the InputBox of the Application Object with Type 8 parameter to allow the user to select a cell for the InputBox. More on the Application.InputBox Method (Excel).

Public Function GetUserSelectedCell(strPrompt As String, _
                                    strTitle As String) As Range

    ''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''
    'GetUserSelectedCell
    'Returns a Range Object based on Cell user selects
    '
    'Parameters        :
    'strPrompt         :    A string variable.
    '                  :    Provide a question or statement to the user to take some action.
    'strTitle          :    A string variable.
    '                  :    Provide a title for the InputBox.
    ''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''

     'Declare variables
        Dim rng                         As Range
        
    'Users - select a cell on a worksheet
        On Error Resume Next
        Set rng = Application.InputBox( _
                        Prompt:=strPrompt, _
                        Title:=strTitle, _
                        Default:=ActiveCell.Address, _
                        Type:=8) 'Range selection

        On Error GoTo 0
        
    'Activate the worksheet
        On Error Resume Next
        rng.Parent.Activate
        
    'Pass object to function
        Set GetUserSelectedCell = rng
     
    'Tidy up
        If Not rng Is Nothing Then Set rng = Nothing

 End Function

And here is how I call the Function in the final Sub()

    'Prompt user to select a cell on a worksheet
        Set rngUserCell = GetUserSelectedCell(strPrompt:="Please select a cell on a worksheet.", _
                                              strTitle:="Get Cell Selection From User")

Function..What if the user clicked cancel?

The user may choose to cancel at the InputBox, so we need to handle that possibility. In this Function() I am using a MsgBox to ask the user if they wish to try again. More on the MsgBox Function.

Public Function GetUserMessageResponse(strPrompt As String, _
                                       strTitle As String, _
                                       lngButtons As Long) As Long

    ''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''
    'GetUserMessageResponse
    'Returns a value as a Long DataType
    '
    'Parameters        :
    'strPrompt         :    Required. A string datatype.
    '                  :    Provide a question or statement to the user to take some action.
    'strTitle          :    A string datatype.
    '                  :    Provide a title for the InputBox.
    'lngButtons        :    A long datatype
    '                  :    Use one of the vba button type enumerations
    '                  :    vbOKOnly            0   OK button only                      <-Default value
    '                  :    vbOKCancel          1   OK and Cancel buttons
    '                  :    vbAbortRetryIgnore  2   Abort, Retry, and Ignore buttons
    '                  :    vbYesNoCancel       3   Yes, No, and Cancel buttons
    '                  :    vbYesNo             4   Yes and No buttons
    '                  :    vbRetryCancel       5   Retry and Cancel buttons
    'Information       :    The Message Box returns 1 of 7 values:
    '                  :    vbOK        1
    '                  :    vbCancel    2
    '                  :    vbAbort     3
    '                  :    vbRetry     4
    '                  :    vbIgnore    5
    '                  :    vbYes       6
    '                  :    vbNo        7
    '
    ''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''

    'Declare variables
        Dim MsgBoxValue             As Long
     
    'Users - select a cell on a worksheet
        MsgBoxValue = MsgBox( _
                        Prompt:=strPrompt, _
                        Buttons:=lngButtons, _
                        Title:=strTitle)
                        
    'Handle user actions
        If MsgBoxValue <> vbYes Then
            MsgBoxValue = vbCancel
        End If
         
    'Pass value to function
        GetUserMessageResponse = MsgBoxValue

 End Function

Function..TestForData

Now that I have a Cell on a Worksheet, I need to test to see if there is any data on the Worksheet. In the Function below, I first check Cell(1,1) for any data, if that does not contain any data, then I check the rest of the worksheet.

Here I am using the Find Method of the Range Object to search for anything on the Worksheet. More on the Range.Find Method (Excel).

Public Function TestForData(ws As Worksheet) As Boolean

    ''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''
    'TestForData
    'Returns a boolean datatype
    'Checks to see that data exists in at least 1 Cell on a Worksheet
    '
    'Parameters        :
    'ws                :   Required, A Woksheet Object.
    '
    '''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''

    'Declare variables
        Dim rng As Range
    
    'Initialize values
        TestForData = False
        
    'Check the worsheet for data
        On Error Resume Next
        If Not IsEmpty(ws.Cells(1, 1)) Then
            Set rng = ws.Cells(1, 1)
        Else
            With ws
                Set rng = .Cells.Find(What:="*", _
                                      After:=.Cells(1, 1), _
                                      LookIn:=xlFormulas, _
                                      LookAt:=xlPart, _
                                      SearchOrder:=xlByRows, _
                                      SearchDirection:=xlPrevious, _
                                      MatchCase:=False)
            End With
        End If
    
    'Update function value if the worksheet contains data
        If Not rng Is Nothing Then TestForData = True
  
    'Tidy up
        Set rng = Nothing

End Function

And here is how I call the Function in the final Sub()

    'Check if the worksheet has any data
        blnFlag = TestForData(ws:=wsUserCell)

Function..Find First And Last Cells

So far, I have tested if the user clicked cancel or if the worksheet contains any data, at this point, I have passed those tests, so now I can get to the meat of it.

I have one Function to return either the first used Cell or the last used Cell – and that my friends is cool. I want my Functions() to be fast, efficient and flexible. I vary whether the Function() returns the last used Cell or first used Cell by passing a variable to the SearchDirection by using the values of the xlSearchDirection Enumeration: xlNext and xlPrevious.

When the SearchDirection is xlNext, the Function() returns the first used Cell. When the SearchDirection is xlPrevious, the Function() returns the last used Cell.

Public Function GetCell(ws As Worksheet, _
                        rng As Range, _
                        lngDirection As Long) As Range
                        
    ''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''
    'GetCell
    'Returns a Range Object based on a single Cell
    'The Cell is either the first Cell in a Range or the last Cell in a Range
    'The distinction is based on the parameter value passed to lngDirection by the user as either xlPrevious or xlNext
    '
    'Parameters        :
    'ws                :   Required, A Woksheet Object.
    'rng               :   Required, A Range Object.
    'lngDirection      :   Required, Either xlNext or xlPrevious.
    '                      Use xlPrevious when searching for the last used Cell.
    '                      Use xlNext when searching or the first used cell.
    '
    'Use               :   Find the last used Cell first
    '                  :   Pass the last used Cell as a Range Object to the function to determine the first used Cell
    '
    '''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''
    
    'Get range as a single cell
        With ws
            Select Case lngDirection
                Case xlNext
                    If Not IsEmpty(.Cells(1, 1)) Then
                        Set rng = .Cells(1, 1)
                    Else
                        Set rng = .Cells.Find(What:="*", _
                                              After:=rng, _
                                              LookIn:=xlFormulas, _
                                              LookAt:=xlPart, _
                                              SearchOrder:=xlByRows, _
                                              SearchDirection:=lngDirection, _
                                              MatchCase:=False)
                    End If
                Case xlPrevious
                    Set rng = .Cells.Find(What:="*", _
                                          After:=rng, _
                                          LookIn:=xlFormulas, _
                                          LookAt:=xlPart, _
                                          SearchOrder:=xlByRows, _
                                          SearchDirection:=lngDirection, _
                                          MatchCase:=False)
            End Select
        End With
        
    'Pass the range to the function
        Set GetCell = rng

    'Tidy up
        Set rng = Nothing

End Function

When I call the Function() to get the last used Cell, I pass Cell(1,1) to the Function() and appropriate enumeration value for SearchDirection:

            'Get last cell
                Set rngLastCell = GetCell(ws:=wsUserCell, _
                                          rng:=wsUserCell.Cells(1, 1), _
                                          lngDirection:=xlPrevious)

When I call the Function() to get the first used Cell, I pass the Range Object created in the first call to the Function() and appropriate enumeration value for SearchDirection:

            'Get first cell
                Set rngFirstCell = GetCell(ws:=wsUserCell, _
                                           rng:=rngLastCell, _
                                           lngDirection:=xlNext)

The Final Sub()…GetTrueUsedRange

And here’s the final Sub() to bring it all together:

Option Explicit
Sub GetTrueUsedRange()

    'Declare variables
        Dim wb As Workbook
        Dim wsUserCell As Worksheet
        Dim rngUserCell As Range
        Dim rngStart As Range
        Dim rngLastCell As Range
        Dim rngFirstCell As Range
        Dim rngTrueUsedRange As Range
        Dim blnDataExists As Boolean
        Dim lngMessageResponse As Long
        Dim lngFirstCellRow As Long
        Dim lngFirstCellColumn As Long
        Dim lngLastCellRow As Long
        Dim lngLastCellColumn As Long
    
    'Initialize
        Set wb = ThisWorkbook
    
    'Prompt user to select a cell on a worksheet
        Set rngUserCell = GetUserSelectedCell( _
                            strPrompt:="Please select a cell on a worksheet.", _
                            strTitle:="Get Cell Selection From User")
                                          
    'Get the worksheet that contains the cell the user selected
        If Not rngUserCell Is Nothing Then
            Set wsUserCell = rngUserCell.Parent
        Else
            lngMessageResponse = GetUserMessageResponse( _
                                    strPrompt:="The selected worksheet does not contain any data." & vbLf & _
                                               "Or you clicked ""Cancel.""" & vbLf & _
                                               "Would you like to try a different worksheet?", _
                                    strTitle:="Missing Data Warning", _
                                    lngButtons:=vbYesNo)
        End If
    
    'Check if the worksheet has any data
        blnDataExists = TestForData(ws:=wsUserCell)
        
    'If the worksheet does not have any data, ask the user to select a different worksheet or exit
        If blnDataExists = False Then
            lngMessageResponse = GetUserMessageResponse( _
                                    strPrompt:="The selected worksheet does not contain any data." & vbCrLf & _
                                               "Would you like to try a different worksheet?", _
                                    strTitle:="Missing Data Warning", _
                                    lngButtons:=vbYesNo)

            If lngMessageResponse = vbYes Then
                Call GetTrueUsedRange   'Recursive call
                Exit Sub
            Else
                MsgBox "You clicked ""No"" or ""Cancel"". Now exiting.", vbInformation, "No Data Warning"
                Exit Sub
            End If
        Else
        
            'Get last cell
                Set rngLastCell = GetCell(ws:=wsUserCell, _
                                          rng:=wsUserCell.Cells(1, 1), _
                                          lngDirection:=xlPrevious)
                With rngLastCell
                    lngLastCellRow = .Row
                    lngLastCellColumn = .Column
                End With
                
            'Get first cell
                Set rngFirstCell = GetCell(ws:=wsUserCell, _
                                           rng:=rngLastCell, _
                                           lngDirection:=xlNext)
                                           
                With rngFirstCell
                    lngFirstCellRow = .Row
                    lngFirstCellColumn = .Column
                End With
        
        End If
        
    'Create true used range
        Set wsUserCell = wb.ActiveSheet
        Debug.Print "Worksheet", wsUserCell.Name
        With wsUserCell
            Set rngTrueUsedRange = .Range(.Cells(lngFirstCellRow, lngFirstCellColumn), _
                                          .Cells(lngLastCellRow, lngLastCellColumn))
        End With
    
    'Results
        Debug.Print "True used range", rngTrueUsedRange.Address

    'Tidy up
        If Not rngUserCell Is Nothing Then Set rngUserCell = Nothing
        If Not rngStart Is Nothing Then Set rngStart = Nothing
        If Not rngLastCell Is Nothing Then Set rngLastCell = Nothing
        If Not rngFirstCell Is Nothing Then Set rngFirstCell = Nothing
        If Not rngTrueUsedRange Is Nothing Then Set rngTrueUsedRange = Nothing
        If Not wsUserCell Is Nothing Then Set wsUserCell = Nothing
        If Not wb Is Nothing Then Set wb = Nothing
End Sub

Tidy Up

I tested the Sub() on several different Worksheets with a variety of placement of data, no data and single cells of data. All tests returned correct expected results. Please let me know if your tests return incorrect results.

How do you find the True Used Range on your Worksheets?

, , , , ,

BearFF

In my last post on using ActiveX Data Objects (ADO) with Excel VBA, I demonstrated some code to load a Recordset, filter the Recordset using the Recordset’s Filter Prpoerty, and copy the Filtered Recordset to a Worksheet using the CopyFromRecordset Method of the Range Object.

I put a link to the blog post on the Excel VBA and Users Group on LinkedIn. To our good fortune, James Wilson was reading. James responded with some nice comments and some very good code of his own. I was impressed and asked James if he would like to do a write up to post on the blog.

James kindly accepted my offer as follows in James’ words. Take it away James!



Bringing the full power of SQL to bear in Excel

James Wilson
September 13, 2014

“I feel the need, the need for speed.” Top Gun

I love Excel, but sometimes you just want a bit more power to analyse your data. My favourite tool for analysing large quantities of data has always been SQL. While Microsoft includes MS Query in Excel out-of-the-box, it does have many limitations and is relatively slow. Using VBA and ADO is the next logical step.

The code below is the latest incarnation of a general purpose SQL function I’ve been using for the last five years or so. For me the data is the thing – I want to be able to start querying my data using SQL without having to start coding from scratch each time. Just copy and paste into a module in your workbook, and you’re ready to go.

Code first then some explanation:

Function SQL(ByVal SQLstr As String, ByVal Destination As String, Optional ByVal ConnectionString As String) As Boolean

    On Error GoTo ErrorHandler
    Application.ScreenUpdating = False
    Application.Calculation = xlCalculationManual
    Application.DisplayAlerts = False

    Dim myConnection As Object
    Dim myRecordSet As Object
    Dim myQueryTable As QueryTable

    ThisWorkbook.Sheets(Destination).Activate
    ThisWorkbook.Sheets(Destination).Cells.Delete

    If ConnectionString = "" Then ConnectionString = "Provider=Microsoft.ACE.OLEDB.12.0;Data Source=" & ThisWorkbook.FullName & ";Extended Properties=Excel 12.0"
    
    Set myConnection = CreateObject("ADODB.Connection")
    Set myRecordSet = CreateObject("ADODB.Recordset")
    
    myConnection.ConnectionString = ConnectionString
    myConnection.Open
    myRecordSet.ActiveConnection = ConnectionString
    myRecordSet.Source = SQLstr
    myRecordSet.Open
    
    Set myQueryTable = Sheets(Destination).QueryTables.Add(Connection:=myRecordSet, Destination:=Range("'" & Destination & "'!a1"))
    myQueryTable.Refresh
    
    If myRecordSet.State <> adStateClosed Then myRecordSet.Close
    If Not myRecordSet Is Nothing Then Set myRecordSet = Nothing
    If Not myConnection Is Nothing Then Set myConnection = Nothing
    
    Err.Clear
ErrorHandler:
    If Err Then
        Sheets(Destination).Cells(1, 1) = "SQL Error: " & Err.Description
        SQL = False
    Else
        SQL = True
    End If
    
    Application.ScreenUpdating = True
    Application.Calculation = xlCalculationAutomatic
    Application.DisplayAlerts = True
End Function

I wrote this as a VBA function rather than a sub procedure, because I wanted to be able to trap errors in the calling procedure. It is a really a matter of preference whether you like your functions to return True or False (lines 28 and 30). I’ve chosen to return True if it worked, so I’d call it using coding something like:

Sub test()
    DidItWork = SQL("SELECT * FROM [Sheet1$] WHERE [Sheet1$].[date] > #01/03/2014#", "Sheet2")
    If DidItWork = False Then … 'Do some error handling
End Sub

Basically this function sets up an ADO link to a data source, executes an SQL query on that data, and returns the results of that query to a worksheet of our choice in the current workbook using a query table.

When you call this function (line 1), you pass a string with your SQL query, a string with the name of the worksheet you want the data to be returned to, and optionally a connection string to the data source. By default the data source is the workbook the code is in. That’s right – you can use SQL to query data in other tabs in the same workbook (make sure your workbook is saved first).

If you find that most of the time you are querying a corporate database or other data source, then you’d just tweak line 15 of the coding to default to the connection string to the data source you are using most often.

Lines 4 to 6 and 42 to 44 are just the standard VBA codes that you’d put in to speed up any bit of coding. If you are calling this function and have these bits of coding in the calling procedure, then you can safely delete these lines from this function.

Lines 8 to 10 are to set up a local connection and recordset object (we’re going to use ADO to get our data), and a query table (which we are going to use to return the results of the SQL query to Excel).

The way this function is written, your data output is always going to be a worksheet in the current workbook in Cell A1. You can have no other data in this worksheet as Lines 12 to 13 delete the contents of the worksheet, before it is refreshed again with the query table set up in Line 26.

Line 17 to 27 is the meat of the function, setting up an ADO link and returning the data using a query table.

Lines 29 to 31 are to tidy up objects and connections. Line 36 is to give you a clue if you’ve made an error in your SQL.

So I’ve a personal library function that allows me to use SQL in Excel without much further thought – what do I do with it? Let me give a few simple examples to give an idea of the possibilities.

  1. Treat my current spreadsheet a bit like a mini-database and run queries on it – that would be much harder to do just using VBA or manually copying and pasting.
  2. Suck data out of multiple corporate databases and spreadsheets and join it together. You don’t need even to open the spreadsheets to get the data (as I said to start with – it’s all about speed and power). So for example let’s say you have one spreadsheet from your sales guys with sales volumes, and you have another spreadsheet with the confidential prices for each customer, then you can do a bit of SQL coding like:
    DidItWork = SQL(“SELECT A.*, B.[Price], A.[Volume]*B.[Price] as [Revenue] from [C:\Sales Volumes.xlsx].[Data$] A LEFT OUTER JOIN [F:\Prices.xlsx].[Sheet1$] B ON A.[Product] = B.[Product] AND A.[Customer No] = B.[Customer] “, “Sales Forecast”)
    So I’m using SQL aliases A and B for brevity, and by using multipart identifiers specifying the full path and filename of the Excel workbooks I can suck data out of any file I have access to. Note if you specify the data source fully, the connection string ADO uses is virtually irrelevant.
  3. By using For…Next loops in VBA and a bit of text manipulation and the SQL command UNION I can consolidate multiple similar data sources simply. So using a string variable like below in a loop:

mySQLstring = mySQLstring & ” UNION ” & …
Good for consolidating budgets submitted in a similar format.

The limitation is really your knowledge of SQL. Beware of missing spaces and extra commas in your SQL if you are using the VBA & _ to join long strings together to form your SQL.


Tidy Up

Thanks James – great job! How do you use ADO, SQL, Recordsets and QueryTables in your Projects?

, , , , , , , , ,

DandelionFinal2

Dandelions are weeds. I’ve spent more hours weeding them out of my family’s yard and my grandparents’ yards than I care to count. Yet, when you come across them in a meadow, they are very nice to look at and add a kind of tranquility in their own right. They are edible and make a nice tasting wine. Here’s a recipe from AllRecipes. Let us know how it turns out.

Today’s post, however, is not about dandelions or wine making – it about the Filter Property of ADO Recordsets.


    edit: As is my usual practice, I am going to use Late Binding in the sample snippets below. A discussion on Late / Early Binding is beyond the scope of this post. Please see these links for a detailed explanation of Late / Early Binding.

    1. Beyond Excel
    2. JP Software Technologies


In my last post on ADO Recordsets, I demonstrated some VBA to load a Worksheet Range into a Recordset – check it out here.

First Step

Before I filter the Recordset, I would like to manually filter the dataset so I can determine what the final results should be so I can compare to make sure everything goes correctly with the Recordset Filter.

RecordsAllFinal

Here’s some data I borrowed from Marco Russo and Alberto Ferrari. It looks as though it may have come from the AdventureWorks Database. There are a total of 60,398 records.

Now I’ll filter on the SalesManager field to look at records that are not related to Marco.

RecordsFilteredFinal

OK, 25,109 records remain after I filter out records for Marco so When I filter the Recordset, I should receive 25,109 records. I removed the AutoFilter, now I am ready to Filter the Recordset

Global Constants

In my last post. on ADO Recordsets, I began by adding some Global Constants to a module named “M_Globals”. I’m going to add a few new constants for the Filter Group Enumeration. I may use them, I may not. But at least I have them defined if I do need them.

'Filter Group Enumeration
    Public Const gcladFilterNone = 0                 'No filter. This value removes the current filter and restores all records to view.
    Public Const gcladFilterPendingRecords = 1       'Use the pending records. This value allows viewing only those records that have changed but have not yet been sent to the server. This value is only applicable for batch update mode.
    Public Const gcladFilterAffectedRecords = 2      'Use only records affected by the last Delete, Resync, UpdateBatch, or CancelBatch call.
    Public Const gcladFilterFetchedRecords = 3       'Use the last fetched records. This value allows viewing the records in the current cache returned as a result of the last call to retrieve records (implying a resynchronization).
    Public Const gcladFilterConflictingRecords = 5   'Use the conflicting records. This value allows viewing only those records that failed the last batch update.

Load The Recordset

I won’t clutter this tutorial by reposting the same code I posted in my last article on ADO Recordsets, check the Sub() out here.

Filter The Recordset

Now that I have a Recordset, I just need to add a bit of code to filter it. Recall, I am interested in all records where the Sales Manager is not Marco. So my criteria string will be something like “SalesManager <> ‘Marco Russo'”

I just need to add 6 lines to my original Sub() and of those, 2 lines are comment lines (I could use fewer lines, I’m using additional lines for clarity)

        Dim strFilter As String
        'Filter string
            strFilter = "SalesManager <> 'Marco Russo'"
        'Filter the Recordset and display the filter record and field count to check results
            rs.Filter = strFilter
            Debug.Print "The filtered recordset contains " & Format(rs.RecordCount, "##,##0") & " records and " & rs.Fields.Count & " fields"

Returns:

The original recordset contains 60,398 records and 23 fields
The filtered recordset contains 25,109 records and 23 fields

Perfect! The Filtered Recordset matches with the results I obtained earlier by manually filtering the Range.

Gimmee The Data…

Most likely, we want to return the dataset back to the user in either a new workbook or a new worksheet. For today, I’ll return the Filtered Recordset back to the same Workbook on a new Worksheet.

Add A Worksheet

I’ll create a Function to add a worksheet to a workbook so that I have a safe place to return the results of the Filtered Recordset

Public Function AddWorksheet(wb As Workbook) As Worksheet

    'Declare variables
        Dim wsNew As Worksheet
        
    'Add worksheet to end of other worksheets in the workbook
        With wb
            Set wsNew = .Worksheets.Add _
                                    (After:=.Worksheets(.Worksheets.Count))
                            
        End With
        
    'Return object to function
        Set AddWorksheet = wsNew
        
    'Tidy up
        Set wsNew = Nothing
        
End Function

And I call the Function here:

        'Add a worksheet for the filtered results
            Set wsResults = AddWorksheet(wb:=wb)

CopyFromRecordset Method

The Range Object has a CopyFromRecordset Method, so I’ll use that:

        'Copy the filtered recordset to the results range
        'The CopyFromRecordset Method does not include headers
            wsResults.Cells(1, 1).CopyFromRecordset rs

And the output:
RecordsetOutFinal

It’s looking good. The record count matches with what I expected from the manual filter process at the top of the post. The only problem is that the CopyFromRecordset Method does not include the field headers, so I’ll need a small Sub() to get the field headers and then output the Recordset to Cell(2,1) instead of Cell(1,1).

The Fields Collection

The Recordset Object has a Fields Collection, so I can loop through the Fields Collection to get the Field Names. The gotcha here is that the Fields Collection begins as zero – so be aware of that.

Here’s the Sub():

Public Sub GetRSFieldNames(ws As Worksheet, _
                           rs As Object)
                           
    'Declare variables
        Dim x As Long
        
    'Get field names
        For x = 0 To rs.Fields.Count - 1
            ws.Cells(1, x + 1).Value = rs.Fields(x).Name
        Next x
    
End Sub

Here is how I called the Sub():

        'Output Recordset Field Names to the worksheet
            Call GetRSFieldNames(ws:=wsResults, _
                                 rs:=rs)

And the Output:
RecordWFieldsFinal

Looks pretty good – I just want to add some formatting to improve readability.

CharlieDanielsFinal

Fiddle Factor

No – not Charlie Daniels pictured here sawing on a fiddle and playing it hot as in The Devil Went Down To Georgia. Rather, Fiddle Factor is a term I learned from one of my supervisors which refers to the amount of time and energy spent formatting an Excel Report. The more time and energy spent – the higher the Fiddle Factor.

But I think formatting is very important. Not only does it make data and information easier to read and understand, but if it is done well, it actually draws or invites the reader in. Stephen Few has quite a bit to say about well-done formatting on his blog, Perceptual Edge.

Enough of my soap box, my goal in this case is not so lofty. I just want to add a bit of color to the header row, fit the column width to the data and maybe play with the zoom level:

Here is the Sub() to format the output:

Sub FormatOutput(ws As Worksheet)

    'Declare variables
        Dim LastColumn As Long
        Dim rngHeader As Range
        Dim lngColor As Long
        
    'initialize
        lngColor = RGB(68, 84, 106)
        
    'Get last column of header row range
        LastColumn = GetLast(ws:=ws, _
                             strType:="c")
                             
    'Create Range Object - header row range
        With ws
            Set rngHeader = .Range(.Cells(1, 1), .Cells(1, LastColumn))
        End With
        
    'Format the header row range
        With rngHeader
            .Interior.Color = lngColor
            .Font.Bold = True
            .Font.Color = vbWhite
        End With
        
    'Format Dates
        With ws
            .Range("L2").EntireColumn.NumberFormat = "MM/DD/YYYY"
        End With
               
    'Set zoom level
        ws.Activate
        ActiveWindow.Zoom = 75
        
    'Fit column width to data
        Columns.AutoFit

End Sub

And here is how I call the Sub():

        'Format the output
            Call FormatOutput(ws:=wsResults)

The Full Monty

Here is the main Sub() with the additions to Filter the Recordset, Output the Recordset to a new Worksheet, and Format the data:

Sub FilterRecordset()

    'Declare variables
        Dim wb As Workbook
        Dim wbADO As Workbook
        Dim ws As Worksheet
        Dim wsResults As Worksheet
        Dim rng As Range
        Dim rngResults As Range
        Dim cn As Object
        Dim rs As Object
        Dim cmd As Object
        Dim strWorksheet As String
        Dim strSQL As String
        Dim strWorkbookADO As String
        Dim strFilter As String
                
    'Excel environemnt
        With Application
            .ScreenUpdating = False
            .DisplayAlerts = False
            .EnableEvents = False
            .Calculation = xlCalculationManual
        End With

    'Initialize
        Set wb = ThisWorkbook
        
        'Get worksheet to be loaded into recordset
            strWorksheet = GetSelectedSheet(strPrompt:="Select a cell on the worksheet to be loaded into the recordset", _
                                            strTitle:="Worksheet To Recordset")
                                            
        'Create a new workbook to hold all data from the selected worksheet
            Set wbADO = Workbooks.Add
            
        'Copy everything from the selected worksheet to the new workbook
            Call CopyData(wbSource:=wb, _
                          wbDestination:=wbADO, _
                          strSource:=strWorksheet)
                          
        'Cleanup the destination workbook
            Call CleanupWorkbook(wb:=wbADO)
            
        'Save and close the data workbook
            With wbADO
                .SaveAs wb.Path & "\" & Mid(wb.Name, 1, Len(wb.Name) - 5) & "_ADO.xlsx", FileFormat:=xlOpenXMLWorkbook
                strWorkbookADO = wbADO.FullName
                .Close
            End With

        'Create a range object to measure source data against final recordset data
            Set ws = wb.Worksheets(strWorksheet)
            Set rng = ws.Range("A1").CurrentRegion

        'SQL string
            strSQL = "SELECT * FROM [Data$]"
            
        'Filter string
            strFilter = "SalesManager <> 'Marco Russo'"

        'Create ADO Connection Object
            Set cn = GetADOConnection()
            cn.Open ("Provider=Microsoft.ACE.OLEDB.12.0;" & _
                     "Data Source=" & strWorkbookADO & ";" & _
                     "Extended Properties='Excel 12.0 Xml;HDR=YES;IMEX=1'")

        'Create ADO Command Object
            Set cmd = GetCommand()
            Set cmd.ActiveConnection = cn
            cmd.CommandType = gcladCmdText
            cmd.CommandText = strSQL                        'Pass SQL String to the command object

        'Create ADO Recordset Object and load records
            Set rs = GetRecordset()
            With rs
                .CursorLocation = gcladUseClient
                .CursorType = gcladOpenDynamic
                .LockType = gcladLockOptimistic
                .Open cmd
            End With

        'Compare recordset results to original data
            Debug.Print "The original recordset contains " & Format(rs.RecordCount, "##,##0") & " records and " & rs.Fields.Count & " fields"
            Debug.Print "The range contains " & Format(rng.Rows.Count - 1, "##,##0") & " rows and " & rng.Columns.Count & " columns" '-1 to discount header row
            
        'Filter the Recordset
            rs.Filter = strFilter
            
        'Add a worksheet for the filtered results
            Set wsResults = AddWorksheet(wb:=wb)
            
        'Output Recordset Field Names to the worksheet
            Call GetRSFieldNames(ws:=wsResults, _
                                 rs:=rs)
            
        'Copy the filtered recordset to the results range
        'The CopyFromRecordset Method does not include headers
            wsResults.Cells(2, 1).CopyFromRecordset rs
            
        'Format the output
            Call FormatOutput(ws:=wsResults)
    
            
        'Tidy up
            'Close objects
                rs.Close
                cn.Close
                
            'Destroy objects
                Set rs = Nothing
                Set cmd = Nothing
                Set cn = Nothing
                Set rng = Nothing
                Set ws = Nothing
                Set wsResults = Nothing
                Set wbADO = Nothing
                Set wb = Nothing
                
            'Excel environemnt
                With Application
                    .ScreenUpdating = True
                    .DisplayAlerts = True
                    .EnableEvents = True
                    .Calculation = xlCalculationAutomatic
                End With
                    
End Sub

And the final output:

RecordWFieldsAutoFitComplete

Tidy up

Final Thoughts

This post was about Filtering ADO Recordsets. The Filter I used was very simple and only scratches the surface of what is possible. You may use the Filters in combinations with AND, OR, LIKE and Wildcard Characters. Make sure you check out the link to Recordset Filter Property. Lots of great information.

I don’t like that I hard coded the Filter String inside the Sub(). It would be better to offer a user form at run-time to read the fields in the recordset and prompt the user to make choices through Combo Boxes, Check Boxes, etc…

Other Recordset Posts At dataprose.org

Additional Resources

Downloads

Download the file from OneDrive. The filename is Excel – Recordset_v3.xlsm

Credits

Data courtesy Microsoft Excel 2013 Building Data Models with PowerPivot by Alberto Ferrari and Marco Russo (Mar 25, 2013)

FemmesFinal

I hope you know that this will go down on your permanent record
Oh yeah? Well, don’t get so distressed
Did I happen to mention that I’m impressed?

So go the lyrics from Kiss Off by the Violent Femmes pictured here. Great song from the 80’s. If you are not familiar with the Femmes, check ’em out – highly recommended.

However, today’s post is not about the Alternative Rock scene of the early 80’s. Rather, it is about ActiveX Data Objects (ADO) Recordsets.


    edit: As is my usual practice, I am going to use Late Binding in the sample snippets below. A discussion on Late / Early Binding is beyond the scope of this post. Please see these links for a detailed explanation of Late / Early Binding.

    1. Beyond Excel
    2. JP Software Technologies


Global Constants

Because I am using Late Binding, I am going to setup Global Constants for the various Enumerations I need for Command Types, Cursor Locations, Cursor Types and Lock Types. It takes a little bit of extra work, but I think it makes the code clearer:

Clear:

cmd.CommandType = gcladCmdText

Not clear:

cmd.CommandType = 1

See? The Constant is self-documenting and makes the code clearer.

Here’s all the Global Contants. I put them in a Module named “M_Globals” because I’m creative that way.

'Command Type Enumeration Values
    Public Const gcladCmdUnspecified = -1       'Unspecified type of command
    Public Const gcladCmdText = 1               'Evaluates CommandText as a textual definition of a command or stored procedure call
    Public Const gcladCmdTable = 2              'Evaluates CommandText as a table name whose columns are returned by an SQL query
    Public Const gcladCmdStoredProc = 4         'Evaluates CommandText as a stored procedure name
    Public Const gcladCmdUnknown = 8            'Default. Unknown type of command
    Public Const gcladCmdFile = 256             'Evaluates CommandText as the file name of a persistently stored Recordset. Used with Recordset.Open or Requery only.
    Public Const gcladCmdTableDirect = 512      'Evaluates CommandText as a table name whose columns are all returned. Used with Recordset.Open or Requery only. To use the Seek method, the Recordset must be opened with adCmdTableDirect. Cannot be combined with the ExecuteOptionEnum value adAsyncExecute.

'Cursor Location Enumeration Values
    Public Const gcladUseNone = 1               'OBSOLETE (appears only for backward compatibility). Does not use cursor services
    Public Const gcladUseServer = 2             'Default. Uses a server-side cursor
    Public Const gcladUseClient = 3             'Uses a client-side cursor supplied by a local cursor library. For backward compatibility, the synonym adUseClientBatch is also supported
    
'Cursor Type Enumeration Values
    Public Const gcladOpenUnspecified = -1      'Unspecified type of cursor
    Public Const gcladOpenForwardOnly = 0       'Default. A forward-only cursor. This improves performance when you need to make only one pass through a Recordset
    Public Const gcladOpenKeyset = 1            'A keyset cursor. Like a dynamic cursor, except that you can't see records that other users add, although records that other users delete are inaccessible from your Recordset. Data changes by other users are still visible.
    Public Const gcladOpenDynamic = 2           'A dynamic cursor. Additions, changes, and deletions by other users are visible, and all types of movement through the Recordset are allowed
    Public Const gcladOpenStatic = 3            'A static cursor. A static copy of a set of records that you can use to find data or generate reports. Additions, changes, or deletions by other users are not visible.

'Lock Type Enumeration Values
    Public Const gcladLockUnspecified = -1      'Unspecified type of lock. Clones inherits lock type from the original Recordset.
    Public Const gcladLockReadOnly = 1          'Default. Read-only records
    Public Const gcladLockPessimistic = 2       'Pessimistic locking, record by record. The provider lock records immediately after editing
    Public Const gcladLockOptimistic = 3        'Optimistic locking, record by record. The provider lock records only when calling update
    Public Const gcladLockBatchOptimistic = 4   'Optimistic batch updates. Required for batch update mode

Let The User Choose Which Worksheet To Load To The Recordset

In the function below, I use an InputBox Type:=8 to let the user choose a cell on the worksheet that contains the data that should be loaded into the recordset:

Public Function GetSelectedSheet(strPrompt As String, _
                                 strTitle As String) As String
     
    'Declare variables
        Dim ws                          As Worksheet
        Dim rng                         As Range
     
    'Users - select a cell on a worksheet
        Set rng = Application.InputBox( _
                                       Prompt:=strPrompt, _
                                       Title:=strTitle, _
                                       Default:=ActiveCell.Address, _
                                       Type:=8) 'Range selection
                     
    'Get the parent worksheet of the selected cell
        Set ws = rng.Parent
         
    'Pass the name of the worksheet to the function
        GetSelectedSheet = ws.Name
     
    'Tidy up
        Set rng = Nothing
        Set ws = Nothing
 End Function

And I call the function like this:

        'Get worksheet to be loaded into recordset
            strWorksheet = GetSelectedSheet(strPrompt:="Select a cell on the worksheet to be loaded into the recordset", _
                                            strTitle:="Worksheet To Recordset")

Save The Data To A New Workbook

I could not get the ADO code to work with data in the same workbook, so in the end I decided to just save the data the user selected out to a new workbook:

First, I added a workbook:

        'Create a new workbook to hold all data from the selected worksheet
            Set wbADO = Workbooks.Add

Then I sent the original workbook, the new workbook and the the worksheet that the user selected to a Private Sub to handle the copying:

Call the sub:

        'Copy everything from the selected worksheet to the new workbook
            Call CopyData(wbSource:=wb, _
                          wbDestination:=wbADO, _
                          strSource:=strWorksheet)

The Sub() to copy the entire worksheet from one workbook to another:

Private Sub CopyData(wbSource As Workbook, _
                     wbDestination As Workbook, _
                     strSource As String)
                     
    wbSource.Worksheets(strSource).Copy wbDestination.Worksheets(1)

End Sub

And then the cleanup:

        'Cleanup the destination workbook
            Call CleanupWorkbook(wb:=wbADO)

The Sub() to handle any cleanup chores:

Private Sub CleanupWorkbook(wb As Workbook)

    'Declare variables
        Dim i As Long
        
    'Rename worksheets
    'Delete unneeded worksheets
        With wb
            .Worksheets(1).Name = "Data"
            For i = .Sheets.Count To 2 Step -1
                .Sheets(i).Delete
            Next i
        End With

End Sub

Lastly, I saved and closed the new workbook, since the ADO Process will want to open the workbook

        'Save and close the data workbook
            With wbADO
                .SaveAs wb.Path & "\" & Mid(wb.Name, 1, Len(wb.Name) - 5) & "_ADO.xlsx", FileFormat:=xlOpenXMLWorkbook
                strWorkbookADO = wbADO.FullName
                .Close
            End With

Create A Range Object To Measure Inputs

I would like to measure the amount of rows and columns in the input Range so that after I load the Recordset I can compare the the Range Dimensions to the Recordset Dimensions.

        'Create a range object to measure source data against final recordset data
            Set ws = wb.Worksheets(strWorksheet)
            Set rng = ws.Range("A1").CurrentRegion

SQL String

I like to create a SQL string and then pass the SQL string to the CommandText Property of the Command Object. I think this makes troubleshooting and tuning the SQL easier:

        'SQL string
            strSQL = "SELECT * FROM [Data$]"

Create The ADO Connection Object

I like to encapsulate any objects I am creating. Here is the function to create the ADO Connection Object:

Public Function GetADOConnection() As Object

    Set GetADOConnection = CreateObject("ADODB.Connection")
  
End Function

And here is how I call it:

        'Create ADO Connection Object
            Set cn = GetADOConnection()

ADO Connection Strings

ADO Connection Strings can be a little challenging, luckily, we have ConnectionStrings.com to help us out. Link is at the bottom of the post. I am using Office 2013 with a workbook in xlOpenXMLWorkbook format (.xlsx). So this is the connection string I’ll be using:

cn.Open ("Provider=Microsoft.ACE.OLEDB.12.0;" & _
         "Data Source=" & strWorkbookADO & ";" & _
         "Extended Properties='Excel 12.0 Xml;HDR=YES;IMEX=1'")

Create The ADO Command Object

Next, I’ll create the ADO Command Object and set some of the properties of the object. Note here that I am using one of the Global Contants that I declared earlier. I also pass my SQL string here:

        'Create ADO Command Object
            Set cmd = GetCommand()
            Set cmd.ActiveConnection = cn
            cmd.CommandType = gcladCmdText
            cmd.CommandText = strSQL                        'Pass SQL String to the command object

And here is the function to create the Command Object :

Public Function GetCommand() As Object

    Set GetCommand = CreateObject("ADODB.Command")
  
End Function

Create And Load The ADO Recordset

Next I need to create and load the recordset.

'Create ADO Recordset Object and load records
            Set rs = GetRecordset()
            With rs
                .CursorLocation = gcladUseClient
                .CursorType = gcladOpenDynamic
                .LockType = gcladLockOptimistic
                .Open cmd
            End With

And here is the encapsulated function that creates the ADO Recordset Object:

Public Function GetRecordset() As Object

    Set GetRecordset = CreateObject("ADODB.Recordset")
  
End Function

Check Recordset Results Against Expected Results

Lastly, I want to compare the Recordset results against expected results. Do do this I will count the number of records and fields in the Recordset and compare them against the number of rows and columns in the Range Object I created earlier:

        'Compare recordset results to original data
            Debug.Print "The recordset contains " & Format(rs.RecordCount, "##,##0") & " records and " & rs.Fields.Count & " fields"
            Debug.Print "The range contains " & Format(rng.Rows.Count - 1, "##,##0") & " rows and " & rng.Columns.Count & " columns" '-1 to discount header row

Returns:

The recordset contains 60,398 records and 23 fields
The range contains 60,398 rows and 23 columns

Everything is working as it should.

The Main Procedure

Sub PopulateRecordset()

    'Declare variables
        Dim wb As Workbook
        Dim wbADO As Workbook
        Dim ws As Worksheet
        Dim rng As Range
        Dim cn As Object
        Dim rs As Object
        Dim cmd As Object
        Dim strWorksheet As String
        Dim strSQL As String
        Dim strWorkbookADO As String
                
    'Excel environemnt
        With Application
            .ScreenUpdating = False
            .DisplayAlerts = False
            .EnableEvents = False
            .Calculation = xlCalculationManual
        End With

    'Initialize
        Set wb = ThisWorkbook
        
        'Get worksheet to be loaded into recordset
            strWorksheet = GetSelectedSheet(strPrompt:="Select a cell on the worksheet to be loaded into the recordset", _
                                            strTitle:="Worksheet To Recordset")
                                            
        'Create a new workbook to hold all data from the selected worksheet
            Set wbADO = Workbooks.Add
            
        'Copy everything from the selected worksheet to the new workbook
            Call CopyData(wbSource:=wb, _
                          wbDestination:=wbADO, _
                          strSource:=strWorksheet)
                          
        'Cleanup the destination workbook
            Call CleanupWorkbook(wb:=wbADO)
            
        'Save and close the data workbook
            With wbADO
                .SaveAs wb.Path & "\" & Mid(wb.Name, 1, Len(wb.Name) - 5) & "_ADO.xlsx", FileFormat:=xlOpenXMLWorkbook
                strWorkbookADO = wbADO.FullName
                .Close
            End With

        'Create a range object to measure source data against final recordset data
            Set ws = wb.Worksheets(strWorksheet)
            Set rng = ws.Range("A1").CurrentRegion

        'SQL string
            strSQL = "SELECT * FROM [Data$]"

        'Create ADO Connection Object
            Set cn = GetADOConnection()
            cn.Open ("Provider=Microsoft.ACE.OLEDB.12.0;" & _
                     "Data Source=" & strWorkbookADO & ";" & _
                     "Extended Properties='Excel 12.0 Xml;HDR=YES;IMEX=1'")

        'Create ADO Command Object
            Set cmd = GetCommand()
            Set cmd.ActiveConnection = cn
            cmd.CommandType = gcladCmdText
            cmd.CommandText = strSQL                        'Pass SQL String to the command object


        'Create ADO Recordset Object and load records
            Set rs = GetRecordset()
            With rs
                .CursorLocation = gcladUseClient
                .CursorType = gcladOpenDynamic
                .LockType = gcladLockOptimistic
                .Open cmd
            End With

        'Compare recordset results to original data
            Debug.Print "The recordset contains " & Format(rs.RecordCount, "##,##0") & " records and " & rs.Fields.Count & " fields"
            Debug.Print "The range contains " & Format(rng.Rows.Count - 1, "##,##0") & " rows and " & rng.Columns.Count & " columns" '-1 to discount header row
            
        'Tidy up
            'Close objects
                rs.Close
                cn.Close
                
            'Destroy objects
                Set rs = Nothing
                Set cmd = Nothing
                Set cn = Nothing
                Set rng = Nothing
                Set ws = Nothing
                Set wbADO = Nothing
                Set wb = Nothing
                
            'Excel environemnt
                With Application
                    .ScreenUpdating = True
                    .DisplayAlerts = True
                    .EnableEvents = True
                    .Calculation = xlCalculationAutomatic
                End With
                    
End Sub

Tidy up

Additional Resources

Downloads

Credits

    Data courtesy Microsoft Excel 2013 Building Data Models with PowerPivot by Alberto Ferrari and Marco Russo (Mar 25, 2013)

Final Thoughts

    I could not get the ADO to work with data in the same workbook that contains the code. That does not mean you cannot – I don’t know. I would generally invoke a FileDialogFilePicker function to select a file that contains the data for processing. That’s it for today. I’ll come back later with more stuff on working with Recordsets. Thanks, Dennis!
, , ,