Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase 1234»»»

Pulling Filename from Windows directory into table Expand / Collapse
Author
Message
Posted Tuesday, July 21, 2009 5:56 PM


SSC Veteran

SSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC Veteran

Group: General Forum Members
Last Login: Yesterday @ 10:20 AM
Points: 220, Visits: 1,176
What is the best way to go about checking a windows directory and inserting file names into a SQL table? Looking to create an control table for incoming files. Dates, rowcounts, etc.

Thanks
-tjm
Post #757081
Posted Tuesday, July 21, 2009 9:47 PM
Hall of Fame

Hall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of Fame

Group: General Forum Members
Last Login: Thursday, December 4, 2014 7:54 PM
Points: 3,087, Visits: 2,686
You could use
SSIS with the FOR EACH container
or possibly something like xp_cmdshell 'DIR c:'.
or maybe the FileSystemObject
or perhaps a small .net application

The can all give you a list of files. It really depends on what you are comfortable with.



Post #757133
Posted Tuesday, July 21, 2009 9:52 PM
Hall of Fame

Hall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of Fame

Group: General Forum Members
Last Login: Thursday, December 4, 2014 7:54 PM
Points: 3,087, Visits: 2,686
You could use
SSIS with the FOR EACH container
or possibly something like xp_cmdshell 'DIR c:'.
or maybe the FileSystemObject
or perhaps a small .net application

The can all give you a list of files. It really depends on what you are comfortable with.



Post #757134
Posted Tuesday, July 21, 2009 9:59 PM
Hall of Fame

Hall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of Fame

Group: General Forum Members
Last Login: Thursday, December 4, 2014 7:54 PM
Points: 3,087, Visits: 2,686
You could use
SSIS with the FOR EACH container
or possibly something like xp_cmdshell 'DIR c:'.
or maybe the FileSystemObject
or perhaps a small .net application

The can all give you a list of files. It really depends on what you are comfortable with.



Post #757136
Posted Tuesday, July 21, 2009 10:40 PM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Today @ 7:27 AM
Points: 35,769, Visits: 32,437
The following method is a bit slow so far as I'm concerned, but it's also pretty safe. Let me know if you need something a whole lot faster with the understanding that if they ever change the format of the DIR command output, you'll need to change a couple of settings...
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)<>'\'
&#160;
--=================================================================================================
-- 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
&#160;
-- Remember the row count
SET @DirTreeCount = @@ROWCOUNT
&#160;

--===== Update the file names with the path for ease of processing later on
UPDATE #DirTree
SET Name = @piFullPath + Name
&#160;
--=================================================================================================
-- 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
&#160;
--===== 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
&#160;
--===== 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
&#160;
--===== 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
&#160;
--===== 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
&#160;
--===== Increment the loop counter to get the next file or quit
SELECT @Counter = @Counter + 1
END
&#160;
--===== House keeping, destroy and drop the file objects to keep memory leaks from happening
EXEC sp_OADestroy @ObjFileSystem
EXEC sp_OADestroy @ObjFile
&#160;
--===== 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."

(play on words) "Just because you CAN do something in T-SQL, doesn't mean you SHOULDN'T." --22 Aug 2013

Helpful Links:
How to post code problems
How to post performance problems
Post #757142
Posted Wednesday, July 22, 2009 4:06 AM


SSC Veteran

SSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC Veteran

Group: General Forum Members
Last Login: Yesterday @ 10:20 AM
Points: 220, Visits: 1,176
Thank you. This looks interesting and I will implement into our development environment today and play around with it. When I copy your code, it pastes into one long string...??? It's only happening with your reply, no others.... Again, thanks for your help!

-tjm
Post #757278
Posted Wednesday, July 22, 2009 8:26 AM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Today @ 7:27 AM
Points: 35,769, Visits: 32,437
tjm (7/22/2009)
Thank you. This looks interesting and I will implement into our development environment today and play around with it. When I copy your code, it pastes into one long string...??? It's only happening with your reply, no others.... Again, thanks for your help!

-tjm


It's a common fault on this forum... paste it into Word first, then copy from that. That should preserve the formatting.


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

(play on words) "Just because you CAN do something in T-SQL, doesn't mean you SHOULDN'T." --22 Aug 2013

Helpful Links:
How to post code problems
How to post performance problems
Post #757472
Posted Wednesday, July 22, 2009 8:28 AM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Today @ 7:27 AM
Points: 35,769, Visits: 32,437
Again... as a reminder... sp_OA* procs tend to be quite slow at things like this. If it turns out to be too slow, post back and I'll throw the DIR "screen scraping" method at you which is very fast.

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

(play on words) "Just because you CAN do something in T-SQL, doesn't mean you SHOULDN'T." --22 Aug 2013

Helpful Links:
How to post code problems
How to post performance problems
Post #757476
Posted Wednesday, July 22, 2009 8:57 AM
Hall of Fame

Hall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of Fame

Group: General Forum Members
Last Login: Yesterday @ 10:32 PM
Points: 3,110, Visits: 11,529
This is a farily simple method:
declare @files table (cmdout nvarchar(100) )

insert into @files ( cmdout )
-- Get filenames excluding directories
exec master.dbo.xp_cmdshell 'dir C:\ /b /a:-d'

select cmdout from @files where cmdout is not null order by cmdout

Results:
cmdout                                                                                               
-------------------
AUTOEXEC.BAT
BOOT.BAK
boot.ini
cmldr
CONFIG.SYS
IO.SYS
license.txt
MSDOS.SYS
ntdetect.com
ntldr
pagefile.sys


Post #757511
Posted Wednesday, July 22, 2009 9:00 AM


SSC Veteran

SSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC Veteran

Group: General Forum Members
Last Login: Yesterday @ 10:20 AM
Points: 220, Visits: 1,176
Nope. Worked Great! Thanks for all your help!

Implemented and is already on production server.

-tjm
Post #757514
« Prev Topic | Next Topic »

Add to briefcase 1234»»»

Permissions Expand / Collapse