Setup SQL Server Integration Services environment and SQL Agent Job to run deployed SSIS package

Possibly save 8 hours of your time: After you create SSIS package and build the project (bin folder should have .ispac file), the next step is to deploy that to a Microsoft SQL Server instance environment and have a scheduled job to run the package. It is not trivial to setup a proper environment. The steps below are targeting Microsoft SQL Server 2012.

Pre-requisites

  • Please make sure that you have SSISDB catalog under Integration Services Catalogs already created. If not, you can right click and choose Create Catalog.

ssisdb

  • A specific user or system user permission will be needed to run the job to execute the package. From here on we call this user the system user.
  • If the package requires read and/or write access to specific database, provide the following database role permissions as needed to the system user:
    • db_datareader
    • db_datawriter
    • SSIS
  • If the package requires execute permission for specific schema on a specific database, provide the following permissions as needed to the system user:
    • Execute
    • Alter (if using bulk insert tasks in SSIS)
  • For msdb system database, the system user needs to be added to Security > Users. Under Owned Schemas, check SQLAgentUserRole.
  • For SSISDB database, the system user needs to be added to Security > Users.
  • The database administrator who will be running the command script to create the job to run the package will need sysadmin role.
  • If you want to receive SSIS job notification on success or failure, you will need to setup an account under Management > Database Mail. Then right click SQL Server Agent, click Alert System and Enable mail profile and choose the account profile created.

Script Implementation

  • Please see at the bottom for the script. The scripts can be run in command prompt directly or embed in a .cmd script file first. Any word surround by %% are variables that you can set.
  • cmd Script will create
    • folder in SSISDB
    • Deploy packages via .ispac
    • run the following SQL script
  • SQL Script will create
    • delete previous existing job
    • create Credential
    • create Proxy
    • create Alerts
    • create SQL Agent Job via .sql
    • add package(s) to the job
    • add job schedule

Post-requisites

  • Setup environment variables if your packages requires specific configuration for this environment – Integration Services Catalog >> SSISDB >> Project >> Environments
  • Update Project Variable Environment
    • Right click project. Select Configure.
    • Under References, add the environment created previously.
    • Under Parameters, edit the same values as in the environment section to use environment variables.
  • Set project level permissions
    • At the SSISDB folder level, add system identity user account with read, execute objects and read objects permissions
    • At the projects level, add read and execute permission for the system identity user.
  • Setup working folder permissions for system user if using working folder (typically if data files are involved in the package, they need to be somewhere)

Script – create folder in SSISDB

set sqlcmdpath=”C:\Program Files\Microsoft SQL Server\110\Tools\Binn\sqlcmd.exe”

REM Create folder in SSISDB

echo Creating folder in SSISDB if not exists…
echo %sqlcmdpath% -S %serverName% -d ssisdb -Q “if not exists(select 1 from internal.folders where name = ‘%folder%’) exec catalog.create_folder %folder%”
%sqlcmdpath% -S %serverName% -d ssisdb -Q “if not exists(select 1 from internal.folders where name = ‘%folder%’) exec catalog.create_folder %folder%”

echo *******************************************************

Script – deploy packages via .ispac file

set isdeploymentwizard=”C:\Program Files\Microsoft SQL Server\110\DTS\Binn\isdeploymentwizard.exe”

REM Deploy the ETL
echo ETL Deployment is running…
echo %isdeploymentwizard% /S /ST:File /SP:”yourProjectName.ispac” /DS:%serverName% /DP:/SSISDB/%folder%/%project%
%isdeploymentwizard% /S /ST:File /SP:”yourProjectName.ispac” /DS:%serverName% /DP:/SSISDB/%folder%/%project%
echo ETL Deployment Completed
echo *******************************************************

Note: If you get error 0xC0011008 such as “the package failed to load due to error error loading from xml”, ensure you are targeting the right version of database via project properties.

Script – to run the following SQL script in one file with passed in parameters

set sqlcmdpath=”C:\Program Files\Microsoft SQL Server\110\Tools\Binn\sqlcmd.exe”

REM Create SQL Agent Job
echo Creating SQL Agent Job…
echo %sqlcmdpath% -S %serverName% -i %jobSQL% -v identity=”%id%” password=”%pass%” operator=”%oper%” environmentId=”%envId%”
%sqlcmdpath% -S %serverName% -i %jobSQL% -v identity=”%id%” password=”%pass%” operator=”%oper%” environmentId=”%envId%”
echo SQL Agent Job has been created

Delete previous existing job

USE [msdb]

GO
–Clean up SQL Agent Job

DECLARE @jobId BINARY(16)

SELECT @jobId = job_id FROM msdb.dbo.sysjobs WHERE (name = N’Your Job Name’)

IF (@jobId IS NOT NULL)    EXEC msdb.dbo.sp_delete_job @jobId go

Create Credential

–Create Credential Note: change the credential name

use master

go

IF EXISTS (SELECT 1 FROM sys.credentials WHERE name = N’Your Credential Name’) DROP credential [Your Credential Name]

go

