Reading File attributes (datecreated,datemodified....) using sp_OACreate....

  • Hi All,

    Here I have a code to read file attributes......however 'am geting no result through this......any idea....

    DECLARE @hr int,@object int,@objfile int,@datecreated int,

    @path varchar(200),@filename varchar(100)

    set @filename='c:\setup.txt'

    EXEC @hr=sp_oacreate 'Scripting.FileSystemObject',@object OUT

    print @hr

    if @hr=0 exec sp_OAmethod @object,'GetFile',@objfile out,@filename

    --print @objfile

    if @hr=0 EXEC @hr=sp_OAGetProperty @objfile,'Path',@path out

    print @path

    Regards,
    [font="Verdana"]Sqlfrenzy[/font]

  • I just ran the following on my server... only thing I changed was the file name to match a file I had.

    DECLARE @hr int,@object int,@objfile int,@datecreated int,

    @path varchar(200),@filename varchar(100)

    set @filename='c:\Sample.txt'

    EXEC @hr=sp_oacreate 'Scripting.FileSystemObject',@object OUT

    print @hr

    if @hr=0 exec sp_OAmethod @object,'GetFile',@objfile out,@filename

    --print @objfile

    if @hr=0 EXEC @hr=sp_OAGetProperty @objfile,'Path',@path out

    print @path

    I got the expected output...

    [font="Courier New"]0

    C:\Sample.txt[/font]

    If I run it for a file that doesn't exist or that the server can't "see", then I just get the 0 for successfully creating the FSO object.

    I guess my question would be, which machine is your C:\setup.txt file on. If it's not on the server, it's not going to see it because "C:\" refers to the "C" drive on the server... not the box you're running the code from.

    In order for the code to work and see a file on your box instead of the server, you must use a full UNC path and the necessary privs must be granted so the server actually has the rights to see the file. The easiest way is to have the SQL Server SERVICE login as a user with full domain privs.

    --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....I ran this command on my machine and setup.txt file do exist........

    well....I will try this wid some other file name.....one more I have evaluation edition ......

    Regards,
    [font="Verdana"]Sqlfrenzy[/font]

  • Ahmad Osama (11/16/2008)


    I ran this command on my machine and setup.txt file do exist........

    You need to read the rest of my previous post... SQL Server CANNOT see your drive as "C:\"... you MUST use a UNC with your machine name AND the SERVER must be logged in as a domain deity.

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

  • Hi Jeff,

    How to traverse a directory/subdirectory to save all file into a table.....

    Regards,
    [font="Verdana"]Sqlfrenzy[/font]

  • Ahmad Osama (11/17/2008)


    Hi Jeff,

    How to traverse a directory/subdirectory to save all file into a table.....

    What is your exact requirement ?

  • I have to compare the file in 2 directories based on their modified date.

    Regards,
    [font="Verdana"]Sqlfrenzy[/font]

  • Ahmad Osama (11/17/2008)


    Hi Jeff,

    How to traverse a directory/subdirectory to save all file into a table.....

    One problem at a time... have you gotten to the point where you can see one file?

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

  • Jeff Moden (11/17/2008)


    Ahmad Osama (11/17/2008)


    Hi Jeff,

    How to traverse a directory/subdirectory to save all file into a table.....

    One problem at a time... have you gotten to the point where you can see one file?

    Yes....

    Regards,
    [font="Verdana"]Sqlfrenzy[/font]

  • Show me your code so I can modify it for you.

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

  • Jeff Moden (11/19/2008)


    Show me your code so I can modify it for you.

    the code is same as posted earlier......I don't know how to traverse the directories....do u have a logic for this....

    Regards,
    [font="Verdana"]Sqlfrenzy[/font]

  • Well, kinda... 😉 It doesn't use xp_CmdShell, but it does (I'm a bit embarrassed but couldn't be helped with sp_OA* in SQL Server 2000, that I know of) use a WHILE loop and the sp_OA* procs. Maybe the saving grace is, it returns a single result set. 😛

    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.

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

    --===== 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.

    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)

  • Damned smiley faces... see attached, please...

    --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 ...I was running short of time....so I decided to do this in SSIS......

    I will certainly review your code....actualy...I think its better to write these things rather than doing it on a GUI.....

    Regards,
    [font="Verdana"]Sqlfrenzy[/font]

  • I'm of the same ilk... 🙂

    Lemme know what you think when you've had a chance to run the code. Thanks.

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

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

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