December 20, 2006 at 7:16 am
Hi,
I need to get the file size in bytes for any given file name inside a stored procedure, without using master..xp_filesize. Can somebody please help me on this.
The path and the file name is known to me.
Regards,
Rajesh Khubchandani
December 20, 2006 at 6:57 pm
Sure... right after you tell us why you can't use xp_filesize so we don't recommend something similar...
--Jeff Moden
Change is inevitable... Change for the better is not.
December 21, 2006 at 12:34 am
I cannot use xp_filesize because the i cannot make use of xpFileUtil.dll file into the sql server version which I am using. this is the restriction which has been put on me for the development. The reason which i can think of is that you need to pay some $ to access that dll.
This is the only reason which i can think of for restriction of the using xpFileUtil.dll.
so now can you please help me for the same.
December 21, 2006 at 6:59 am
Ok, thanks... isn't that the way? Company buys something and that won't let you use it which forces you to revert to undocumented features in SQL Server...
This will work in SQL Server 2000 and SQL Server 2005 and you don't need SA privs to use it... Master.dbo.xp_GetFileDetails comes with SQL Server...
EXEC Master.dbo.xp_GetFileDetails 'pathandfilenamehere'
...or...
EXEC Master.dbo.xp_GetFileDetails 'uncpathandfilenamehere'
--Jeff Moden
Change is inevitable... Change for the better is not.
December 21, 2006 at 10:51 pm
Rajesh!
Did you try it or what?
--Jeff Moden
Change is inevitable... Change for the better is not.
December 28, 2006 at 4:35 am
That's running for local files only.
When you try using UNC Path, access is denied or the authentication failed.
December 28, 2006 at 7:33 am
Yes, it will fail if your server isn't setup to "see" the path. The SQL Server "service" must be started as a power user that can "see" the UNC path you give it.
--Jeff Moden
Change is inevitable... Change for the better is not.
February 19, 2009 at 8:32 am
I see this hasn't been active for awhile, but I wanted to just thank you Jeff for the insight on that. It sure helped me!
February 19, 2009 at 8:49 am
Outstanding... thank you very much for taking the time to stop by and make a comment. All of us do this stuff for free and our only reward is comments such as yours. Thanks.
--Jeff Moden
Change is inevitable... Change for the better is not.
February 20, 2009 at 1:33 pm
Jeff,
What I was trying to do was find a means of getting a file listing so I could scedule a job to delete files that were say two weeks or more old. So because of your assistance, I was able to come up with this stored procedure that basically recreates the "dir" command to a table.
Now that's acting stable, I can now move on to making a procedure that references this one to delete files based on date, size, name, or whatever.
Thanks again and have a great weekend!
Tony
create procedure [dbo].[sproc_utility_Dir]
(
@pathvarChar ( 1000 ) = 'c:'
)
as
begin
declare
@isDirectorybit,
@namevarChar ( 0255 ),
@pathFilevarChar ( 1255 ),
@commandnvarChar ( 4000 ),
@resultint
set nocount on
create table
#commandLineOutput
(
rowvarChar ( 0400 ),
flagbit
)
create table #detail
(
[isDirectory]bit,
[path]varChar ( 1000 ),
[name]varChar ( 0255 ),
[pathFile]varChar ( 1255 ),
[Alternate Name]varChar ( 0255 ),
[Size]int,
[Creation Date]varChar ( 0010 ),
[Creation Time]varChar ( 0010 ),
[Last Written Date]varChar ( 0010 ),
[Last Written Time]varChar ( 0010 ),
[Last Accessed Date]varChar ( 0010 ),
[Last Accessed Time]varChar ( 0010 ),
[Attributes]int
)
select
@command = 'dir "' + @path + '\*.*" /b /a:d /o:n',
@result = 0
insert into
#commandLineOutput
(
row
)
execute@result = master.dbo.xp_cmdshell
@command
if (@result <> 0)
begin
select
[isDirectory],
[path],
[name],
[pathFile],
[Alternate Name],
[Size],
[Creation Date],
[Creation Time],
[Last Written Date],
[Last Written Time],
[Last Accessed Date],
[Last Accessed Time],
[Attributes]
from
#detail
where
0 > 1
drop table#commandLineOutput
drop table#detail
return@result
end
update
#commandLineOutput
set
flag = 1
where
flag is null
select
@command = 'dir "' + @path + '\*.*" /b /a:-d /o:n',
@result = 0
insert into
#commandLineOutput
(
row
)
execute@result = master.dbo.xp_cmdshell
@command
if (@result <> 0)
begin
select
[isDirectory],
[path],
[name],
[pathFile],
[Alternate Name],
[Size],
[Creation Date],
[Creation Time],
[Last Written Date],
[Last Written Time],
[Last Accessed Date],
[Last Accessed Time],
[Attributes]
from
#detail
where
0 > 1
drop table#commandLineOutput
drop table#detail
return@result
end
update
#commandLineOutput
set
flag = 0
where
flag is null
delete
from
#commandLineOutput
where
row is null
declareloopingcursor
forselect[flag],
[row]
from#commandLineOutput
openlooping
fetch next fromlooping
into @isDirectory,
@name
while (@@fetch_status = 0)
begin
select@pathFile = @path + '\' + @name
insert into #detail
(
[Alternate Name],
[Size],
[Creation Date],
[Creation Time],
[Last Written Date],
[Last Written Time],
[Last Accessed Date],
[Last Accessed Time],
[Attributes]
)
execute @result = master.dbo.xp_GetFileDetails
@pathFile
if (@result = 0)
begin
if (@isDirectory = 0)
begin
update
#detail
set
[isDirectory] = @isDirectory,
[path] = @path,
[name] = @name,
[pathFile] = @pathFile,
[Creation Time] = replicate('0', 6 - len([Creation Time])) + [Creation Time],
[Last Written Time] = replicate('0', 6 - len([Last Written Time])) + [Last Written Time],
[Last Accessed Time] = replicate('0', 6 - len([Last Accessed Time])) + [Last Accessed Time]
where
[isDirectory] is null
and[path] is null
and[name] is null
and[pathFile] is null
end
else if (@isDirectory = 1)
begin
update
#detail
set
[isDirectory] = @isDirectory,
[path] = @path,
[name] = @name,
[pathFile] = @pathFile + '\',
[Creation Time] = replicate('0', 6 - len([Creation Time])) + [Creation Time],
[Last Written Time] = replicate('0', 6 - len([Last Written Time])) + [Last Written Time],
[Last Accessed Time] = replicate('0', 6 - len([Last Accessed Time])) + [Last Accessed Time]
where
[isDirectory] is null
and[path] is null
and[name] is null
and[pathFile] is null
end
end
fetch next fromlooping
into @isDirectory,
@name
end
closelooping
deallocatelooping
select
[isDirectory],
[path],
[name],
[pathFile],
[Alternate Name],
[Size],
convert(varChar ( 10 ), cast([Creation Date] as dateTime), 101) as [Creation Date],
subString([Creation Time], 1, 2) + ':' + subString([Creation Time], 3, 2) + ':' + subString([Creation Time], 5, 2) as [Creation Time],
convert(varChar ( 10 ), cast([Last Written Date] as dateTime), 101) as [Last Written Date],
subString([Last Written Time], 1, 2) + ':' + subString([Last Written Time], 3, 2) + ':' + subString([Last Written Time], 5, 2) as [Last Written Time],
convert(varChar ( 10 ), cast([Last Accessed Date] as dateTime), 101) as [Last Accessed Date],
subString([Last Accessed Time], 1, 2) + ':' + subString([Last Accessed Time], 3, 2) + ':' + subString([Last Accessed Time], 5, 2) as [Last Accessed Time],
[Attributes]
from
#detail
order by
[isDirectory] desc,
name asc
drop table#commandLineOutput
drop table#detail
end
February 20, 2009 at 2:22 pm
Wow, what's happened to dir?
_____________
Code for TallyGenerator
February 20, 2009 at 2:24 pm
Thanks for sharing your hard earned code. Here's an alternative that doesn't involve (essentially) "screen scraping" a DOS window and doesn't use xp_CMDShell... In 2k5, we could probably avoid the loop, as well.
[font="Courier New"]
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
EXEC dbo.GetDirDetails 'c:\temp'
[/font]
--Jeff Moden
Change is inevitable... Change for the better is not.
February 20, 2009 at 2:26 pm
I need to be able to schedule a job in SQL Server to delete files in a directory that are two weeks or more old. Erase and delete don't seem to have a means for deleting based on date and time. I know I could use For in a batch script but I couldn't find a way to test for the file's date and time that way. I could just write a vb script, but then I get nervous bringing down the server if the script has an unforeseen issue.
The results from the procedure will get me a table basically that I can select from by date, name, or whatever. Unless there's a better way, I know this is a bit overkill.
Tony
February 20, 2009 at 2:30 pm
Hey, yours works really well! And I'm using SQL Server 2000 no less. After working on my previuos procedure I saw how that xp_GetFileDetails left in 2005.
Thanks again!
Tony
February 20, 2009 at 6:14 pm
Heh... yeah... I wish MS would figure out that T-SQL is a great place to do ETL from and that you don't really need SSIS... in fact, if you hold your mouth just right, it seems like you can do a lot more in T-SQL than SSIS unless you count all the Active-X scripts that folks write. I'm working on replacing a DTS step that splits and "impossible-to-import" file that they used a Perl script on... the Perl script takes 40 minutes just to get the data ready for import. The T-SQL I've written to do the same job weighs in at about 27 seconds.
It would be nice if they'd stop removing features... undocumented features like xp_GetFileDetails and xp_DirTree (available in 2k, 2k5, and 2k8) should be documented and kept because they're bloody useful.
--Jeff Moden
Change is inevitable... Change for the better is not.
Viewing 15 posts - 1 through 15 (of 26 total)
You must be logged in to reply to this topic. Login to reply