create credential [Your Credential Name] with identity = N’$(identity)’, secret = N’$(password)’go

Create Proxy

–Create Proxy Note: change the proxy name

USE msdb

GO

IF EXISTS (SELECT 1 FROM msdb.dbo.sysproxies WHERE name = N’Your Proxy Name’) EXEC dbo.sp_delete_proxy @proxy_name = N’Your Proxy Name’

GO

EXEC msdb.dbo.sp_add_proxy @proxy_name=N’Your Proxy Name’,@credential_name=N’Your Credential Name’, @enabled=1

GO

EXEC msdb.dbo.sp_grant_proxy_to_subsystem @proxy_name=N’Your Proxy Name’, @subsystem_id=11GOEXEC msdb.dbo.sp_grant_login_to_proxy @proxy_name=N’Your Proxy Name’, @login_name=N’$(identity)’

GO

Create Alerts

–Create Operator

USE [msdb]

GO

IF EXISTS(SELECT 1 FROM msdb.dbo.sysoperators WHERE name = N’Your Operator Name’) EXEC sp_delete_operator @name=N’Your Operator Name’

GO

EXEC msdb.dbo.sp_add_operator @name=N’Your Operator Name’,  @enabled=1,  @weekday_pager_start_time=90000,  @weekday_pager_end_time=180000,  @saturday_pager_start_time=90000,  @saturday_pager_end_time=180000,  @sunday_pager_start_time=90000,  @sunday_pager_end_time=180000,  @pager_days=0,  @email_address=N’$(operator)’,  @category_name=N'[Uncategorized]’

GO

Create SQL Agent Job

 

–Create SQLAgent Job

USE [msdb]

GO
BEGIN TRANSACTION

DECLARE @ReturnCode INT

SELECT @ReturnCode = 0

IF NOT EXISTS (SELECT name FROM msdb.dbo.syscategories WHERE name=N'[Uncategorized (Local)]’ AND category_class=1)

BEGIN

EXEC @ReturnCode = msdb.dbo.sp_add_category @class=N’JOB’, @type=N’LOCAL’, @name=N'[Uncategorized (Local)]’IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
END
DECLARE @jobId BINARY(16)

EXEC @ReturnCode =  msdb.dbo.sp_add_job @job_name=N’Your Job Name’,  @enabled=1,  @notify_level_eventlog=0,  @notify_level_email=2,  @notify_level_netsend=0,  @notify_level_page=0,  @delete_level=0,  @description=N’No description available.’,  @category_name=N'[Uncategorized (Local)]’,  @owner_login_name=N’$(identity)’,  @notify_email_operator_name=N’Your Job Name’, @job_id = @jobId OUTPUTIF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback

Add package to the job

EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N’Your Step Name’,
@step_id=1,
@cmdexec_success_code=0,
@on_success_action=3,
@on_success_step_id=0,
@on_fail_action=2,
@on_fail_step_id=0,
@retry_attempts=0,
@retry_interval=0,
@os_run_priority=0, @subsystem=N’SSIS’,
@command=N’/ISSERVER “\”\SSISDB\Your Folder Name\Your Project Name\Your Package Name.dtsx\”” /SERVER “\”$(serverName)\”” /ENVREFERENCE $(environmentId) /Par “\”$ServerOption::LOGGING_LEVEL(Int16)\””;1 /Par “\”$ServerOption::SYNCHRONIZED(Boolean)\””;True /CALLERINFO SQLAGENT /REPORTING E’,
@database_name=N’master’,
@flags=0,
@proxy_name=N’Your Proxy Name’
IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback

EXEC @ReturnCode = msdb.dbo.sp_update_job @job_id = @jobId, @start_step_id = 1

IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback

Note: You can repeat this to add more packages as steps in your job.

Add Job Schedule
EXEC @ReturnCode = msdb.dbo.sp_add_jobschedule @job_id=@jobId, @name=N’Your Schedule Name’,  @enabled=1,  @freq_type=4,  @freq_interval=1,  @freq_subday_type=8,  @freq_subday_interval=12,  @freq_relative_interval=0,  @freq_recurrence_factor=0,  @active_start_date=20160616,  @active_end_date=99991231,  @active_start_time=0,  @active_end_time=235959,  @schedule_uid=N’d5de52a3-a8e8-49ca-92d0-fbbc3ee10098′

IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback

EXEC @ReturnCode = msdb.dbo.sp_add_jobserver @job_id = @jobId, @server_name = N’$(serverName)’

IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback

COMMIT TRANSACTION

GOTO EndSave

QuitWithRollback:

IF (@@TRANCOUNT > 0) ROLLBACK TRANSACTION

EndSave:
GO

 

 

Advertisements

Leave a Reply

Fill in your details below or click an icon to log in:

WordPress.com Logo

You are commenting using your WordPress.com account. Log Out / Change )

Twitter picture

You are commenting using your Twitter account. Log Out / Change )

Facebook photo

You are commenting using your Facebook account. Log Out / Change )

Google+ photo

You are commenting using your Google+ account. Log Out / Change )

Connecting to %s