something like PIVOT?

  • I have a table that stores a tablename, the last time the table was accessed and when that data was put into the table:

    CREATE TABLE [dbo].[LastSelectCheck](

    [TableName] [nvarchar](128) NULL,

    [LastSelect] [datetime] NULL,

    [RunDate] [datetime] NOT NULL,

    [Server] [nvarchar](128) NULL

    ) ON [PRIMARY]

    GO

    It’s populated every night by a select from sys.dm_db_index_usage_stats.

    My question: I’d like to run a query that shows the last select over a week’s time, like this:

    Tablename day1 day2 day3

    --------------------------------------------------------------------------------

    tblOrder 2013-04-08 NULL 2013-04-10

    tblOrder2 2013-04-08 2013-04-09 NULL

    I realize I can do this thru a series of CTE, temp tables or joins but it seems that there’s something more elegant out there. I tried PIVOT but it doesn’t look like it’ll work here as I'm not aggregating and the columns are not items from the tables.

    Any advice? TIA.

    Sample data:

    insert into LastSelectCheck2 values ('tblOrder', NULL, '2013-04-08', 'MyServer1')

    insert into LastSelectCheck2 values ('tblOrder2', '2013-04-08', '2013-04-08', 'MyServer1')

    insert into LastSelectCheck2 values ('tblOrder3', NULL, '2013-04-08', 'MyServer1')

    insert into LastSelectCheck2 values ('tblOrder4', '2013-04-08', '2013-04-08', 'MyServer1')

    insert into LastSelectCheck2 values ('tblOrder', '2013-04-09', '2013-04-09', 'MyServer1')

    insert into LastSelectCheck2 values ('tblOrder2', '2013-04-09', '2013-04-09', 'MyServer1')

    insert into LastSelectCheck2 values ('tblOrder3', '2013-04-09', '2013-04-09', 'MyServer1')

    insert into LastSelectCheck2 values ('tblOrder4', '2013-04-09', '2013-04-09', 'MyServer1')

    insert into LastSelectCheck2 values ('tblOrder', '2013-04-10', '2013-04-10', 'MyServer1')

    insert into LastSelectCheck2 values ('tblOrder2', '2013-04-10', '2013-04-10', 'MyServer1')

    insert into LastSelectCheck2 values ('tblOrder3', NULL, '2013-04-10', 'MyServer1')

    insert into LastSelectCheck2 values ('tblOrder4', NULL, '2013-04-10', 'MyServer1')

    ----------------------------------------------------------------------------
    Sacramento SQL Server users group - http://sac.sqlpass.org
    Follow me on Twitter - @SQLDCH
    ----------------------------------------------------------------------------

    Yeah, well...The Dude abides.
  • SQLDCH (4/12/2013)


    I have a table that stores a tablename, the last time the table was accessed and when that data was put into the table:

    CREATE TABLE [dbo].[LastSelectCheck](

    [TableName] [nvarchar](128) NULL,

    [LastSelect] [datetime] NULL,

    [RunDate] [datetime] NOT NULL,

    [Server] [nvarchar](128) NULL

    ) ON [PRIMARY]

    GO

    It’s populated every night by a select from sys.dm_db_index_usage_stats.

    My question: I’d like to run a query that shows the last select over a week’s time, like this:

    Tablename day1 day2 day3

    --------------------------------------------------------------------------------

    tblOrder 2013-04-08 NULL 2013-04-10

    tblOrder2 2013-04-08 2013-04-09 NULL

    I realize I can do this thru a series of CTE, temp tables or joins but it seems that there’s something more elegant out there. I tried PIVOT but it doesn’t look like it’ll work here as I'm not aggregating and the columns are not items from the tables.

    Any advice? TIA.

    Sample data:

    insert into LastSelectCheck2 values ('tblOrder', NULL, '2013-04-08', 'MyServer1')

    insert into LastSelectCheck2 values ('tblOrder2', '2013-04-08', '2013-04-08', 'MyServer1')

    insert into LastSelectCheck2 values ('tblOrder3', NULL, '2013-04-08', 'MyServer1')

    insert into LastSelectCheck2 values ('tblOrder4', '2013-04-08', '2013-04-08', 'MyServer1')

    insert into LastSelectCheck2 values ('tblOrder', '2013-04-09', '2013-04-09', 'MyServer1')

    insert into LastSelectCheck2 values ('tblOrder2', '2013-04-09', '2013-04-09', 'MyServer1')

    insert into LastSelectCheck2 values ('tblOrder3', '2013-04-09', '2013-04-09', 'MyServer1')

    insert into LastSelectCheck2 values ('tblOrder4', '2013-04-09', '2013-04-09', 'MyServer1')

    insert into LastSelectCheck2 values ('tblOrder', '2013-04-10', '2013-04-10', 'MyServer1')

    insert into LastSelectCheck2 values ('tblOrder2', '2013-04-10', '2013-04-10', 'MyServer1')

    insert into LastSelectCheck2 values ('tblOrder3', NULL, '2013-04-10', 'MyServer1')

    insert into LastSelectCheck2 values ('tblOrder4', NULL, '2013-04-10', 'MyServer1')

    I don't know if this query can be useful for you:

    SELECT (TableName+''+ISNULL(CONVERT(CHAR(10),LastSelect,120 ),' ')+''+ISNULL(CONVERT(CHAR(10),(RunDate),120),' ')+''+[Server]+' ')TEXT,TableName INTO #TEST

    FROM LastSelectCheck2

    select TEXT INTO #TEXTS

    from #test

    order by TABLENAME

    SELECT DISTINCT 'Table name day1day2day3'

    union all

    select TEXT

    from #TEXTS

    Best Regards

  • SQLDCH (4/12/2013)


    I have a table that stores a tablename, the last time the table was accessed and when that data was put into the table:

    CREATE TABLE [dbo].[LastSelectCheck](

    [TableName] [nvarchar](128) NULL,

    [LastSelect] [datetime] NULL,

    [RunDate] [datetime] NOT NULL,

    [Server] [nvarchar](128) NULL

    ) ON [PRIMARY]

    GO

    It’s populated every night by a select from sys.dm_db_index_usage_stats.

    My question: I’d like to run a query that shows the last select over a week’s time, like this:

    Tablename day1 day2 day3

    --------------------------------------------------------------------------------

    tblOrder 2013-04-08 NULL 2013-04-10

    tblOrder2 2013-04-08 2013-04-09 NULL

    I realize I can do this thru a series of CTE, temp tables or joins but it seems that there’s something more elegant out there. I tried PIVOT but it doesn’t look like it’ll work here as I'm not aggregating and the columns are not items from the tables.

    Any advice? TIA.

    Sample data:

    insert into LastSelectCheck2 values ('tblOrder', NULL, '2013-04-08', 'MyServer1')

    insert into LastSelectCheck2 values ('tblOrder2', '2013-04-08', '2013-04-08', 'MyServer1')

    insert into LastSelectCheck2 values ('tblOrder3', NULL, '2013-04-08', 'MyServer1')

    insert into LastSelectCheck2 values ('tblOrder4', '2013-04-08', '2013-04-08', 'MyServer1')

    insert into LastSelectCheck2 values ('tblOrder', '2013-04-09', '2013-04-09', 'MyServer1')

    insert into LastSelectCheck2 values ('tblOrder2', '2013-04-09', '2013-04-09', 'MyServer1')

    insert into LastSelectCheck2 values ('tblOrder3', '2013-04-09', '2013-04-09', 'MyServer1')

    insert into LastSelectCheck2 values ('tblOrder4', '2013-04-09', '2013-04-09', 'MyServer1')

    insert into LastSelectCheck2 values ('tblOrder', '2013-04-10', '2013-04-10', 'MyServer1')

    insert into LastSelectCheck2 values ('tblOrder2', '2013-04-10', '2013-04-10', 'MyServer1')

    insert into LastSelectCheck2 values ('tblOrder3', NULL, '2013-04-10', 'MyServer1')

    insert into LastSelectCheck2 values ('tblOrder4', NULL, '2013-04-10', 'MyServer1')

    You can use either a Pivot or a Cross Tab for this. What you have to realize is that you're pivoting text or dates. Instead of using SUM, use MAX as a "text aggregate" to pivot the data.

    --Jeff Moden


    RBAR is pronounced "ree-bar" and is a "Modenism" for Row-By-Agonizing-Row.
    First step towards the paradigm shift of writing Set Based code:
    ________Stop thinking about what you want to do to a ROW... think, instead, of what you want to do to a COLUMN.

    Change is inevitable... Change for the better is not.


    Helpful Links:
    How to post code problems
    How to Post Performance Problems
    Create a Tally Function (fnTally)

  • Thanks for the replies.

    After applying the MAX aggregate to the [LastSelect] column, the second part of my dilemma was solved by creating another column with the ten digit date using the CONVERT function. It gave me specific items to pivot on. For giggles I threw in the 'day of the week' column.

    Here's the updated DDL and some sample data in case this could help someone else:

    CREATE TABLE [dba_admin].[dbo].[LastSelectCheck](

    [TableName] [nvarchar](128) NULL,

    [LastSelect] [datetime] NULL,

    [RunDate] [datetime] NOT NULL,

    [Server] [nvarchar](128) NULL,

    [DotW] [int] NULL, -- Day of the week

    [TenDigDate] [char](10) NULL -- Ten Digit Date

    )

    -- Top part of the CTE is from http://beyondrelational.com/modules/1/justlearned/0/tips/9111/sql-server-finding-last-accessed-time-for-tables-by-queries-or-find-unused-tables.aspx

    WITH LastActivity (ObjectID, LastAction) AS

    (

    SELECT OBJECT_ID AS TableName,

    last_user_seek AS LastAction

    FROM sys.dm_db_index_usage_stats u

    WHERE database_id = DB_ID(DB_NAME())

    UNION

    SELECT OBJECT_ID AS TableName,

    last_user_scan AS LastAction

    FROM sys.dm_db_index_usage_stats u

    WHERE database_id = DB_ID(DB_NAME())

    UNION

    SELECT OBJECT_ID AS TableName,

    last_user_lookup AS LastAction

    FROM sys.dm_db_index_usage_stats u

    WHERE database_id = DB_ID(DB_NAME())

    )

    INSERT INTO [dba_admin].[dbo].[LastSelectCheck]

    SELECT OBJECT_NAME(so.OBJECT_ID) AS TableName,

    MAX(la.LastAction) AS LastSelect,

    getdate() as 'RunDate',

    @@servername as 'Server',

    datepart(dw, getdate()) as 'DotW',

    convert(char(10), getdate(), 112) as 'TenDigDate'

    FROM sys.objects so

    LEFT JOIN LastActivity la

    ON so.OBJECT_ID = la.ObjectID

    WHERE so.TYPE = 'U'

    AND so.OBJECT_ID > 100

    GROUP BY OBJECT_NAME(so.OBJECT_ID)

    ORDER BY OBJECT_NAME(so.OBJECT_ID)

    Find which days the table has been accessed:

    select tablename, [20130408], [20130409], [20130410]

    from

    (

    select tablename, LastSelect

    ,TenDigDate

    from LastSelectCheck

    where tablename like 'ACCOUNT%'

    ) as LSC

    pivot

    (

    max(LastSelect)

    for TenDigDate in ([20130408], [20130409], [20130410])

    ) as P

    ----------------------------------------------------------------------------
    Sacramento SQL Server users group - http://sac.sqlpass.org
    Follow me on Twitter - @SQLDCH
    ----------------------------------------------------------------------------

    Yeah, well...The Dude abides.

Viewing 4 posts - 1 through 3 (of 3 total)

You must be logged in to reply to this topic. Login to reply