Secure SSIS step execution when running as a SQL Job

Here is the scenario:

SQL Agent account (NETWORK SERVICE or some DOMAIN ACCOUNT) does not have access to database activities in a SSIS package.   You want to run a job but need to "proxy" a security account when a SSIS package runs.   The following script sets up the information required to run a specific SQL Job step under a certain seucrity account.  This is one approach and there may be others.   Hope this helps!

/* Wrap everything inside a transaction */
BEGIN TRANSACTION
DECLARE @ReturnCode INT
SELECT @ReturnCode = 0
DECLARE @SSISproxy nvarchar(255),@SSIScredential nvarchar(255), @SSIScategory nvarchar(255)
DECLARE @SSIScredentialname nvarchar(255), @SSIScredentialsecret nvarchar(255), @SSISjobname nvarchar(255)
DECLARE @SSISstepname nvarchar(255), @SSISjobdesc nvarchar(255), @SSISstepcmd nvarchar(255)

/* This is the variables used in the script */
SET @SSISproxy = N'My Proxy'
SET @SSIScredential = N'MyCredential'
SET @SSIScategory = N'My SSIS Category'
SET @SSIScredentialname = N'DOMAIN\USER'
SET @SSIScredentialsecret = N'USERPWD'
SET @SSISjobname = N'My SSIS Job'
SET @SSISstepname = N'My SSIS Step'
SET @SSISjobdesc = N'My SSIS Job Description'
SET @SSISstepcmd = N'/DTS "\File System\DTSXNAME" /SERVER SERVERNAME /MAXCONCURRENT " -1 " /CHECKPOINTING OFF'
USE [msdb]

/* Create a credential with the appropriate domain service account */
DECLARE @SQLString nvarchar(500)
SET @SQLString = 'CREATE CREDENTIAL ' + @SSIScredential + ' WITH IDENTITY = ''' + @SSIScredentialname + ''', SECRET = ''' + @SSIScredentialsecret +''';'
EXEC @ReturnCode = msdb.dbo.sp_executesql @SQLString;
IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback

/* Add a proxy for the SSIS step to use */
EXEC @ReturnCode = msdb.dbo.sp_add_proxy @proxy_name=@SSISproxy, @credential_name=@SSIScredential, @enabled=1
IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback

/* Grant permission to proxy to SSIS subsystem */
EXEC @ReturnCode = msdb.dbo.sp_grant_proxy_to_subsystem @proxy_name = @SSISproxy, @subsystem_name= N'SSIS'
IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
USE [msdb]

/* Create Job category if does not exist */
IF NOT EXISTS (SELECT name FROM msdb.dbo.syscategories WHERE name=@SSIScategory AND category_class=1)
BEGIN
EXEC @ReturnCode = msdb.dbo.sp_add_category @class=N'JOB', @type=N'LOCAL', @name=@SSIScategory
IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
END

/* Create Job */
DECLARE @jobId BINARY(16)
EXEC @ReturnCode = msdb.dbo.sp_add_job @job_name=@SSISjobname,
@enabled=1,
@notify_level_eventlog=0,
@notify_level_email=0,
@notify_level_netsend=0,
@notify_level_page=0,
@delete_level=0,
@description=@SSISjobdesc,
@category_name=@SSIScategory,
@owner_login_name=N'sa', @job_id = @jobId OUTPUT
IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback

/* Create Job Step */
EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=@SSISstepname,
@step_id=1,
@cmdexec_success_code=0,
@on_success_action=1,
@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=@SSISstepcmd,
@database_name=N'master',
@flags=0,
@proxy_name=@ssisproxy
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
EXEC @ReturnCode = msdb.dbo.sp_add_jobserver @job_id = @jobId, @server_name = N'(local)'
IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback

COMMIT TRANSACTION
GOTO EndSave

QuitWithRollback:
IF (@@TRANCOUNT > 0) ROLLBACK TRANSACTION
EndSave: