How to get file date using xp_cmdshell?

  • Hi,

    I have a file in my C: directory, using SQL, I am trying to get the date of that file.  I used below query to get the outpu.

    exec master..xp_cmdshell 'dir C:\AH.aspx'

    By using this query, I got the below output.

     Volume in drive C is OS

     Volume Serial Number is 0831-E01D

    NULL

     Directory of C:\

    NULL

    09/11/2006  02:35 PM             2,477 AH.aspx

                   1 File(s)          2,477 bytes

                   0 Dir(s)  17,976,348,672 bytes free

    NULL

    I have transferred the output to a file and tried to get date.  Instead of doing in this way, is there any other way that we can get date directly of that file?

    Regards,

    Mahesh

  • Do you want to try this one:

    CREATE TABLE #tmp (strData VARCHAR(1000))

    INSERT INTO #tmp EXEC xp_cmdshell 'dir c:\myFile'

    SELECT * FROM #tmp WHERE strData LIKE '%/%/%'

    DROP TABLE #tmp

  • You can get a lot more than just the date...

    EXEC Master.dbo.xp_GetFileDetails 'C:\AH.aspx'

    --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 Jeff .  Got more details with this command.

    Regards,

    Mahesh

  • You're welcome...

    I've verified that it's available in both SQL Server 2000 and 2005.  Dunno if it will be available in 2008.

    --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)

  • It is not available in SQL 2008. Does anyone have a code for this SP?

  • Naomi N (11/3/2011)


    It is not available in SQL 2008. Does anyone have a code for this SP?

    I do. This one (it's older and could use a couple of updates) uses sp_OA* procs and is a little bit slow as a result. I also have one that uses xp_CmdShell that's quite a bit faster and allows wildcards. Of course, that one won't do you much good unless you know how to lock down a system properly so that only stored procedures can run xp_CmdShell...

    CREATE PROCEDURE dbo.GetDirDetails

    /**************************************************************************************************

    Purpose:

    Replacement code for the sp_GetFileDetails proc that was available in SQL Server 2000

    which is no longer available in SQL Server 2005 except this gets all the file details

    for all the files in the directory provided.

    Notes:

    1. If the directory does not exist or there are no files in the directory, an empty

    result set will be returned.

    2. If the trailing backslash on the path is missing, it will be added automatically.

    3. No error checking is done. Either a valid result set is returned or an empty

    result set is returned (much like a function operates).

    Usage:

    EXEC dbo.GetDirDetails 'drive:path or UNC'

    Example:

    EXEC dbo.GetDirDetails 'C:\Temp'

    ... or ...

    EXEC dbo.GetDirDetails 'C:\Temp\'

    Revision History:

    Rev 00 - 05/23/2008 - Jeff Moden

    - Initial concept borrowed from Simple-Talk.com (Phil Factor) and

    modified for multiple files.

    Rev 01 - 05/25/2008 - Jeff Moden

    - Formalize the code for use.

    **************************************************************************************************/

    --===== Declare the I/O parameters

    @piFullPath VARCHAR(128)

    AS

    --===== Suppress the auto-display of rowcounts so as not to interfere with the returned

    -- result set

    SET NOCOUNT ON

    --=================================================================================================

    -- Local variables

    --=================================================================================================

    --===== These are processing control and reporting variables

    DECLARE @Counter INT --General purpose counter

    DECLARE @CurrentName VARCHAR(256) --Name of file currently being worked

    DECLARE @DirTreeCount INT --Remembers number of rows for xp_DirTree

    DECLARE @IsFile BIT --1 if Name is a file, 0 if not

    --===== These are object "handle" variables

    DECLARE @ObjFile INT --File object

    DECLARE @ObjFileSystem INT --File System Object

    --===== These variable names match the sp_OAGetProperty options

    -- Made names match so they're less confusing

    DECLARE @Attributes INT --Read only, Hidden, Archived, etc, as a bit map

    DECLARE @DateCreated DATETIME --Date file was created

    DECLARE @DateLastAccessed DATETIME --Date file was last read (accessed)

    DECLARE @DateLastModified DATETIME --Date file was last written to

    DECLARE @Name VARCHAR(128) --File Name and Extension

    DECLARE @Path VARCHAR(128) --Full path including file name

    DECLARE @ShortName VARCHAR(12) --8.3 file name

    DECLARE @ShortPath VARCHAR(100) --8.3 full path including file name

    DECLARE @Size INT --File size in bytes

    DECLARE @Type VARCHAR(100) --Long Windows file type (eg.'Text Document',etc)

    --=================================================================================================

    -- Create temporary working tables

    --=================================================================================================

    --===== Create a place to store all file names derived from xp_DirTree

    IF OBJECT_ID('TempDB..#DirTree','U') IS NOT NULL

    DROP TABLE #DirTree

    CREATE TABLE #DirTree

    (

    RowNum INT IDENTITY(1,1),

    Name VARCHAR(256) PRIMARY KEY CLUSTERED,

    Depth BIT,

    IsFile BIT

    )

    --===== Create a place to store the file details so we can return all the file details

    -- as a single result set

    IF OBJECT_ID('TempDB..#FileDetails','U') IS NOT NULL

    DROP TABLE #FileDetails

    CREATE TABLE #FileDetails

    (

    RowNum INT IDENTITY(1,1) PRIMARY KEY CLUSTERED,

    Name VARCHAR(128), --File Name and Extension

    Path VARCHAR(128), --Full path including file name

    ShortName VARCHAR(12), --8.3 file name

    ShortPath VARCHAR(100), --8.3 full path including file name

    DateCreated DATETIME, --Date file was created

    DateLastAccessed DATETIME, --Date file was last read

    DateLastModified DATETIME, --Date file was last written to

    Attributes INT, --Read only, Compressed, Archived

    ArchiveBit AS CASE WHEN Attributes& 32=32 THEN 1 ELSE 0 END,

    CompressedBit AS CASE WHEN Attributes&2048=2048 THEN 1 ELSE 0 END,

    ReadOnlyBit AS CASE WHEN Attributes& 1=1 THEN 1 ELSE 0 END,

    Size INT, --File size in bytes

    Type VARCHAR(100) --Long Windows file type (eg.'Text Document',etc)

    )

    --=================================================================================================

    -- Make sure the full path name provided ends with a backslash

    --=================================================================================================

    SELECT @piFullPath = @piFullPath+'\'

    WHERE RIGHT(@piFullPath,1)<>'\'

    --=================================================================================================

    -- Get all the file names for the directory (includes directory names as IsFile = 0)

    --=================================================================================================

    --===== Get the file names for the desired path

    -- Note that xp_DirTree is available in SQL Server 2000, 2005, and 2008.

    INSERT INTO #DirTree (Name, Depth, IsFile)

    EXEC Master.dbo.xp_DirTree @piFullPath,1,1 -- Current diretory only, list file names

    -- Remember the row count

    SET @DirTreeCount = @@ROWCOUNT

    --===== Update the file names with the path for ease of processing later on

    UPDATE #DirTree

    SET Name = @piFullPath + Name

    --=================================================================================================

    -- Get the properties for each file. This is one of the few places that a WHILE

    -- loop is required in T-SQL because sp_OA is as dumb as a fart-sack full of broken antlers.

    --=================================================================================================

    --===== Create a file system object and remember the "handle"

    EXEC dbo.sp_OACreate 'Scripting.FileSystemObject', @ObjFileSystem OUT

    --===== Step through the file names and get the properties for each file.

    SET @Counter = 1

    WHILE @Counter <= @DirTreeCount

    BEGIN

    --===== Get the current name and see if it's a file

    SELECT @CurrentName = Name,

    @IsFile = IsFile

    FROM #DirTree

    WHERE RowNum = @Counter

    --===== If it's a file, get the details for it

    IF @IsFile = 1 AND @CurrentName LIKE '%%'

    BEGIN

    --===== Create an object for the path/file and remember the "handle"

    EXEC dbo.sp_OAMethod @ObjFileSystem,'GetFile', @ObjFile OUT, @CurrentName

    --===== Get the all the required attributes for the file itself

    EXEC dbo.sp_OAGetProperty @ObjFile, 'Path', @Path OUT

    EXEC dbo.sp_OAGetProperty @ObjFile, 'ShortPath', @ShortPath OUT

    EXEC dbo.sp_OAGetProperty @ObjFile, 'Name', @Name OUT

    EXEC dbo.sp_OAGetProperty @ObjFile, 'ShortName', @ShortName OUT

    EXEC dbo.sp_OAGetProperty @ObjFile, 'DateCreated', @DateCreated OUT

    EXEC dbo.sp_OAGetProperty @ObjFile, 'DateLastAccessed', @DateLastAccessed OUT

    EXEC dbo.sp_OAGetProperty @ObjFile, 'DateLastModified', @DateLastModified OUT

    EXEC dbo.sp_OAGetProperty @ObjFile, 'Attributes', @Attributes OUT

    EXEC dbo.sp_OAGetProperty @ObjFile, 'Size', @Size OUT

    EXEC dbo.sp_OAGetProperty @ObjFile, 'Type', @Type OUT

    --===== Insert the file details into the return table

    INSERT INTO #FileDetails

    (Path, ShortPath, Name, ShortName, DateCreated,

    DateLastAccessed, DateLastModified, Attributes, Size, Type)

    SELECT @Path,@ShortPath,@Name,@ShortName,@DateCreated,

    @DateLastAccessed,@DateLastModified,@Attributes,@Size,@Type

    END

    --===== Increment the loop counter to get the next file or quit

    SELECT @Counter = @Counter + 1

    END

    --===== House keeping, destroy and drop the file objects to keep memory leaks from happening

    EXEC sp_OADestroy @ObjFileSystem

    EXEC sp_OADestroy @ObjFile

    --===== Return the details for all the files as a single result set.

    -- This is one of the few places in T-SQL where SELECT * is ok.

    -- If you don't think so, go look at some of the MS stored procedures. ;-)

    SELECT * FROM #FileDetails

    GO

    --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)

  • in 2008 and above, i think the expectation is to start switching over to CLR;

    here's the CLR equivilent of xp_GetFileDetails:

    Imports System.Data.SqlClient

    Imports System.Data.SqlTypes

    Imports Microsoft.SqlServer.Server

    Imports System.IO

    Namespace Enterprise.SqlServer.Server

    Public Partial Class GetFileDetails

    <Microsoft.SqlServer.Server.SqlProcedure()> _

    Public Shared Sub csp_getfiledetails(ByVal filePath As String)

    Try

    Dim fileProperties As New FileInfo(filePath)

    Dim colAlternateName As New SqlMetaData("Alternate Name", SqlDbType.NVarChar, 4000)

    Dim colSize As New SqlMetaData("Size", SqlDbType.BigInt)

    Dim colCreationDate As New SqlMetaData("Creation Date", SqlDbType.NChar, 8)

    Dim colCreationTime As New SqlMetaData("Creation Time", SqlDbType.NChar, 6)

    Dim colLastWrittenDate As New SqlMetaData("Last Written Date", SqlDbType.NChar, 8)

    Dim colLastWrittenTime As New SqlMetaData("Last Written Time", SqlDbType.NChar, 6)

    Dim colLastAccessedDate As New SqlMetaData("Last Accessed Date", SqlDbType.NChar, 8)

    Dim colLastAccessedTime As New SqlMetaData("Last Accessed Time", SqlDbType.NChar, 6)

    Dim colAttributes As New SqlMetaData("Attributes", SqlDbType.Int)

    Dim record As New SqlDataRecord(New SqlMetaData() {colAlternateName, colSize, colCreationDate, colCreationTime, colLastWrittenDate, colLastWrittenTime, _

    colLastAccessedDate, colLastAccessedTime, colAttributes})

    record.SetInt64(1, fileProperties.Length)

    record.SetString(2, fileProperties.CreationTime.ToString("yyyyMMdd"))

    record.SetString(3, fileProperties.CreationTime.ToString("HHmmss"))

    record.SetString(4, fileProperties.LastWriteTime.ToString("yyyyMMdd"))

    record.SetString(5, fileProperties.LastWriteTime.ToString("HHmmss"))

    record.SetString(6, fileProperties.LastAccessTime.ToString("yyyyMMdd"))

    record.SetString(7, fileProperties.LastAccessTime.ToString("HHmmss"))

    Dim splitter As Char() = {","c}

    Dim attributes As String() = fileProperties.Attributes.ToString().Split(splitter)

    Dim attributesInt__1 As Integer = 0

    For Each attributesString As String In attributes

    Dim fileAttributes As FileAttributes = DirectCast([Enum].Parse(GetType(FileAttributes), attributesString), FileAttributes)

    attributesint += CInt(fileAttributes)

    Next

    record.SetInt32(8, attributesInt__1)

    record.SetInt32(8, CInt(fileProperties.Attributes))

    SqlContext.Pipe.Send(record)

    Catch myexception As Exception

    Throw (myexception)

    End Try

    End Sub

    End Class

    End Namespace

    Lowell


    --help us help you! If you post a question, make sure you include a CREATE TABLE... statement and INSERT INTO... statement into that table to give the volunteers here representative data. with your description of the problem, we can provide a tested, verifiable solution to your question! asking the question the right way gets you a tested answer the fastest way possible!

  • Thank you both!

  • Jeff,

    That looks like ever so much fun.

    I can't wait to try it.

    We're trying to manage updates to third party reporting software and need to deal with variable update times.

    Just wait for a newer file and away we go.

    Thanks

  • Thanks but if you can use CLR, the solution that Lowell posted is better.

    --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)

  • I don't know if its too late to answer or not . here is the way to get date .

    CREATE TABLE #mytable ( Line VARCHAR(512))

    SET @PathName = '\\uncpath\foldername\flodername\foldername\' --if you have unc path else use c:\ etc.

    SET @CMD = 'DIR ' + @PathName + ' /TC'

    INSERT INTO #mytable

    EXEC MASTER..xp_cmdshell @CMD

    DELETE FROM #mytable

    WHERE Line NOT LIKE '[0-9][0-9]/[0-9][0-9]/[0-9][0-9][0-9][0-9] %'

    OR Line LIKE '%<DIR>%'

    OR Line is null

    SELECT TOP 1 FILENAME ,Createdate into ##Onlydate_formytab FROM

    (SELECT TOP 1000 REVERSE( LEFT(REVERSE(Line),CHARINDEX(' ',REVERSE(line))-1 ) ) AS FILENAME ,

    ---1 need to change if you have space in source filename like 'my excel name 20130202.xlsx'

    right(LEFT(Line,10),4)+LEFT(left(Line,10),2)+SUBSTRING(LEFT(line,10),4,2)

    as Createdate FROM #mytable ORDER BY REVERSE( LEFT(REVERSE(Line),CHARINDEX(' ',REVERSE(line))-1 ) ) DESC)s

    plz mark as answer if this answer your question

  • Thank you! Much more straightforward than other solutions seen, i.e., you just delete the lines that don't match the date mask. Nice!

  • HI Jeff,

    Is this possible to club the details of all the folders/files if one mentions any location/path???

    This one is only working against files and a v nice one as it says what kind of filetype they are. But kind of consolidation would be great.

    Thanks.

  • Hi Lowell

    To run your script, do I need to use vb.net alone or any other way available?

    Thanks.

Viewing 15 posts - 1 through 15 (of 15 total)

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