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

Default mdf/ldf directory at the server level Expand / Collapse
Author
Message
Posted Wednesday, May 15, 2013 3:05 PM
SSC-Addicted

SSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-Addicted

Group: General Forum Members
Last Login: Thursday, March 27, 2014 9:32 AM
Points: 415, Visits: 595
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?
Post #1453277
Posted Wednesday, May 15, 2013 3:33 PM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Today @ 2:26 PM
Points: 12,744, Visits: 31,071
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

--There is no spoon, and there's no default ORDER BY in sql server either.
Actually, Common Sense is so rare, it should be considered a Superpower. --my son
Post #1453282
Posted Wednesday, May 15, 2013 4:21 PM
SSC-Addicted

SSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-Addicted

Group: General Forum Members
Last Login: Thursday, March 27, 2014 9:32 AM
Points: 415, Visits: 595
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
Post #1453287
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse