Home Page for the TeradataForum
 

Archives of the TeradataForum

Message Posted: Wed, 02 Apr 2003 @ 23:23:23 GMT


     
  <Prev Next>   <<First <Prev
Next>
Last>>
 


Subj:   Re: Date of Statistics
 
From:   Hough, David A

Building on Kyle Prescott's work:

select db.databasenamei as DatabaseName,
tvm.tvmnamei as TableName,
tvf.fieldname as ColumnName,
cast(
 (position(
   substring(fieldstatistics from 1 for 1)
    in 'cecfd0d1d2d3'XB)+1997
 (format '9999'))||'-'||
 (position(
   substring(fieldstatistics from 3 for 1)
    in '0102030405060708090A0B0C'XB)
 (format '99'))||'-'||
 (position(
   substring(fieldstatistics from 4 for 1)
    in =
'0102030405060708090A0B0C0D0E0F101112131415161718191A1B1C1D1E1F'XB)
 (format '99'))
as date) as CollectionDate,
cast(tvf.lastaltertimestamp as date) as LastAlter,
current_date - collectiondate as FromCurrent,
lastalter - collectiondate as FromAlter
from dbc.tvfields tvf
inner join dbc.tvm tvm
on tvm.tvmid = tvf.tableid
and tvm.tablekind in ('t','i')
inner join dbc.dbase db
on tvm.databaseid = db.databaseid
where tvf.fieldstatistics is not null;

This version is more concise, and runs a little faster because of less parse time. If you want indicators for out of range data, you can wrap NULLIF(position(...),0) around the pieces of the date string.

/dave hough



     
  <Prev Next>   <<First <Prev
Next>
Last>>
 
 
 
 
 
 
 
 
 
  
  Top Home Privacy Feedback  
 
 
Copyright for the TeradataForum (TDATA-L), Manta BlueSky    
Copyright 2016 - All Rights Reserved    
Last Modified: 15 Jun 2023