July 7, 2011 at 5:22 am
Deee -Daah! (7/6/2011)
I originated this thread in 2008. Below is the alternate approach:1) create a batch file with the following code to list files in folders and subfolders:
@echo off
cd c:\MyFolder
FOR /R %%i IN (*.*) DO @echo %%~tfzi > c:\myfolder\mylist.txt
2) bulk insert into a temp table where you can manipulate the contents and loop.
You can call the batch file using XP_CMDSHELL (assuming your environment allows it),
then bulk insert after it. Alternatively, you can also call the batch file from SQL Agent. maybe as the first step.
I know it looks so simple, but that's how it is really. If you can create the listing and you can insert into a table, T-SQL will be sufficient to do the rest.:-D
Enjoy!
I'm not sure what I did wrong but after putting your code into a batch file (changed C:\MyFolder to C:\Temp everywhere) and executing the batch file, I get the following error.
IN(*.*) was unexpected at this time.
Besides, if that does what I think it does, there's just no need for such complexity. The following will give you a list of file names for the identified Drive:\Directory (with wild cards, if you need to) along with their full Drive:\path...filename.extension...
DIR C:\Temp /S /B
If you want the output to go to a file (an unnecessary complication if you're using xp_CmdShell), just add the redirection operator and the target file name.
DIR C:\Temp /S /B > Dir.txt
{Edit} Apologies... for some reason, I can't make the " & g t ; " change to a "greater than" carat this time. It will need to be replaced in real code.
--Jeff Moden
Change is inevitable... Change for the better is not.
July 7, 2011 at 5:29 am
ken_wenze (7/6/2011)
Jeff - This looks pretty good but how would i modify this to loop through every sub directory in a folder such as C:\MyFolder
Hi Ken,
Are you allowed to use xp_CmdShell?
--Jeff Moden
Change is inevitable... Change for the better is not.
July 7, 2011 at 8:04 am
Yes - I can use the cmdshell but C:\ in that command would be the servers C:...the directory i need to gather from is on my local desktop.
July 7, 2011 at 9:59 am
ken_wenze (7/7/2011)
Yes - I can use the cmdshell but C:\ in that command would be the servers C:...the directory i need to gather from is on my local desktop.
Not a problem. All you need to do is build a "share" that SQL Server can see and then use a UNC to your machine.
--Jeff Moden
Change is inevitable... Change for the better is not.
July 7, 2011 at 10:31 am
DIR C:\temp /s >gt list.txt does not give you the fullpath of the files. The output looks more like this:
Directory of C:\temp\test1\test2
and then followed by the file listing.
July 8, 2011 at 7:41 am
Deee -Daah! (7/7/2011)
DIR C:\temp /s >gt list.txt does not give you the fullpath of the files. The output looks more like this:Directory of C:\temp\test1\test2
and then followed by the file listing.
Of course it doesn't and, if you look closely, that's NOT what I posted. You're missing the /B switch. 😉 This is what I posted...
DIR C:\Temp /S /B > Dir.txt
--Jeff Moden
Change is inevitable... Change for the better is not.
July 8, 2011 at 12:39 pm
I guess if filedates and sizes are not required then /B (bare) switch will work just fine.;-)
Otherwise, DIR does not have a switch that has the filedates, sizes and fullpath altogether in one row.
July 8, 2011 at 8:09 pm
Deee -Daah! (7/8/2011)
I guess if filedates and sizes are not required then /B (bare) switch will work just fine.;-)Otherwise, DIR does not have a switch that has the filedates, sizes and fullpath altogether in one row.
Heh... gosh... I knew that... Otherwise, I'd have posted a different solution. 😉
Since I couldn't get your batch file to run (not sure why it's giving an error), can you show us the example output of that batch file, please?
--Jeff Moden
Change is inevitable... Change for the better is not.
July 11, 2011 at 1:57 pm
Hi Jeff,
Below is the sample output:
09/04/2009 10:39 AM 722432 C:\temp\input1.xls
This should run fine on the command line:
FOR /R %i IN (*.*) DO @echo %%~tfzi
For some reason, running it on the command line requires only one percent symbol.
But inside a batch file, it needs two!
Thanks
July 12, 2011 at 7:49 am
The need to double-up on % for the variable is to escape the % because there are other variables that use % as a lead character in batch code.
Clever use of the "i" variable. Nicely done. It's a shame they didn't "columnize" the number of bytes but that's not insurmountable by any means.
--Jeff Moden
Change is inevitable... Change for the better is not.
July 13, 2011 at 7:42 am
Are you allowed to use CLR?
I got fed up with a number of work-arounds I had to get file information, so I created a CLR-based TVF to return several attributes of files in a passed-in directory. This made it easy to get things like the filename both with and without the file extension, the archive bit (which I really needed, so I could run an agent job and look for backup files that didn't go off to tape), etc.
This was one of my first forays into CLR, and the syntax of creating a TVF was a little odd to me, but there were some excellent examples here:
http://nclsqlclrfile.codeplex.com/[/url]
and here:
http://www.sqlservercentral.com/articles/SQLCLR/65656/[/url]
that I used as go-bys.
Rich
July 29, 2014 at 9:27 am
I am using SQL 2012, wanting to use DirTree to capture folder/subfolders within a share on a server - I can path to the UNC via Windows explorer with no issue - as it uses the local admins auth to that share via that method, however when xp_dirtree runs the credentials it uses are anonymous. can i use SetCred someplace to have windows store the credentials and put the user name in my script?
thanks!
April 2, 2015 at 8:44 am
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
April 2, 2015 at 6:26 pm
Stephen Swan (4/2/2015)
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
You're welcome but just expanding the range of the DirTree doesn't solve the problem of subdirectories. When I run the code above, it returns many duplicates and none of the subdirectory information.
--Jeff Moden
Change is inevitable... Change for the better is not.
April 3, 2015 at 10:22 am
I know I'm somewhat late to the show, haven't read through the whole trail and therefore might be missing something, but my approach would be the xp_cmdshell with "dir /S /N /C" and then filter and parse the results, in my experience it's much more efficient than creating an OLE Object.
😎
Viewing 15 posts - 31 through 45 (of 54 total)
You must be logged in to reply to this topic. Login to reply