May 15, 2013 at 3:05 pm
I need this for an outside application to create a DB using the default. Currently we use:
DECLARE @SQL_path nvarchar(256)
SELECT TOP 1 @SQL_path = SUBSTRING(filename, 1, CHARINDEX(N'master.mdf', LOWER(filename)) - 1)
FROM [master].[sys].[sysdatabases]
This is not really effective if the master is on another drive from the default. We can't use cmdshell to get to the settings. Command shell could be turned off in the instance I am trying to install a database to. Is this the best I can do or is there a way to get at that server mdf/ldf default when creating the database?
May 15, 2013 at 3:33 pm
BACKUP default directory
http://www.sqlservercentral.com/Forums/Topic1319398-1550-1.aspx
/*
In case it was not clear in Jason's post, the @key parameter value remain consistent
across all of your instances. The proc he is calling does proper registry resolution
for us depending on the instance we run it from. That is the beauty of master.sys.xp_instance_regread, as opposed to master.sysxp_regread
which requires the literal path to the registry location you want.
If you were using master.sys.xp_regread your calls would need
to be different across all of your 5-10 instances.
*/
EXECUTE [master].dbo.xp_instance_regread
N'HKEY_LOCAL_MACHINE',
N'SOFTWARE\Microsoft\MSSQLServer\MSSQLServer', N'BackupDirectory'
Lowell
May 15, 2013 at 4:21 pm
That got me to the right spot with that link
Declare @datadir nvarchar(4000)
,@logdir nvarchar(4000)
EXEC master.dbo.xp_instance_regread
N'HKEY_LOCAL_MACHINE'
, N'Software\Microsoft\MSSQLServer\MSSQLServer'
, N'DefaultData'
, @datadir output;
IF @datadir IS NULL
BEGIN
EXEC master.dbo.xp_instance_regread
N'HKEY_LOCAL_MACHINE'
, N'Software\Microsoft\MSSQLServer\Setup'
, N'SQLDataRoot'
, @datadir output;
END
EXEC master.dbo.xp_instance_regread
N'HKEY_LOCAL_MACHINE'
, N'Software\Microsoft\MSSQLServer\MSSQLServer'
, N'DefaultLog'
, @logdir output;
SELECT @datadir as Data_directory, ISNULL(@logdir,@datadir) as Log_directory
That being said it is magic. I am not sure how it is coming back with the right answer. I searched the registry and did a search for the result and both came back empty. I am going to give this a try and see if it gets past testing. Thanks
Viewing 3 posts - 1 through 2 (of 2 total)
You must be logged in to reply to this topic. Login to reply