• I modified Jeff's procedure to allow for subfolders. I put a maxDepth parameter into it for some control as needed. Thanks Jeff for the code.

    ALTER 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'

    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.

    Rev 02- 04/02/2015 - Stephen Swan

    - Altered code to allow for subdirectories

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

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

    @piFullPath VARCHAR(128), @maxDepth INT

    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

    DECLARE @DirTree TABLE

    (

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

    Name VARCHAR(256),

    Depth INT,

    IsFile INT,

    ParentNum VARCHAR(255),

    FilePath VARCHAR(255)

    )

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

    DECLARE @FileDetails TABLE

    (

    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, @maxDepth, 1

    -- Mark Parent Directory id

    UPDATE d

    SET d.ParentNum = (SELECT MAX(DT.RowNum) FROM @DirTree DT WHERE DT.Depth = d.Depth - 1 AND DT.RowNum < d.RowNum)

    FROM @DirTree d;

    -- Recurse through records to put together folder names

    WITH CTE AS (

    SELECT RowNum, CAST(Name as nvarchar(255)) as Name,

    Depth, ParentNum, CAST('' as nvarchar(255)) as Parent

    FROM @DirTree WHERE ParentNum IS NULL

    UNION ALL

    SELECT d.RowNum, CAST(d.Name as nvarchar(255)),

    d.Depth, d.ParentNum, CAST(CTE.Name as nvarchar(255))

    FROM @DirTree d

    INNER JOIN CTE ON d.ParentNum = CTE.RowNum

    )

    UPDATE DT

    SET FilePath = CASE WHEN CTE.ParentNum IS NULL THEN @piFullPath ELSE @piFullPath + ISNULL(CTE.Parent + '\','') END

    FROM CTE

    INNER JOIN @DirTree DT ON CTE.RowNum = DT.RowNum

    -- Remove folders from listing as they are no longer necessary

    DELETE FROM @DirTree

    WHERE IsFile <> 1

    -- Remember the row count

    SELECT @DirTreeCount = COUNT(1) FROM @DirTree

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

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

    SELECT @CurrentName = FilePath + Name

    FROM @DirTree

    WHERE RowNum = @Counter

    IF @CurrentName IS NOT NULL BEGIN

    --===== Get File Details

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