how to annotate pivot tables?

miconian

Well-known Member
Joined
Aug 18, 2004
Messages
769
My users spend a lot of time in large pivot tables that are set up in compact view, expanding and collapsing fields by clicking on the plus and minus symbols. As they do this, they want to make notes about individual line items.

However, this is difficult because a) there is nowhere that allows the user to make notes inside the pivot table, and b) if they make notes outside the table, the row their note corresponds to will change when fields are collapsed and expanded. Also, it seems that Excel does not allow comments to be added to cells within pivot tables.

Surely others have had this problem. Is there some obvious workaround I'm missing?

thanks!
 
Created an account to say this code is fantastic, thank you so much!!

I was wondering if it would be possible to modify this code to work with a mix of compact and tabular formats in the pt. I use a pt with the first 6 fields in compact and starting with field 7 through 12 are in tabular. Any guidance would be greatly appreciated, thank you again
 
Upvote 0

Excel Facts

Best way to learn Power Query?
Read M is for (Data) Monkey book by Ken Puls and Miguel Escobar. It is the complete guide to Power Query.
Created an account to say this code is fantastic, thank you so much!!

I was wondering if it would be possible to modify this code to work with a mix of compact and tabular formats in the pt. I use a pt with the first 6 fields in compact and starting with field 7 through 12 are in tabular. Any guidance would be greatly appreciated, thank you again


I'm really new to VBA but I've been playing with the code and think i figured out how to post all fields when mixed between compact and tabular formatting into the notes page, im stuck on the getkey function for the match, i figured i would share the portion of the code i modified if it can help in anyway to figure out the getkey function. for this to work the check for compact or tabular form needs to be deleted.

Thanks again.


Code:
Public Function Update_Note_Database(PT As PivotTable, rNote As Range)    Dim rLabels As Range
    Dim sField As String, sItem As String
    Dim vFields As Variant, tblNotes As ListObject
    Dim lPosition As Long, lIdx As Long, lCol As Long
    Dim iArray As Variant, i As Integer
 
   ' If PT.RowFields(1).LayoutCompactRow Then '--Compact layout
    '---Make array of rowfields by position to trace each row in hierarchy
         With PT.RowFields
            ReDim vFields(1 To .Count)
            For lIdx = 1 To .Count
                vFields(PT.RowFields(lIdx).Position) = PT.RowFields(lIdx).Name
            Next lIdx
        End With
     
    '---Make new record of note at top of database table
        lIdx = lIdx + 1
        
        Set tblNotes = Sheets(PT.Parent.Name & "|Notes").ListObjects(1)
        tblNotes.ListRows.Add (1)
        tblNotes.ListColumns("Note").Range(2) = rNote.Value
        With PT.RowRange
            Set rLabels = .Offset(1).Resize(rNote.Row - .Row, 1)
            For i = rLabels.Rows.Count To 1 Step -1
                On Error Resume Next
                sField = rLabels(i).PivotField.Name
                lPosition = Application.Match(sField, vFields, 0)
                If lPosition < lIdx Then
                    sItem = rLabels(i).PivotItem.Name
                    tblNotes.ListColumns(sField).Range(2) = sItem
                    lIdx = lPosition
                    If lIdx = 1 Then Exit For
                End If
            Next i
        End With
 '   Else    '--Tabular or Outline layout
        Set tblNotes = Sheets(PT.Parent.Name & "|Notes").ListObjects(1)
        'tblNotes.ListRows.Add (1)
        tblNotes.ListColumns("Note").Range(2) = rNote.Value
        Set rLabels = Intersect(rNote.EntireRow, PT.RowRange)
       
        For lCol = rLabels.Count To 1 Step -1
            With rLabels(1, lCol)
                tblNotes.ListColumns(.PivotField.Name).Range(2) = .PivotItem.Name
            End With
        Next lCol


    
