Skip to content

Commit 058a1b2

Browse files
authored
Add files via upload
1 parent 2014f3d commit 058a1b2

7 files changed

+630
-0
lines changed

PMDB.Create_Database_Backup.sql

+78
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,78 @@
1+
/*--------------------------------------------------------------------------------------------------------------------------------+
2+
| Purpose: Create a backup of a database
3+
| Example: EXEC admin.Create_Database_Backup 'PMDB1_TEST'
4+
+--------------------------------------------------------------------------------------------------------------------------------*/
5+
6+
:setvar _server "Server1"
7+
:setvar _user "***username***"
8+
:setvar _password "***password***"
9+
:setvar _database "master"
10+
:connect $(_server) -U $(_user) -P $(_password)
11+
12+
USE [$(_database)];
13+
GO
14+
15+
CREATE PROCEDURE [admin].[Create_Database_Backup]
16+
(
17+
@DatabaseName VARCHAR(50)
18+
)
19+
AS
20+
BEGIN
21+
22+
PRINT '====================================================================='
23+
PRINT 'set the name of the database...'
24+
PRINT '====================================================================='
25+
DECLARE @SourceDB VARCHAR(50)
26+
SET @SourceDB = @DatabaseName --DB_NAME()
27+
28+
PRINT '====================================================================='
29+
PRINT 'get user name...'
30+
PRINT '====================================================================='
31+
DECLARE @BackupUser VARCHAR(255)
32+
SET @BackupUser = (substring(suser_sname(),charindex('\',suser_sname())+(1),len(suser_sname())-charindex('\',suser_sname())))
33+
34+
PRINT '====================================================================='
35+
PRINT 'get current date and time...'
36+
PRINT '====================================================================='
37+
DECLARE @DateStamp VARCHAR(20)
38+
SET @DateStamp = '_' + CONVERT(VARCHAR(20),GetDate(),112) + '_' + REPLACE(CONVERT(VARCHAR(20),GetDate(),108),':','')
39+
40+
PRINT '====================================================================='
41+
PRINT 'set database backup path...'
42+
PRINT '====================================================================='
43+
DECLARE @TargetPath VARCHAR(255)
44+
-- TO DO: Standardize the backup folder location for all servers
45+
IF @@SERVERNAME = 'Server1' SET @TargetPath = 'C:\Temp\'
46+
47+
PRINT '====================================================================='
48+
PRINT 'set the backup file name...'
49+
PRINT '====================================================================='
50+
SET @TargetPath = @TargetPath + @SourceDB + @DateStamp + '_' + @BackupUser + '.bak'''
51+
PRINT @TargetPath
52+
53+
PRINT '====================================================================='
54+
PRINT 'backup the database...'
55+
PRINT '====================================================================='
56+
IF EXISTS(SELECT NAME FROM sys.databases where name = @SourceDB)
57+
BEGIN
58+
DECLARE @BACKUP_SQL VARCHAR(MAX)
59+
SET @BACKUP_SQL =
60+
'BACKUP DATABASE ' + @SourceDB + '
61+
TO DISK = ''' + @TargetPath + '
62+
WITH FORMAT,
63+
MEDIANAME = ''' + @BackupUser + ''',
64+
NAME = ''' + @SourceDB + @DateStamp + ''''
65+
66+
PRINT @BACKUP_SQL
67+
EXEC (@BACKUP_SQL)
68+
END
69+
PRINT '====================================================================='
70+
PRINT 'Finished!'
71+
PRINT '====================================================================='
72+
73+
END
74+
75+
76+
GO
77+
78+

PMDB.Remove database locks.sql

+51
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,51 @@
1+
/*--------------------------------------------------------------------------------------------------------------------------------+
2+
| Purpose: Remove database locks on the server
3+
| Note: SQLCmdMode Script
4+
+--------------------------------------------------------------------------------------------------------------------------------*/
5+
6+
7+
:setvar _server "Server1"
8+
:setvar _user "***username***"
9+
:setvar _password "***password***"
10+
:setvar _database "PMDB_TEST"
11+
:connect $(_server) -U $(_user) -P $(_password)
12+
13+
USE [$(_database)];
14+
GO
15+
16+
17+
PRINT '====================================================================='
18+
PRINT 'show the blocked processes. '
19+
PRINT '====================================================================='
20+
GO
21+
22+
SELECT DB_NAME(dbid) as 'Database Name', * FROM master.dbo.sysprocesses WITH (NOLOCK)
23+
WHERE BLOCKED <> 0
24+
--DB_NAME(dbid) = 'PMDB_TEST' -- change the database name here
25+
26+
PRINT '====================================================================='
27+
PRINT 'show the blocked process record. '
28+
PRINT '====================================================================='
29+
GO
30+
31+
SELECT DB_NAME(dbid) AS 'Database Name', * FROM master.dbo.sysprocesses
32+
WHERE SPID = 212 -- update the spid here
33+
34+
PRINT '====================================================================='
35+
PRINT 'get the sql statement of the blocked process for the ticket. '
36+
PRINT '====================================================================='
37+
GO
38+
39+
DBCC INPUTBUFFER (212) -- update the spid here
40+
41+
PRINT '====================================================================='
42+
PRINT 'remove the blocked process. '
43+
PRINT '====================================================================='
44+
GO
45+
46+
--KILL 212
47+
48+
PRINT '====================================================================='
49+
PRINT 'Finished!'
50+
PRINT '====================================================================='
51+
GO

PMDB.Remove orphan project ids.sql

+35
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,35 @@
1+
/*--------------------------------------------------------------------------------------------------------------------------------+
2+
| Purpose: Remove orphan projects
3+
| Note: SQLCmdMode Script
4+
+--------------------------------------------------------------------------------------------------------------------------------*/
5+
6+
:setvar _server "Server1"
7+
:setvar _user "***username***"
8+
:setvar _password "***password***"
9+
:setvar _database "PMDB_TEST"
10+
:connect $(_server) -U $(_user) -P $(_password)
11+
12+
USE [$(_database)];
13+
GO
14+
15+
PRINT '====================================================================='
16+
PRINT 'Find orphan project ids. '
17+
PRINT '====================================================================='
18+
GO
19+
20+
SELECT proj_id FROM project WHERE proj_id NOT IN(SELECT proj_id FROM projwbs)
21+
22+
PRINT '====================================================================='
23+
PRINT 'remove orphan project ids. '
24+
PRINT '====================================================================='
25+
GO
26+
27+
--declare @ret integer, @msg varchar(255)
28+
--BEGIN
29+
--EXEC cascade_delete 'PROJECT','*****', @ret output, @msg output --replace with the proj_id from above
30+
--END
31+
32+
PRINT '====================================================================='
33+
PRINT 'Finished!'
34+
PRINT '====================================================================='
35+
GO

PMDB.Remove user sessions.sql

+42
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,42 @@
1+
/*--------------------------------------------------------------------------------------------------------------------------------+
2+
| Purpose: Remove user sessions
3+
| Note: SQLCmdMode Script
4+
+--------------------------------------------------------------------------------------------------------------------------------*/
5+
6+
:setvar _server "Server1"
7+
:setvar _user "***username***"
8+
:setvar _password "***password***"
9+
:setvar _database "PMDB_TEST"
10+
:connect $(_server) -U $(_user) -P $(_password)
11+
12+
USE [$(_database)];
13+
GO
14+
15+
PRINT '====================================================================='
16+
PRINT 'The first step is to find out the user_id of the user that we wish to remove. '
17+
PRINT '====================================================================='
18+
GO
19+
20+
DECLARE @LANID varchar(50)
21+
DECLARE @USER_ID varchar(50)
22+
SET @LANID = 'NetworkUserIdHere' -- replace the user name here
23+
24+
SELECT @USER_ID = user_id FROM users WHERE LOWER(user_name) LIKE LOWER('%' + @LANID + '%');
25+
26+
UPDATE usession SET delete_session_id = 0 , delete_date = GETDATE() WHERE user_id = @USER_ID;
27+
GO
28+
29+
SELECT * FROM usession ORDER BY HOST_NAME
30+
GO
31+
32+
PRINT '====================================================================='
33+
PRINT 'Remove a session if the job has not cleared it. '
34+
PRINT '====================================================================='
35+
GO
36+
37+
--DELETE FROM usession WHERE session_id = 123456 -- replace this session_id with the one you want to remove
38+
39+
PRINT '====================================================================='
40+
PRINT 'Finished!'
41+
PRINT '====================================================================='
42+
GO

PMDB.Restore_Primavera_Backup.sql

+147
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,147 @@
1+
/*--------------------------------------------------------------------------------------------------------------------------------+
2+
| Purpose: Restore a backup of a database
3+
| Example: EXEC admin.Restore_Primavera_Backup 'C:\Temp\PMDB1_20170519_073701_firstname.lastname.bak', 'PMDB1_TEST'
4+
+--------------------------------------------------------------------------------------------------------------------------------*/
5+
6+
:setvar _server "Server1"
7+
:setvar _user "***username***"
8+
:setvar _password "***password***"
9+
:setvar _database "master"
10+
:connect $(_server) -U $(_user) -P $(_password)
11+
12+
USE [$(_database)];
13+
GO
14+
15+
16+
CREATE PROCEDURE [admin].[Restore_Primavera_Backup]
17+
(
18+
@FileName VARCHAR(255)
19+
, @DatabaseName VARCHAR(50)
20+
)
21+
AS
22+
BEGIN
23+
24+
PRINT '====================================================================='
25+
PRINT 'check if the database exists first...'
26+
PRINT '====================================================================='
27+
28+
IF (NOT EXISTS (SELECT name FROM master.dbo.sysdatabases WHERE name = @DatabaseName))
29+
BEGIN
30+
31+
PRINT '====================================================================='
32+
PRINT 'set the name and path for the restore...'
33+
PRINT '====================================================================='
34+
DECLARE @DataFile VARCHAR(200)
35+
36+
PRINT '====================================================================='
37+
PRINT 'set the data path for sql server...'
38+
PRINT '====================================================================='
39+
40+
SELECT @DataFile = SUBSTRING(physical_name, 1, CHARINDEX(N'master.mdf', LOWER(physical_name)) - 1)
41+
FROM master.sys.master_files
42+
WHERE database_id = 1 AND file_id = 1
43+
44+
PRINT '====================================================================='
45+
PRINT 'get the logical names from the backup file...'
46+
PRINT '====================================================================='
47+
DECLARE @Table TABLE (
48+
[LogicalName] varchar(128)
49+
, [PhysicalName] varchar(128)
50+
, [Type] varchar
51+
, [FileGroupName] varchar(128)
52+
, [Size] varchar(128)
53+
, [MaxSize] varchar(128)
54+
, [FileId]varchar(128)
55+
, [CreateLSN]varchar(128)
56+
, [DropLSN]varchar(128)
57+
, [UniqueId]varchar(128)
58+
, [ReadOnlyLSN]varchar(128)
59+
, [ReadWriteLSN]varchar(128)
60+
, [BackupSizeInBytes]varchar(128)
61+
, [SourceBlockSize]varchar(128)
62+
, [FileGroupId]varchar(128)
63+
, [LogGroupGUID]varchar(128)
64+
, [DifferentialBaseLSN]varchar(128)
65+
, [DifferentialBaseGUID]varchar(128)
66+
, [IsReadOnly]varchar(128)
67+
, [IsPresent]varchar(128)
68+
, [TDEThumbprint]varchar(128)
69+
)
70+
71+
DECLARE @LogicalNameData varchar(128)
72+
DECLARE @LogicalNameLog varchar(128)
73+
INSERT INTO @table EXEC('RESTORE FILELISTONLY FROM DISK=''' + @FileName + '''')
74+
75+
SET @LogicalNameData=(SELECT LogicalName FROM @Table WHERE Type='D')
76+
SET @LogicalNameLog=(SELECT LogicalName FROM @Table WHERE Type='L')
77+
78+
PRINT '====================================================================='
79+
PRINT 'Restore the Database starting with a file from a Full Backup...'
80+
PRINT '====================================================================='
81+
BEGIN
82+
DECLARE @RESTORE_SQL VARCHAR(MAX)
83+
SET @RESTORE_SQL =
84+
'RESTORE DATABASE ' + @DatabaseName + '
85+
FROM DISK = ''' + @FileName + '''
86+
WITH
87+
RECOVERY
88+
, STATS = 10
89+
, MOVE ''' + @LogicalNameData + ''' TO ''' + @DataFile + @DatabaseName + '.mdf''
90+
, MOVE ''' + @LogicalNameLog + ''' TO ''' + @DataFile + @DatabaseName + '.ldf'''
91+
PRINT @RESTORE_SQL
92+
EXEC (@RESTORE_SQL)
93+
END
94+
95+
PRINT '====================================================================='
96+
PRINT 'Update owner of the database to standard...'
97+
PRINT '====================================================================='
98+
BEGIN
99+
DECLARE @OWNER_SQL VARCHAR(MAX)
100+
SET @OWNER_SQL = 'ALTER AUTHORIZATION ON DATABASE::' + @DatabaseName + ' TO sa;'
101+
PRINT @OWNER_SQL
102+
EXEC (@OWNER_SQL)
103+
END
104+
105+
PRINT '====================================================================='
106+
PRINT 'Restore system user logins...'
107+
PRINT '====================================================================='
108+
109+
DECLARE @sql NVARCHAR(255);
110+
SET @sql = 'USE ' + @DatabaseName + '; EXEC dbo.sp_change_users_login ''Update_One'', ''privuser'', ''privuser''; ';
111+
112+
PRINT @sql
113+
EXEC (@sql)
114+
115+
SET @sql = 'USE ' + @DatabaseName + '; EXEC dbo.sp_change_users_login ''Update_One'', ''pubuser'', ''pubuser''; ';
116+
117+
PRINT @sql
118+
EXEC (@sql)
119+
120+
PRINT '====================================================================='
121+
PRINT 'Restore system jobs if they havent already been setup...'
122+
PRINT '====================================================================='
123+
124+
SET @sql = 'USE ' + @DatabaseName + '; EXEC initialize_background_procs; ';
125+
126+
PRINT @sql
127+
EXEC (@sql)
128+
129+
SET @sql = 'USE ' + @DatabaseName + '; EXEC system_monitor; ';
130+
131+
PRINT @sql
132+
EXEC (@sql)
133+
134+
SET @sql = 'USE ' + @DatabaseName + '; EXEC data_monitor; ';
135+
136+
PRINT @sql
137+
EXEC (@sql)
138+
139+
PRINT '====================================================================='
140+
PRINT 'Finished!'
141+
PRINT '====================================================================='
142+
143+
END
144+
145+
END;
146+
147+
GO

0 commit comments

Comments
 (0)