Created
July 8, 2012 22:06
-
-
Save AkosLukacs/3073102 to your computer and use it in GitHub Desktop.
Create drop+create scripts for MS SQL stored procedures and views in a given database using PowerShell and SMO
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
-- * * * * 2012.07.09. 0:13:16, server:'xxxx', db:'xxxx', search:'A_exampl' * * * * | |
IF EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'[dbo].[A_example]') AND type in (N'P', N'PC')) --#1 | |
Drop procedure [dbo].[A_example]; | |
GO | |
-- * * * * BODY * * * * | |
-- * * * * #1:A_example; CreateDate:2012.07.09. 0:13:04, DateLastModified:2012.07.09. 0:13:04 * * * * | |
GO | |
-- ============================================= | |
-- Author: Akos | |
-- Create date: just now :) | |
-- This script includes comments as well! | |
-- ============================================= | |
CREATE PROCEDURE A_example | |
@something int | |
AS | |
BEGIN | |
SET NOCOUNT ON; | |
-- Insert statements for procedure here | |
SELECT @something | |
--and a comment in the end | |
END | |
GO | |
-- * * * * * * * * * done: 2012.07.09. 0:13:16 * * * * * * * * * * | |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
param( | |
$connStr = "server=your_server;database=your_database;Integrated Security=SSPI;", | |
$dbName = "", | |
$search = "man_", | |
$savePath = "d:\Publish\SPSave", | |
$outPrefix = "Man", | |
$schema = "dbo", | |
$copyTo = "d:\Publish\SPSave\Man_latest\{0}", | |
$delCopyTo = "true" | |
) | |
#usage (assuming the script is saved as sqlScriptExport.ps1: | |
# just use the defaults: | |
# sqlScriptExport | |
# Script another db from the same server: | |
# sqlScriptExport -dbName:"other" -search:"" -outPrefix:"Other" -copyTo:"d:\Publish\SPSave\Other_latest\{0}" | |
Add-Type -Path "c:\Program Files (x86)\Microsoft SQL Server\100\SDK\Assemblies\Microsoft.SqlServer.Smo.dll" | |
$fileName = ([string]::Format("{0}__{1}.sql", $outPrefix, [DateTime]::Now.ToString("yyyy.MM.dd_HH_mm_ss"))) | |
$fileFullPath = join-path $savePath $fileName | |
#$rx = new-object Regex($searchRX, [System.Text.RegularExpressions.RegexOptions]::Compiled); | |
$conn = new-object System.Data.SqlClient.SqlConnection | |
$conn.ConnectionString = $connStr | |
$srv = new-object Microsoft.SqlServer.Management.Smo.Server(new-object Microsoft.SqlServer.Management.Common.ServerConnection($conn)) | |
#if dbName is not set, use the one from the ConnectionString | |
if(!$dbName) {$dbName = $srv.ConnectionContext.DatabaseName;} | |
$db = $srv.Databases[$dbName]; | |
" db: '" + $dbName + "', searching for: '" + $search + "', saving to: " + $fileFullPath | |
$cnt = 0 | |
$sbHead = [System.Text.StringBuilder] [string]::Format("-- * * * * {0}, server:'{1}', db:'{2}', search:'{3}' * * * *" + [Environment]::NewLine, [DateTime]::Now, $srv.Name, $dbName, $search) | |
$sbBody = [System.Text.StringBuilder] ("-- * * * * BODY * * * *" + [Environment]::NewLine) | |
foreach($sp in $db.StoredProcedures) | |
{ | |
#if($rx.Match($sp.Name)){ # regex took much more time | |
if(($sp.Schema -eq $schema) -and ([string]::IsNullOrEmpty($search) -or $sp.Name.Contains($search))){ | |
$dummy= $sbHead.AppendLine( [string]::Format(@" | |
IF EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'[{0}].[{1}]') AND type in (N'P', N'PC')) --#{2} | |
Drop procedure [{0}].[{1}]; | |
GO | |
"@, $sp.Schema, $sp.Name, ++$cnt)) | |
$dummy = $sbBody.AppendLine( [string]::Format(@" | |
-- * * * * #{0}:{1}; CreateDate:{2}, DateLastModified:{3} * * * * | |
GO | |
{4} | |
{5} | |
GO | |
"@, $cnt, $sp.Name, $sp.CreateDate, $sp.DateLastModified, $sp.TextHeader, $sp.TextBody)) | |
if($cnt %10) { write-host "." -nonewline} | |
} | |
} | |
#doing the same for views | |
foreach($sp in $db.Views) | |
{ | |
if(($sp.Schema -eq $schema) -and ([string]::IsNullOrEmpty($search) -or $sp.Name.Contains($search))){ | |
$dummy = $sbBody.AppendLine( [string]::Format(@" | |
-- * * * * #{0}:{1}; CreateDate:{2}, DateLastModified:{3} * * * * | |
GO | |
IF EXISTS (SELECT * FROM sys.views WHERE object_id = OBJECT_ID(N'[dbo].[{1}]')) | |
DROP VIEW [dbo].[{1}] | |
GO | |
{4} | |
{5} | |
GO | |
"@, ++$cnt, $sp.Name, $sp.CreateDate, $sp.DateLastModified, $sp.TextHeader, $sp.TextBody)) | |
if($cnt %10) { write-host "." -nonewline} | |
} | |
} | |
$stream = [System.IO.StreamWriter] ($fileFullPath) | |
$stream.WriteLine($sbHead.ToString()) | |
$stream.WriteLine($sbBody.ToString()) | |
$stream.WriteLine([string]::Format("-- * * * * * * * * * done: {0} * * * * * * * * * *" + [Environment]::NewLine, [DateTime]::Now)) | |
$stream.Close() | |
$conn.Close() | |
write-host "`nDone scripting " $cnt " SPs! " -nonewline | |
#Copying the new file to the "latest" directory. | |
if($copyTo){ | |
if($delCopyTo){ | |
$delPath = ([string]::Format($copyTo, "*")) | |
del $delPath -include *.* | |
"Files deleted from here: '" + $delPath + "'" | |
} | |
$cel = ([string]::Format($copyTo, $fileName)) | |
copy $fileFullPath $cel; | |
" file copied here: " + $cel; | |
} else { " No copying..." } |
Sign up for free
to join this conversation on GitHub.
Already have an account?
Sign in to comment
Thx for the code. Modified a few lines to include the USE DatabaseName ;
` $dummy= $sbHead.AppendLine( [string]::Format(@"
USE {3} ;
IF EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'[{0}].[{1}]') AND type in (N'P', N'PC')) --#{2}
Drop procedure [{0}].[{1}];
GO
"@, $sp.Schema, $sp.Name, ++$cnt, $db))`