---------------------------------------------------------------------------------- -- Author : htl258(Tony) -- Date : 2010-06-26 21:51:30 -- Version: Microsoft SQL Server 2008 (RTM) - 10.0.1600.22 (Intel X86) -- Jul 9 2008 14:43:34 -- Copy
----------------------------------------------------------------------------------
-- Author : htl258(Tony)
-- Date : 2010-06-26 21:51:30
-- Version: Microsoft SQL Server 2008 (RTM) - 10.0.1600.22 (Intel X86)
-- Jul 9 2008 14:43:34
-- Copyright (c) 1988-2008 Microsoft Corporation
-- Developer Edition on Windows NT 5.1
-- Blog : (转载保留此信息)
-- Subject: SQL查询与修改数据库逻辑文件名,移动数据库存储路径示例
----------------------------------------------------------------------------------
USE mydb
GO
--1.查询当前数据库的逻辑文件名
SELECT FILE_NAME(1) AS 'File Name 1', FILE_NAME(2) AS 'File Name 2';
--或通过以下语句查询:
--SELECT name FROM sys.database_files
/*
File Name 1 File Name 2
------------------- --------------------
mydb mydb_log
(1 行受影响)
*/
--2.修改数据文件或日志文件的逻辑名称
ALTER DATABASE [mydb]
MODIFY FILE ( NAME = mydb, NEWNAME = new_mydb )
ALTER DATABASE [mydb]
MODIFY FILE ( NAME = mydb_log, NEWNAME = new_mydb_log )
--查询更改后的名称:
SELECT FILE_NAME(1) AS 'File Name 1', FILE_NAME(2) AS 'File Name 2';
/*
File Name 1 File Name 2
------------------- --------------------
new_mydb new_mydb_log
(1 行受影响)
*/
--3.若要将数据文件或日志文件移至新位置,先OFFLINE把文件MOVE到相应的位置,然后再ONLINE
-- 详细参考以下步骤
--3.1 查询数据文件或日志文件当前存放路径:
SELECT physical_name FROM sys.database_files
/*
physical_name
-------------------------------------------------------------------------------------------
D:/Program Files/Microsoft SQL Server/MSSQL10.MSSQLSERVER/MSSQL/DATA/mydb.mdf
D:/Program Files/Microsoft SQL Server/MSSQL10.MSSQLSERVER/MSSQL/DATA/mydb_log.ldf
(2 行受影响)
*/
--3.2 移动路径
USE [master]
GO
--3.2.1 关闭所有进程
DECLARE @str VARCHAR(500);
SET @str = '';
SELECT @str = @str + 'KILL '+RTRIM(spid)+';'+CHAR(13)+CHAR(10)
FROM master.dbo.sysprocesses
WHERE dbid=DB_ID('mydb');
EXEC(@str);
GO
--3.2.2 设置数据库脱机
ALTER DATABASE [mydb] SET OFFLINE
GO
--3.2.3 移动数据文件与日志文件(为确保数据安全,建议改move为copy,复制成功后再删除源文件)
EXEC master..xp_cmdshell 'move "D:/Program Files/Microsoft SQL Server/MSSQL10.MSSQLSERVER/MSSQL/DATA/mydb.mdf" "E:/DBTEST"',NO_OUTPUT
EXEC master..xp_cmdshell 'move "D:/Program Files/Microsoft SQL Server/MSSQL10.MSSQLSERVER/MSSQL/DATA/mydb_log.LDF" "E:/DBTEST"',NO_OUTPUT
GO
--3.2.4 设置新的存储路径
ALTER DATABASE [mydb] MODIFY FILE (NAME = new_mydb,FILENAME = 'E:/DBTEST/mydb.mdf')
ALTER DATABASE [mydb] MODIFY FILE (NAME = new_mydb_log,FILENAME = 'E:/DBTEST/mydb_log.ldf')
GO
--3.2.5 设置数据库联机
ALTER DATABASE [mydb] SET ONLINE
GO
--3.2.6 查询新的路径
USE mydb
GO
SELECT physical_name FROM sys.database_files
/*
physical_name
------------------------------
E:/DBTEST/mydb.mdf
E:/DBTEST/mydb_log.ldf
(2 行受影响)
*/
,