'---Remove any previous notes with matching rowfield values
    With tblNotes.Range
        ReDim iArray(0 To .Columns.Count - 3)
        For i = 0 To UBound(iArray)
            iArray(i) = i + 2
        Next i
        .RemoveDuplicates Columns:=(iArray), Header:=xlYes
        If rNote = vbNullString Then tblNotes.ListRows(1).Delete
    End With
End Function
 
Upvote 0
Hi and Welcome to the Board,

You're taking on an ambitious project for being new to VBA! :)

I had my hands full tonight and wasn't able to look at this, but I'd be glad to try to help you tomorrow.

Since there are a few different versions of parts of the code as it has evolved through this thread, please either post all the parts you are currently using or reference the Post number you are using as your base.
 
Upvote 0
Hi and Welcome to the Board,

You're taking on an ambitious project for being new to VBA! :)

I had my hands full tonight and wasn't able to look at this, but I'd be glad to try to help you tomorrow.

Since there are a few different versions of parts of the code as it has evolved through this thread, please either post all the parts you are currently using or reference the Post number you are using as your base.


I am hoping to learn quickly :) thank you again for your help,

below is the code i am using, though currently it will not recall the match on pivot update only post the note to the notes sheet.

Module Code:
Code:
Option Explicit

 
Public Const sRngName = "PT_Notes"

 
Public Function Check_Setup(ws As Worksheet) As Boolean
    Dim rNotes As Range, i As Long, bCompact As Boolean
    Dim PT As PivotTable, ptField As PivotField
    Dim tblNotes As ListObject
    Dim wsSave As Worksheet

 
'---Check if not exactly one PT on Worksheet- exit
    If ws.PivotTables.Count <> 1 Then GoTo StopNotes
    Set PT = ws.PivotTables(1)

 
'---Check Compact Layout option is same for all fields (True or False)
    'Select Case PT.RowFields.Count


 
'---Check if Named Range "PT_Notes" doesn't exist- define it
    If Not NameExists(sRngName, ws.Name) Then
        With PT.TableRange1
            Set rNotes = Intersect(PT.DataBodyRange.EntireRow, _
                    .Resize(, 1).Offset(0, .Columns.Count))
        End With
        Set rNotes = rNotes.Resize(rNotes.Rows.Count _
            + PT.ColumnGrand)
        ws.Names.Add Name:=sRngName, RefersTo:=rNotes
        Call Format_NoteRange(rNotes)
    End If
 

'---Check if "|Notes" Worksheet doesn't exist- add it
    If Not SheetExists(ws.Name & "|Notes") Then
        Set wsSave = ActiveSheet
        Sheets.Add
        ActiveSheet.Name = ws.Name & "|Notes"
        wsSave.Activate
    End If
 

'---Check if Notes DataTable doesn't exist- add it
    With Sheets(ws.Name & "|Notes")
        On Error Resume Next
        Set tblNotes = .ListObjects(1)
        If tblNotes Is Nothing Then
            .Cells(1) = "KeyPhrase"
            .Cells(1, 2) = "Note"
            Set tblNotes = .ListObjects.Add(xlSrcRange, _
                .Range("A1:B2"), , xlYes)
        End If
    End With
 

'---Check if any PT fields are not Table Headers - add
    With tblNotes
        For Each ptField In PT.RowFields
            If IsError(Application.Match(ptField.Name, .HeaderRowRange, 0)) Then
                .ListColumns.Add Position:=2
                .HeaderRowRange(1, 2) = ptField.Name
            End If
        Next ptField
    End With
    Check_Setup = True
    Exit Function
 

StopNotes:
    If NameExists(sRngName, ws.Name) Then
        Application.EnableEvents = False
        Call Clear_Notes_Range(ws)
        ws.Names(sRngName).Delete
        Application.EnableEvents = True
        Check_Setup = False
        Exit Function
    End If
End Function
 

Private Function Format_NoteRange(rNotes As Range)
'---Format body
    With rNotes
        .Interior.Color = 16316664
        .Font.Italic = True
        .HorizontalAlignment = xlLeft
        .IndentLevel = 1
        .Borders(xlInsideHorizontal).LineStyle = xlDot
        .Borders(xlBottom).LineStyle = xlDot
    End With
 
'---Format optional header
    With rNotes.Resize(1)(0)
        .Value = "Notes"
        .Interior.Color = 16316664
        .Font.Italic = True
        .Font.Bold = True
        .HorizontalAlignment = xlCenter
        .Borders(xlBottom).LineStyle = xlContinuous
    End With
End Function
 

Private Function Clear_Notes_Range(ws As Worksheet)
'---Clear existing notes range
    On Error Resume Next
    Dim c As Range
    With ws.Range(sRngName)
        With .Offset(-1).Resize(.Rows.Count + 1)
            If Intersect(ws.PivotTables(1).TableRange2, _
                    .Cells) Is Nothing Then
                .ClearContents
                .ClearFormats
            Else 'PT overlaps notes
                For Each c In .Cells
                    c.ClearContents
                    c.ClearFormats
                Next c
                On Error GoTo 0
            End If
        End With
    End With
End Function
 

Public Function Refresh_Notes(PT As PivotTable)
    Dim sField As String, sKey As String, sFormula As String
    Dim ptField As PivotField
    Dim tblNotes As ListObject
    Dim rNotes As Range, c As Range
    Dim rLabels As Range, rLabelsAll As Range
    Dim vFields As Variant, vReturn As Variant
    Dim lPosition As Long, lOffset As Long
    Dim i As Long, lIdx As Long
    Dim lRow As Long, lCol As Long

    
'---Clear existing notes range
    Call Clear_Notes_Range(ws:=PT.Parent)
'---Redefine and format notes range
    With PT.TableRange1
        Set rNotes = Intersect(PT.DataBodyRange.EntireRow, _
            .Resize(, 1).Offset(0, .Columns.Count))
    End With
    Set rNotes = rNotes.Resize(rNotes.Rows.Count + PT.ColumnGrand)
    PT.Parent.Names(sRngName).RefersTo = rNotes
    Call Format_NoteRange(rNotes)
 
'---Make array of rowfields by position to trace each row in hierarchy
     With PT.RowFields
        ReDim vFields(1 To .Count)
        For lIdx = 1 To .Count
            vFields(PT.RowFields(lIdx).Position) = PT.RowFields(lIdx).Name
        Next lIdx
    End With
 
'---Build formula to use as Match KeyPhrase
    Set tblNotes = Sheets(PT.Parent.Name & "|Notes").ListObjects(1)
    With tblNotes
        On Error Resume Next
        sFormula = "="
        For lIdx = LBound(vFields) To UBound(vFields)
            lCol = Application.Match(vFields(lIdx), .HeaderRowRange, 0)
            sFormula = sFormula & "RC" & lCol & "&""|""&"
        Next lIdx
        sFormula = Left(sFormula, Len(sFormula) - 1)
        Intersect(.DataBodyRange, .ListColumns(1).Range).FormulaR1C1 = sFormula
    End With
 
