Consulting

Results 1 to 4 of 4

Thread: VBA code for pivot-filter

  1. #1
    VBAX Newbie
    Joined
    Oct 2011
    Posts
    2
    Location

    VBA code for pivot-filter

    Hi, i'm having a problem with the VBA code for changing the report-filter in a pivot table.
    Today i'm manually typing in the date in the vba code, as seen below (the date is in the format YYYYMMDD, in this case 20111001):

    [VBA]ActiveSheet.PivotTables("Pivottabell1").PivotFields( _
    "[Invoice Date].[Calendar].[Date]").VisibleItemsList = Array("", _
    "[Invoice Date].[Calendar].[Date].&[20111001]")

    Instead of manually typing in the date in the code i want enter a value in the form YYYYMMDD and save it in to a Long variable and then be able to use this variable instead of manually typing in the date. Below is the code that i tried to use where "Day" is the variable containing the date.


    Dim Day As Long
    Day = InputBox("Insert date in format: YYYYMMDD")

    ActiveSheet.PivotTables("Pivottabell1").PivotFields( _
    "[Invoice Date].[Calendar].[Date]").VisibleItemsList = Array("", _
    "[Invoice Date].[Calendar].[Date].&[Day]")[/VBA]

    Unfortunately this doesn't work. I am going to use the value "Day" to update a number of pivot tables and that's why i can't type it in manually each time. Thankful for all your help!

    /Martin

  2. #2
    VBAX Guru mancubus's Avatar
    Joined
    Dec 2010
    Location
    "Where I lay my head is home" :D
    Posts
    2,644
    hi cii04mh5.
    wellcome to VBAX.

    try this...

    [VBA]
    Sub PvtTest()

    Dim pvtDate As String, pvtCrt As String
    Dim Day As Date

    pvtDate = Application.InputBox("Insert date")

    If IsDate(pvtDate) Then
    Day = DateValue(pvtDate)
    Else
    MsgBox "Please enter a valid date"
    Exit Sub
    End If

    pvtCrt = Format(Day, "yyyymmdd")

    'your code here

    End Sub
    [/VBA]
    PLS DO NOT PM; OPEN A THREAD INSTEAD!!!

    1) Posting Code
    [CODE]PasteYourCodeHere[/CODE]
    (or paste your code, select it, click # button)

    2) Uploading File(s)
    Go Advanced / Attachments - Manage Attachments / Add Files / Select Files / Select the file(s) (multiple files can be selected while holding Ctrl key) / Upload Files / Done
    Replace company specific / sensitive / confidential data. Include so many rows and sheets etc in the uploaded workbook to enable the helpers visualize the data and table structure. Helpers do not need the entire workbook.

    3) Testing the Codes
    always back up your files before testing the codes.

    4) Marking the Thread as Solved
    from Thread Tools (on the top right corner, above the first message)

  3. #3
    VBAX Master Aflatoon's Avatar
    Joined
    Sep 2009
    Location
    UK
    Posts
    1,723
    Location
    Your last line would need to be:
    [vba]ActiveSheet.PivotTables("Pivottabell1").PivotFields( _
    "[Invoice Date].[Calendar].[Date]").VisibleItemsList = Array("", _
    "[Invoice Date].[Calendar].[Date].&[" & Day & "]") [/vba]

    so that you concatenate the Day variable into the field string.
    Be as you wish to seem

  4. #4
    VBAX Newbie
    Joined
    Oct 2011
    Posts
    2
    Location
    Thanks a lot! Now it works fine.

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •