Pivot Table that takes data only till current date

PresidentEvil

New Member
Joined
Jan 2, 2021
Messages
34
Office Version
  1. 2021
  2. 2016
Platform
  1. Windows
Hi All,

I'm trying to write a macro where in the final output is a pivot table with counts of transaction, name of processor, along with Follow up date.

Since the data I'm dealing with is in large number, I need only the data till 'current follow up data' and not future date. There is no specific start date since the data is dynamic in nature. But end date will be the system date.

Please provide me a code which gives me my desired output. Thanks in advance

Below is the code I'm using:

VBA Code:
Range("A1:R1").Select
    Selection.AutoFilter
    ActiveSheet.Range("$A$1:$R$885").AutoFilter Field:=11, Criteria1:="<>" 'Field here is Follow up date column
    Range("A1").Select
    Range(Selection, Selection.End(xlToRight)).Select
    Range(Selection, Selection.End(xlDown)).Select
    Selection.Copy
    Workbooks.Add
    ActiveSheet.Paste
     Range("A1").Select
    Range(Selection, Selection.End(xlToRight)).Select
    Range(Selection, Selection.End(xlDown)).Select
    ActiveSheet.ListObjects.Add(xlSrcRange, Range("$A$1:$S$670"), , xlYes).Name = _
        "Table1"
    Range("A2").Select
    ActiveSheet.ListObjects("Table1").Name = "MyData1"
    Application.CutCopyMode = False
    Sheets.Add
    ActiveWorkbook.PivotCaches.Create(SourceType:=xlDatabase, SourceData:= _
        "MyData1", Version:=6).CreatePivotTable TableDestination:="Sheet2!R3C1", _
        TableName:="PivotTable1", DefaultVersion:=6
    Sheets("Sheet2").Select
    Cells(3, 1).Select
    With ActiveSheet.PivotTables("PivotTable1").PivotFields("Processed by") 'name of individual who processed the transactions
        .Orientation = xlRowField
        .Position = 1
    End With
        With ActiveSheet.PivotTables("PivotTable1").PivotFields("Follow up Date") 'this is what I'm talking about. This field has future dates too which I don't want in my table.
        .Orientation = xlRowField
        .Position = 2
    End With
    With ActiveSheet.PivotTables("PivotTable1").PivotFields("Follow Up Status")
        .Orientation = xlColumnField
        .Position = 1
    End With
    ActiveSheet.PivotTables("PivotTable1").AddDataField ActiveSheet.PivotTables( _
        "PivotTable1").PivotFields("Transactions"), "Count of Transactions", xlCount
    Windows("Book1").Activate
    Cells.Select
    Selection.Copy
    Workbooks(1).Activate
    Sheets("My Sheet").Select
    Range("A1").Select
    ActiveSheet.Paste
    Range("C5").Select
    Application.WindowState = xlNormal
    Workbooks(2).Activate
    Application.DisplayAlerts = False
    ActiveWindow.Close
    Application.DisplayAlerts = True
    Windows("Book1").Activate
    Application.DisplayAlerts = False
    ActiveWindow.Close
    Application.DisplayAlerts = True
 

Excel Facts

Can you AutoAverage in Excel?
There is a drop-down next to the AutoSum symbol. Open the drop-down to choose AVERAGE, COUNT, MAX, or MIN
VBA Code:
    Dim sDate As String
    sDate = Date
    ActiveSheet.PivotTables("PivotTable1").PivotFields("Follow up Date").ClearAllFilters
    ActiveSheet.PivotTables("PivotTable1").PivotFields("Follow up Date").PivotFilters.Add2 Type:=xlBefore, Value1:=sDate
 
Upvote 0
Solution
VBA Code:
    Dim sDate As String
    sDate = Date
    ActiveSheet.PivotTables("PivotTable1").PivotFields("Follow up Date").ClearAllFilters
    ActiveSheet.PivotTables("PivotTable1").PivotFields("Follow up Date").PivotFilters.Add2 Type:=xlBefore, Value1:=sDate
Thanks. Will try this code and let you know the outcome.

Also there is '(blanks)' created in my pivot table below the required data. Also I've verified from the source data. It does have blanks cells which are the ones from where the table ends and blank cells begin. Is there a solution to remove that 'blanks' from the table? Please note that 'Blanks' is appearing in both row as well as the columns.
 
Upvote 0
VBA Code:
    For Each pField In ActiveSheet.PivotTables("PivotTable1").PivotFields
        On Error Resume Next
        pField.PivotItems("(blank)").Visible = False
    Next
 
Upvote 0
VBA Code:
    Dim sDate As String
    sDate = Date
    ActiveSheet.PivotTables("PivotTable1").PivotFields("Follow up Date").ClearAllFilters
    ActiveSheet.PivotTables("PivotTable1").PivotFields("Follow up Date").PivotFilters.Add2 Type:=xlBefore, Value1:=sDate
I checked this and I'm getting Application-defined or object defined error. Is it something to do with where this code is used in my macro?

Sorry, I'm new to vba and trying to understand as much as I can.
 
Upvote 0
Okay, so I've finally fixed the runtime error. It was a simple error of not converting the date format (of follow up date column) from 'General' format to 'short date' format. And hence it wasn't taking the xlBefore as the 'Type'.

Made the correction to the source data and now the macro is working fine.

@mart37 Thank you for the codes. :)
 
Upvote 0

Forum statistics

Threads
1,224,823
Messages
6,181,184
Members
453,020
Latest member
Mohamed Magdi Tawfiq Emam

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