'---Match KeyPhrases for each visible row of PT
    Application.EnableEvents = False
    lOffset = PT.TableRange1.Columns.Count + 1
    
    With PT.RowRange
        For lRow = 2 To .Rows.Count
            sKey = GetKey(rRowRange:=.Cells, _
                lNoteRow:=.Row + lRow - 1, vFields:=vFields)
            vReturn = Evaluate("=INDEX(" & tblNotes.Name & "[Note],MATCH(""" & _
                sKey & """," & tblNotes.Name & "[KeyPhrase],0))")
            If (Not IsError(vReturn)) Then .Cells(lRow, lOffset) = CStr(vReturn)
        Next lRow
    End With
    Application.EnableEvents = True
End Function


Private Function GetKey(rRowRange As Range, lNoteRow As Long, _
        vFields As Variant) As String
        
    Dim sFieldCurr As String, sFieldPrev As String, sNew As String, sField As String
    Dim rLabels As Range
    Dim lIdx As Long, i As Long, lPosition As Long, lCol As Long

    With rRowRange '--Compact layout
        If .PivotTable.RowFields(1).LayoutCompactRow Then
            lIdx = UBound(vFields) + 1
            Set rLabels = .Offset(1).Resize(lNoteRow - .Row)
            For i = rLabels.Rows.Count To 1 Step -1
                sField = rLabels(i).PivotField.Name
                lPosition = Application.Match(sField, vFields, 0)
                Do While lIdx > lPosition + 1
                    GetKey = "|" & GetKey
                    lIdx = lIdx - 1
                Loop
                If lPosition < lIdx Then
                    GetKey = rLabels(i).PivotItem.Name & "|" & GetKey
                    lIdx = lPosition
                    If lIdx = 1 Then Exit For
                End If
            Next i
        Else    '--Tabular or Outline layout
            For lCol = 1 To .Columns.Count
                With .Cells(lNoteRow - .Row + 1, lCol)
                    sFieldCurr = .PivotField.Name
                    sNew = IIf(sFieldCurr = sFieldPrev, "", .PivotItem.Name)
                    GetKey = GetKey & sNew & "|"
                    sFieldPrev = sFieldCurr
                End With
            Next lCol

    End With
 End Function


Public Function Update_Note_Database_Tabular(PT As PivotTable, rNote As Range)
    Dim rLabels As Range
    Dim tblNotes As ListObject
    Dim lCol As Long
    Dim iArray As Variant, i As Integer
    
'---Make new record of note at top of database table
    Set tblNotes = Sheets(PT.Parent.Name & "|Notes").ListObjects(1)
    tblNotes.ListRows.Add (1)
    tblNotes.ListColumns("Note").Range(2) = rNote.Value
    Set rLabels = Intersect(rNote.EntireRow, PT.RowRange)
   
    For lCol = rLabels.Count To 1 Step -1
        With rLabels(1, lCol)
            tblNotes.ListColumns(.PivotField.Name).Range(2) = .PivotItem.Name
        End With
    Next lCol
   

   
'---Remove any previous notes with matching rowfield values
    With tblNotes.Range
        ReDim iArray(0 To .Columns.Count - 3)
        For i = 0 To UBound(iArray)
            iArray(i) = i + 2
        Next i
        .RemoveDuplicates Columns:=(iArray), Header:=xlYes
        If rNote = vbNullString Then tblNotes.ListRows(1).Delete
    End With
   
End Function


 
Public Function Update_Note_Database(PT As PivotTable, rNote As Range)
    Dim rLabels As Range
    Dim sField As String, sItem As String
    Dim vFields As Variant, tblNotes As ListObject
    Dim lPosition As Long, lIdx As Long, lCol As Long
    Dim iArray As Variant, i As Integer
 
   ' If PT.RowFields(1).LayoutCompactRow Then '--Compact layout
    '---Make array of rowfields by position to trace each row in hierarchy
         With PT.RowFields
            ReDim vFields(1 To .Count)
            For lIdx = 1 To .Count
                vFields(PT.RowFields(lIdx).Position) = PT.RowFields(lIdx).Name
            Next lIdx
        End With
     
    '---Make new record of note at top of database table
        lIdx = lIdx + 1
       
        Set tblNotes = Sheets(PT.Parent.Name & "|Notes").ListObjects(1)
        tblNotes.ListRows.Add (1)
        tblNotes.ListColumns("Note").Range(2) = rNote.Value
        With PT.RowRange
            Set rLabels = .Offset(1).Resize(rNote.Row - .Row, 1)
            For i = rLabels.Rows.Count To 1 Step -1
                On Error Resume Next
                sField = rLabels(i).PivotField.Name
                lPosition = Application.Match(sField, vFields, 0)
                If lPosition < lIdx Then
                    sItem = rLabels(i).PivotItem.Name
                    tblNotes.ListColumns(sField).Range(2) = sItem
                    lIdx = lPosition
                    If lIdx = 1 Then Exit For
                End If
            Next i
        End With
 '   Else    '--Tabular or Outline layout
        Set tblNotes = Sheets(PT.Parent.Name & "|Notes").ListObjects(1)
        'tblNotes.ListRows.Add (1)
        tblNotes.ListColumns("Note").Range(2) = rNote.Value
        Set rLabels = Intersect(rNote.EntireRow, PT.RowRange)
       
        For lCol = rLabels.Count To 1 Step -1
            With rLabels(1, lCol)
                tblNotes.ListColumns(.PivotField.Name).Range(2) = .PivotItem.Name
            End With
        Next lCol

    
'---Remove any previous notes with matching rowfield values
    With tblNotes.Range
        ReDim iArray(0 To .Columns.Count - 3)
        For i = 0 To UBound(iArray)
            iArray(i) = i + 2
        Next i
        .RemoveDuplicates Columns:=(iArray), Header:=xlYes
        If rNote = vbNullString Then tblNotes.ListRows(1).Delete
    End With
End Function
 

Private Function NameExists(sRngName As String, _
        sSheetName As String) As Boolean
    Dim rTest As Range
    On Error Resume Next
    Set rTest = Sheets(sSheetName).Range(sRngName)
    NameExists = Not rTest Is Nothing
End Function
 

Private Function SheetExists(sSheetName As String) As Boolean
    Dim sTest As String
    On Error Resume Next
    sTest = Worksheets(sSheetName).Name
    SheetExists = LCase(sTest) = LCase(sSheetName)
End Function

PivotSheet Code:

Code:
Option Explicit


Private Sub Worksheet_Change(ByVal Target As Range)
'----When changes are made in the named range displaying
'--    PivotTable Notes, the Note database table
'--    will be updated with each New or Revised note.
 
    Dim rNotesChanged As Range, c As Range
 
    Application.ScreenUpdating = False
    If Check_Setup(Me) = False Then GoTo CleanUp
    Set rNotesChanged = Intersect(Target, _
        Range(sRngName))
    If rNotesChanged Is Nothing Then Exit Sub
    For Each c In rNotesChanged
        Call Update_Note_Database( _
            PT:=Me.PivotTables(1), _
            rNote:=c)
    Next c
CleanUp:
    Set rNotesChanged = Nothing
    Application.EnableEvents = True
    Application.ScreenUpdating = True
End Sub
 

Private Sub Worksheet_PivotTableUpdate(ByVal Target As PivotTable)
'----Refreshes display of PivotTable Notes from the Note database
'--    when the PivotTable is updated (refreshed, sorted, filtered, etc)
    If Check_Setup(Me) = False Then Exit Sub
 
    Application.ScreenUpdating = False
    Application.EnableEvents = False
 
    Call Refresh_Notes(PT:=Target)
 
    Application.EnableEvents = True
    Application.ScreenUpdating = True
End Sub
 
Upvote 0
Also, my source data has unique key that is not a row field in the pivot, is there any way to bring this into the note post as well, or are functions like this only limited to what is visible?
 
Upvote 0
Below is revised code for you to try. Using the PivotCell object allowed the handling of mixed report layout forms and also simplified the mapping of the items.

Be aware that the code won't handle many scenarios, such as reordering of the pivotfields or having a pivottable that has no rowfields or datafields.
Save a copy of your data so you won't lose your notes if the something unexpected happens.

Paste into a standard module....

Code:
Option Explicit

 
Public Const sRngName = "PT_Notes"

 
Public Function Check_Setup(ws As Worksheet) As Boolean
    Dim rNotes As Range, i As Long, bCompact As Boolean
    Dim PT As PivotTable, ptField As PivotField
    Dim tblNotes As ListObject
    Dim wsSave As Worksheet

 
'---Check if not exactly one PT on Worksheet- exit
    If ws.PivotTables.Count <> 1 Then GoTo StopNotes
    Set PT = ws.PivotTables(1)
    
'---Check if not at least one RowField and one DataField- exit
    If PT.DataFields.Count = 0 Or PT.RowFields.Count = 0 Then GoTo StopNotes
  
'---Check if Named Range "PT_Notes" doesn't exist- define it
    If Not NameExists(sRngName, ws.Name) Then
        With PT.TableRange1
            Set rNotes = Intersect(PT.DataBodyRange.EntireRow, _
                    .Resize(, 2).Offset(0, .Columns.Count))
        End With
        Set rNotes = rNotes.Resize(rNotes.Rows.Count _
            + PT.ColumnGrand)
        ws.Names.Add Name:=sRngName, RefersTo:=rNotes
        Call Format_NoteRange(rNotes)
    End If
 

'---Check if "|Notes" Worksheet doesn't exist- add it
    If Not SheetExists(ws.Name & "|Notes") Then
        Set wsSave = ActiveSheet
        Sheets.Add
        ActiveSheet.Name = ws.Name & "|Notes"
        wsSave.Activate
    End If
 

'---Check if Notes DataTable doesn't exist- add it
    With Sheets(ws.Name & "|Notes")
        On Error Resume Next
        Set tblNotes = .ListObjects(1)
        If tblNotes Is Nothing Then
            .Cells(1) = "KeyPhrase"
            .Cells(1, 2) = "Note1"
            .Cells(1, 3) = "Note2"
            Set tblNotes = .ListObjects.Add(xlSrcRange, _
                .Range("A1:C2"), , xlYes)
        End If
    End With
 

'---Check if any PT fields are not Table Headers - add
    With tblNotes
        For Each ptField In PT.RowFields
            If IsError(Application.Match(ptField.Name, .HeaderRowRange, 0)) Then
                .ListColumns.Add Position:=2
                .HeaderRowRange(1, 2) = ptField.Name
            End If
        Next ptField
    End With
    Check_Setup = True
    Exit Function
 

StopNotes:
    If NameExists(sRngName, ws.Name) Then
        Application.EnableEvents = False
        Call Clear_Notes_Range(ws)
        ws.Names(sRngName).Delete
        Application.EnableEvents = True
        Check_Setup = False
        Exit Function
    End If
End Function
 

Private Function Format_NoteRange(rNotes As Range)
'---Format body
    With rNotes
        .Interior.Color = 16316664
        .Font.Italic = True
        .HorizontalAlignment = xlLeft
        .IndentLevel = 1
        .Borders(xlInsideHorizontal).LineStyle = xlDot
        .Borders(xlBottom).LineStyle = xlDot
    End With
 
'---Format optional header
    With rNotes.Resize(1).Offset(-1)
        .Cells(1).Value = "Note1"
        .Cells(2).Value = "Note2"
        .Interior.Color = 16316664
        .Font.Italic = True
        .Font.Bold = True
        .HorizontalAlignment = xlCenter
        .Borders(xlBottom).LineStyle = xlContinuous
    End With
End Function
 

Private Function Clear_Notes_Range(ws As Worksheet)
'---Clear existing notes range
    On Error Resume Next
    Dim c As Range
    With ws.Range(sRngName)
        With .Offset(-1).Resize(.Rows.Count + 1)
            If Intersect(ws.PivotTables(1).TableRange2, _
                    .Cells) Is Nothing Then
                .ClearContents
                .ClearFormats
            Else 'PT overlaps notes
                For Each c In .Cells
                    c.ClearContents
                    c.ClearFormats
                Next c
                On Error GoTo 0
            End If
        End With
    End With
End Function
 

Public Function Refresh_Notes(PT As PivotTable)
    Dim sField As String, sKey As String, sFormula As String
    Dim ptField As PivotField
    Dim tblNotes As ListObject
    Dim rNotes As Range, c As Range
    Dim rLabels As Range, rLabelsAll As Range
    Dim vFields As Variant, vReturn As Variant
    Dim lPosition As Long, lOffset As Long
    Dim i As Long, lIdx As Long
    Dim lRow As Long, lCol As Long

    
'---Clear existing notes range
    Call Clear_Notes_Range(ws:=PT.Parent)
'---Redefine and format notes range
    With PT.TableRange1
        Set rNotes = Intersect(PT.DataBodyRange.EntireRow, _
            .Resize(, 2).Offset(0, .Columns.Count))
    End With
    Set rNotes = rNotes.Resize(rNotes.Rows.Count + PT.ColumnGrand)
    PT.Parent.Names(sRngName).RefersTo = rNotes
    Call Format_NoteRange(rNotes)
 
'---Make array of rowfields by position to trace each row in hierarchy

     With PT.RowFields
        ReDim vFields(1 To .Count)
        For lIdx = 1 To .Count
            vFields(PT.RowFields(lIdx).Position) = PT.RowFields(lIdx).Name
        Next lIdx
    End With
 
'---Build formula to use as Match KeyPhrase
    Set tblNotes = Sheets(PT.Parent.Name & "|Notes").ListObjects(1)
    With tblNotes
        On Error Resume Next
        sFormula = "="
        For lIdx = LBound(vFields) To UBound(vFields)
            lCol = Application.Match(vFields(lIdx), .HeaderRowRange, 0)
            sFormula = sFormula & "RC" & lCol & "&""|""&"
        Next lIdx
        sFormula = Left(sFormula, Len(sFormula) - 1)
        Intersect(.DataBodyRange, .ListColumns(1).Range).FormulaR1C1 = sFormula
    End With
 
'---Match KeyPhrases for each visible row of PT
    Application.EnableEvents = False
    With PT.TableRange1
        lOffset = .Column + .Columns.Count - PT.DataBodyRange.Column + 1
    End With
    
    With PT.DataBodyRange.Resize(, 1)
        For lRow = 1 To .Rows.Count + PT.ColumnGrand
            sKey = GetKey(rPC:=.Cells(lRow), vFields:=vFields)
            vReturn = Evaluate("=MATCH(""" & _
                sKey & """," & tblNotes.Name & "[KeyPhrase],0)")
            If (Not IsError(vReturn)) Then
                .Cells(lRow, lOffset) = Evaluate("=INDEX(" & tblNotes.Name & "[Note1]," & vReturn & ")")
                .Cells(lRow, lOffset + 1) = Evaluate("=INDEX(" & tblNotes.Name & "[Note2]," & vReturn & ")")
            End If
        Next lRow
    End With
    Application.EnableEvents = True
End Function


Private Function GetKey(rPC As Range, vFields As Variant) As String
    Dim i As Long
    Dim sNew As String
    
    With rPC.PivotCell.RowItems
        For i = LBound(vFields) To UBound(vFields)
            If i > .Count Then sNew = "" Else sNew = .Item(i).Caption
            GetKey = GetKey & sNew & "|"
        Next i
    End With
 End Function

Public Function Update_Note_Database(PT As PivotTable, rNote As Range)
    Dim tblNotes As ListObject
    Dim rPC As Range
    Dim iArray As Variant, i As Integer
 
    '---Make new record of note at top of database table
    Set tblNotes = Sheets(PT.Parent.Name & "|Notes").ListObjects(1)
    tblNotes.ListRows.Add (1)
    tblNotes.ListColumns("Note1").Range(2) = rNote(1).Value
    tblNotes.ListColumns("Note2").Range(2) = rNote(1, 2).Value
    
    Set rPC = Intersect(PT.DataBodyRange.Resize(, 1), rNote.EntireRow)
    With rPC.PivotCell.RowItems
        For i = 1 To .Count
            With .Item(i)
                tblNotes.ListColumns(.Parent.Name).Range(2) = .Caption
            End With
        Next i
    End With
    
'---Remove any previous notes with matching rowfield values
    With tblNotes.Range
        ReDim iArray(0 To .Columns.Count - 4)
        For i = 0 To UBound(iArray)
            iArray(i) = i + 2
        Next i
        .RemoveDuplicates Columns:=(iArray), Header:=xlYes
        If rNote(1).Value = "" And rNote(1, 2).Value = "" Then _
            tblNotes.ListRows(1).Delete
    End With
End Function
  
Private Function NameExists(sRngName As String, _
        sSheetName As String) As Boolean
    Dim rTest As Range
    On Error Resume Next
    Set rTest = Sheets(sSheetName).Range(sRngName)
    NameExists = Not rTest Is Nothing
End Function
 

Private Function SheetExists(sSheetName As String) As Boolean
    Dim sTest As String
    On Error Resume Next
    sTest = Worksheets(sSheetName).Name
    SheetExists = LCase(sTest) = LCase(sSheetName)
End Function
Paste into the sheet code module of the sheet with the pivottable....

Code:
Option Explicit

Private Sub Worksheet_Change(ByVal Target As Range)
'----When changes are made in the named range displaying
'--    PivotTable Notes, the Note database table
'--    will be updated with each New or Revised note.
 
    Dim rNotesChanged As Range, c As Range
 
    Application.ScreenUpdating = False
    If Check_Setup(Me) = False Then GoTo CleanUp
    Set rNotesChanged = Intersect(Target, _
        Range(sRngName))
    If rNotesChanged Is Nothing Then Exit Sub
    For Each c In rNotesChanged
        Call Update_Note_Database( _
            PT:=Me.PivotTables(1), _
            rNote:=Intersect(c.EntireRow, Range(sRngName)))
    Next c
CleanUp:
    Set rNotesChanged = Nothing
    Application.EnableEvents = True
    Application.ScreenUpdating = True
End Sub
 

Private Sub Worksheet_PivotTableUpdate(ByVal Target As PivotTable)
'----Refreshes display of PivotTable Notes from the Note database
'--    when the PivotTable is updated (refreshed, sorted, filtered, etc)
    If Check_Setup(Me) = False Then Exit Sub
 
    Application.ScreenUpdating = False
    Application.EnableEvents = False
 
    Call Refresh_Notes(PT:=Target)
 
    Application.EnableEvents = True
    Application.ScreenUpdating = True
End Sub
 
Upvote 0
Had to tweak this a bit to work with my data (since the first 8 fields point to locations and fields 9 through 12 are variables that can change in future runs of the data, I changed the .count and ubound to only cycle through 8)

It now works amazingly, thank you so much for your help and guidance.
 
Upvote 0
I'm also new to VB but am learning a lot from this so first of all THANKS!
This appears to work until I expand my columns - then it overwrites my notes. Works fine when expanding rows - just not columns - can you give me a hint?
 
Upvote 0
Hi Jerry,

I am trying to use this code with hyperlinks in the two columns rather than just text. This code copies the text but the hyperlink disappears. Could this be modified to work with hyperlinks. I have tried but I keep receiving errors.

btw this code is GREAT! It's very sophisticated.

Thanks,

Oz
 
Upvote 0
Hi kgettings and Oz,

Thank you for your interest in this and your kind feedback.

Those are cababilities I hadn't incorporated in the earlier versions, and they are good ideas for enhancements.

I'd like to make this code more robust since there has been more interest in it than I expected.
It's difficult because there are so many scenarios to consider.

I'll incorporate your suggestions when I do that...it probably won't be until this weekend at the earliest.
 
Upvote 0

Forum statistics

Threads
1,224,041
Messages
6,176,028
Members
452,697
Latest member
CuriousSpreadsheet

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top