• Displaying “Last Updated” Date And Time In PowerPivot

    We use PowerPivot to display key information in dashboards, some of which can be refreshed right up to the current second. Naturally, one of the first questions asked when looking at the reports (particularly if they get printed) is “When was the data last updated?”

    Personally, I struggled with this for a while. I could tell when the most current record in the database file was, but that’s sometimes not enough. As we run a golf course, we have days with no revenue due to snow or heavy rain. And in that case, we actually want to know that no revenue was present, so picking up the last posted transaction just doesn’t cut it.

    The solution to this is actually really easy though. It consists of three steps:
    1. Create a simple SQL query
    2. Create a measure
    3. Create an OLAP Cube formula

    (Please note that the steps listed are for PowerPivot 2012, but an alternate tip for 2008 is provided at the bottom of the article.)

    Creating the SQL Query

    To begin with, you need to go into PowerPivot and create a connection to your database. These steps assume that you already have a connection in place to one (or more) of these databases.

    To start with:
    • Go to PowerPivot-->Design-->Existing Connections
    • Select your existing PowerPivot Data Connection and click “Open”
    • Choose “Write a query that will specify the data to import” and click “Next”
    • Enter the appropriate SQL Query as shown below:
    SQL Server: SELECT GETDATE() AS Updates
    Microsoft Access: SELECT NOW() AS Updates
    • Click Validate to ensure your SQL is well formed
    • Click Finish

    At this point, you’ll have a one cell table that looks something like this:

    The nice thing here is that every time you update your PowerPivot data, the query will run and return the date/time stamp that you did so.

    Creating The Measure

    The next step is that we need to create a measure to return the max value from the Updates column. Now granted, there will only ever be one value in there, but creating the measure allows us to talk to the OLAP formula later.

    Go to the measures pane (at the bottom of the table) and enter the following formula in the first cell of the first column:
    Code:
    LastUpdated:=MAX([Updates])
    Once done, your table should now look like this:

    Returning LastUpdated To Excel

    Now, you could build a one cell PivotTable on your worksheet to return this info, but then you’d have to refresh it all the time. And that’s way too much work. Instead, drop the following CUBE formula into a cell:
    Code:
    =CUBEVALUE("PowerPivot Data",CUBEMEMBER("PowerPivot Data","[Measures].[LastUpdated]"))
    You’ll probably also want to:
    • Right click the cell
    • Choose Format Cell-->Number-->Custom
    • Place the following in the “Type” area: yyyy-mm-dd h:mm:ss AM/PM
    • Click OK

    Of course, you could also skip all that, and just place the following formula in a cell too:
    Code:
    ="Last Updated "&TEXT(CUBEVALUE("PowerPivot Data",CUBEMEMBER("PowerPivot Data","[Measures].[LastUpdated]")),"yyyy-mm-dd h:mm:ss AM/PM")
    And that's it! Now every time the database is refreshed, the LastUpdated measure will be updated as well.

    Notes For Developing With PowerPivot 2008

    Unfortunately it’s not quite as easy to create a measure in the first version of PowerPivot. While steps 1 and 3 remain the same, you’ll need to create a PivotTable to get your measure.

    The basic steps are to create a PivotTable, drop the Updates field in to the Values area, and change it to show the Max. You’ll then be able to reference the name of that measure in the OLAP formula.

     

    I'm afraid that you must be logged in to comment or leave a testimonial. I wish it could be otherwise, but I'm trying to keep my site spam free for everyone's benefit. If you don't yet have an account it's completely free to sign up, and a very quick process. Simply click here to Register. Not only can you post a comment here, but it gives you full access to posts questions in our forum as well!

     

    If you already have an account, and just haven't logged in yet, what are you waiting for? Login Now!

  • MVP Logo
  • Recent Forum Posts

    AndyDuncombe

    Worksheet named from cell

    this is truly incredible! In an ideal worls I'd like to use data validation to populate the names that show in column A...

    AndyDuncombe Today, 08:58 PM Go to last post
    Jodie

    IF Formula

    I’m looking for help with a formula that will only do calculation based on if there is data in a cell. Example: ColumnA is an enrollment date but is...

    Jodie Today, 08:11 PM Go to last post
    Bob Phillips

    Worksheet named from cell

    I have made that change. I named the sheets as ddd d mmm as it takes less space, is just as clear, and means you see more roster sheets at one time. Each...

    Bob Phillips Today, 08:05 PM Go to last post
    AndyDuncombe

    Worksheet named from cell

    Which I'd like to rename as Sunday 2 Jan + sunday 9 Jan etc or whatever variant will fit. I think this would call from the app settings sheet data in...

    AndyDuncombe Today, 06:27 PM Go to last post
    Bob Phillips

    Worksheet named from cell

    The title does reflect that, do you mean the sheet name? Your example had sheet names WEEK 1 and WEEK 2....

    Bob Phillips Today, 03:30 PM Go to last post