July 24, 2008 at 5:47 pm
Hi experts,
I was wondering if there is an alternative to running XP_cmdshell DIR.
Basically, I run xp_cmdshell to gather file info on a folder.
without using XP_cmdshell, is there other method?
Thank you for the help.
July 24, 2008 at 7:48 pm
there are also sp_OA* procedures...
* Noel
July 24, 2008 at 10:32 pm
If you want to try a new technology, Powershell can do this.
Do you want info inside SQL Server for something?
July 25, 2008 at 4:31 am
Deee -Daah! (7/24/2008)
Hi experts,I was wondering if there is an alternative to running XP_cmdshell DIR.
Basically, I run xp_cmdshell to gather file info on a folder.
without using XP_cmdshell, is there other method?
Thank you for the help.
If all you need is filenames, try this...
EXEC Master.dbo.xp_DirTree "filepath or UNC",1,1
If you need it in a table, create a table similar to the output of that, and use INSERT/EXEC to populate it.
If you need more than just file names, post back.
--Jeff Moden
Change is inevitable... Change for the better is not.
July 25, 2008 at 5:03 pm
Hi Jeff, thank you. I think this will work. But I also need the filesize & filedates. I can store them in a #temp table.
Best Regards,
Michael
July 25, 2008 at 8:46 pm
Try this, Michael... It's not done yet, but it'll do what you want without hitting up 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'
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
Change is inevitable... Change for the better is not.
July 27, 2008 at 12:02 am
Hope this article will answer your question,
http://venkattechnicalblog.blogspot.com/2008/06/finding-subdirectories-and-directory.html
Thanks and Regards,
Venkatesan Prabu, 😛
My Blog:
http://venkattechnicalblog.blogspot.com/
July 28, 2008 at 9:51 am
Jeff, thank you very much. This is perfect.
Kindest Regards,
Michael
July 28, 2008 at 5:49 pm
You bet... thanks for the feedback, Micheal. 🙂
--Jeff Moden
Change is inevitable... Change for the better is not.
August 20, 2010 at 2:56 pm
Jeff -
I adapted your code above and it works most of the time except when I want to get the size of compressed backup files created by Quest LiteSpeed. In this case, the file size is returned as NULL. I was wondering if you know of any workaround for this problem.
Thanks in advance.
August 21, 2010 at 11:24 am
chrs-513176 (8/20/2010)
Jeff -I adapted your code above and it works most of the time except when I want to get the size of compressed backup files created by Quest LiteSpeed. In this case, the file size is returned as NULL. I was wondering if you know of any workaround for this problem.
Thanks in advance.
I have no idea what Quest LiteSpeed does to the file size, if anything. What do you see for those files if you do a DIR on the that same directory? Also, if a file is in the process of being built, it very well could return a NULL for file size.
--Jeff Moden
Change is inevitable... Change for the better is not.
August 22, 2010 at 9:05 am
Perhaps the file size is more than 2GB?
Anyways, have you tried using SQLCLR for this?
N 56°04'39.16"
E 12°55'05.25"
August 22, 2010 at 8:01 pm
SwePeso (8/22/2010)
Perhaps the file size is more than 2GB?Anyways, have you tried using SQLCLR for this?
Yep... that could certainly be it. There are other things we can do. I have to admit, though... a properly written CLR with some wildcard and other capabilities would probably do very well here.
--Jeff Moden
Change is inevitable... Change for the better is not.
August 23, 2010 at 7:21 am
The file size is greater than 2GB. Is that the max this method can return? Unfortunately, I'm still on 2000 so CLR is not an option for me.
August 23, 2010 at 7:38 am
You know you posted your question in a SQL Server 2005 forum?
N 56°04'39.16"
E 12°55'05.25"
Viewing 15 posts - 1 through 15 (of 54 total)
You must be logged in to reply to this topic. Login to reply