June 27, 2008 at 12:51 pm
I'm struggling to find a way to get the default data and log locations using t-sql. Is there a way to either do this without reading the registry? if not, does anyone have a script that will grab those values from the registry regardless of default/named instance?
I have one that works well for default instance, but I need one I can drop on any server and have it grab those values correctly.
Any help would be greatly appreciated.
Thanks
June 27, 2008 at 1:39 pm
Data:
-- ***************************************************************************
-- nvarchar(4000) = dbo.fn_SQLServerDataDir()
-- ***************************************************************************
IF OBJECT_ID('SQLServerDataDir_fn','FN') IS NOT NULL
DROP FUNCTION SQLServerDataDir_fn
GO
create function dbo.SQLServerDataDir_fn()
returns nvarchar(4000)
as
begin
declare @rc int,
@dir nvarchar(4000)
exec @rc = master.dbo.xp_instance_regread N'HKEY_LOCAL_MACHINE',N'Software\Microsoft\MSSQLServer\MSSQLServer',N'DefaultData', @dir output, 'no_output'
if (@dir is null)
begin
exec @rc = master.dbo.xp_instance_regread N'HKEY_LOCAL_MACHINE',N'Software\Microsoft\MSSQLServer\Setup',N'SQLDataRoot', @dir output, 'no_output'
select @dir = @dir + N'\Data'
end
return @dir
end
Log
-- ***************************************************************************
-- nvarchar(4000) = dbo.SQLServerLogDir_fn()
-- ***************************************************************************
IF OBJECT_ID('SQLServerLogDir_fn','FN') IS NOT NULL
DROP FUNCTION SQLServerLogDir_fn
GO
create function dbo.SQLServerLogDir_fn()
returns nvarchar(4000)
as
begin
declare @rc int,
@dir nvarchar(4000)
exec @rc = master.dbo.xp_instance_regread N'HKEY_LOCAL_MACHINE',N'Software\Microsoft\MSSQLServer\MSSQLServer',N'DefaultLog', @dir output, 'no_output'
if (@dir is null)
begin
exec @rc = master.dbo.xp_instance_regread N'HKEY_LOCAL_MACHINE',N'Software\Microsoft\MSSQLServer\Setup',N'SQLDataRoot', @dir output, 'no_output'
select @dir = @dir + N'\Data'
end
return @dir
end
Viewing 2 posts - 1 through 1 (of 1 total)
You must be logged in to reply to this topic. Login to reply