November 6, 2007 at 11:46 am
i'm pulling all the job names, and dts package that are being run by pulling the name
from the command column. problem is... many of them are encrypted.
is there a way i can get the name?
here's the query:
select sj.name, command from msdb..sysjobs sj join msdb..sysjobsteps sjs on sj.job_id = sjs.job_id where command like '%dtsrun%'
order by sj.name asc
if someone has a better way of getting the job name, and dts package name it's running
then i'm down.
thanks in advance 🙂
_________________________
November 6, 2007 at 1:43 pm
It depends on what you mean by encrypted. If it is truly encrypted
Ie looks something like this:
DTSRun /~Z0xDAC2174AE009BA9EAFDFE4F8C02C4D5E70E125E112D6ECC40408B206774CA90EA767DE8612443BCE01BF6BB84E7C9E08AA9DDA04FD11DED435F81A2BAD5B95367F58222BDD99DE29D1B4536486954C5C15FB84B234DA01877CEB543538196CD304B38C2983B8DC9947291BFBD3D7DAFAA763BFD72296FCE44C602BEE4FEF18DF494A4B94C2D4AB60130C125741945A475789A80C4CF59ABE1524613EB4397A63EFB70C9198248F7563B657DA7561F340BA561C61687A1ADC3FD72FADC09B76DE46358042E40C338F24D2F1
Then to the best of my knowledge there is no way to tell what DTS package the job is actually running.
If on the other hand it looks something like this:
dtsrun /E /S ServerName /G "{BB286F23-934C-41DB-B0CA-FA1E4948B824}"
Then you could try something like this:
select sj.name, dts.name, command
from msdb..sysjobs sj
join msdb..sysjobsteps sjs on sj.job_id = sjs.job_id
LEFT OUTER JOIN msdb..sysdtspackages dts on sjs.command LIKE '%'+cast(id as varchar(100))+'%'
where command like '%dtsrun%'
order by sj.name asc
Kenneth FisherI was once offered a wizards hat but it got in the way of my dunce cap.--------------------------------------------------------------------------------For better, quicker answers on T-SQL questions, click on the following... http://www.sqlservercentral.com/articles/Best+Practices/61537/[/url]For better answers on performance questions, click on the following... http://www.sqlservercentral.com/articles/SQLServerCentral/66909/[/url]Link to my Blog Post --> www.SQLStudies.com[/url]
November 6, 2007 at 2:09 pm
thanks for the info...
unfortuantely; i'm still getting alot of this:
DTSRun /~Z0xA4B4A470F16C241170D086F8277AAB179479EAEF0653209E93D3B0C54A5941C67F5274344A50AC0F315B532EA2ADCFB782696FACCC7E993E92AD91161BF2A40F3E4530A93BA3CDC6C0DA082360EE7A797CF35B455574BBE18BB3C8ECFFD8CC3789EF01826362E5EDFBBFAFE346695984CD28CA914B520A4C1116
so i suppose i'm left in the dark on what is being executed.
nuts!
_________________________
November 6, 2007 at 2:15 pm
i remember a script from while back that would do some kind of decryption. i think
it's in the scripts repository here. i'll see if i can dig it up.
_________________________
November 6, 2007 at 2:19 pm
I would love to see it if you can find it.
Kenneth FisherI was once offered a wizards hat but it got in the way of my dunce cap.--------------------------------------------------------------------------------For better, quicker answers on T-SQL questions, click on the following... http://www.sqlservercentral.com/articles/Best+Practices/61537/[/url]For better answers on performance questions, click on the following... http://www.sqlservercentral.com/articles/SQLServerCentral/66909/[/url]Link to my Blog Post --> www.SQLStudies.com[/url]
November 6, 2007 at 4:53 pm
To decrypt a DTSRUN command as used in a job step, copy the command to a cmd prompt, append /!X /!C to the end, and run it.
The !X argument blocks execution of the package and the !C argument copies the unencrypted command to the Windows clipboard.
Just open Notepad and paste to see the unencrypted command.
Example:
DTSRun /~Z0x5F473BFAEEC0EE48EAF6121A88792F925A32FAF162A18E19FB06C5246A4CA2785EE38A17F0A6101B17B16C8F336C65EBF62B0E624C1E9B83 /!X /!C
Greg
BTW, Since this is posted in a SQL2005 forum, you might need to install the DTS 2000 runtime components to be able to use DTSRUN.
Greg
November 7, 2007 at 8:45 am
yeah... it was an accident. i have shortcuts setup to 2005 admin section.
forgot to get into the 2000 area.
_________________________
November 7, 2007 at 8:50 am
Greg I have to say that is probably one of the coolest things I have seen in awhile.
Kenneth FisherI was once offered a wizards hat but it got in the way of my dunce cap.--------------------------------------------------------------------------------For better, quicker answers on T-SQL questions, click on the following... http://www.sqlservercentral.com/articles/Best+Practices/61537/[/url]For better answers on performance questions, click on the following... http://www.sqlservercentral.com/articles/SQLServerCentral/66909/[/url]Link to my Blog Post --> www.SQLStudies.com[/url]
November 7, 2007 at 3:40 pm
I can't take credit for figuring it out, but I pass it on every chance I get!
Greg
Greg
November 7, 2007 at 5:34 pm
i've got to say... this is pretty awesome.
unfortunately; could take a while. i've got hundreds of packages, but if
thats whats needed...
a dba's got to do what a dba's got to do.
thanks 🙂
_________________________
November 7, 2007 at 5:50 pm
something interesting though... (pseudo logic)
whats your take on this:
selecting out all the job names, and 'command' encryption lines into
a table, then concatenating an xp_cmdshell statement to include
the DTSRUN statement including the '/!' switches then (... and here
is the hard part...) getting it to paste or 'print' the output including
the the job name.
select 'print ''' + sj.name + '''' + char(10) + 'go' + char(10) +
'xp_cmdshell ' + left (sjs.command, ???) + ' /!X /!C'
from sysjobs sj join sysjobsteps sjs on sj.job_id = sjs.job_id order by sj.name asc
not so good logic, but you can get an idea where i'm going with this...
i wouldn't know where to begin to get the equivalent of CTRL+V into the Enterprise
Manager or Management Studio Output window.
do you think something like this is do-able?
_________________________
November 8, 2007 at 6:47 am
That's very cool, and useful, thanks.
[font="Comic Sans MS"]The GrumpyOldDBA[/font]
www.grumpyolddba.co.uk
http://sqlblogcasts.com/blogs/grumpyolddba/
November 8, 2007 at 8:52 am
this will return all packages that are encrypted from sql server 2000.
even though 'DTSRUN' applies to the SQL 2000 environment i strongly recommend
this be run from management studio so you can see the entire encryption string.
then simply copy and paste the command string into the command prompt, and
then paste the output into a notepad, or something.
unfortunately it's a manual (1 at a time) process, but at least gets you what you
need.
use msdb
go
select sj.name, step_name, step_id, command + ' /!X /!C' from sysjobs sj join sysjobsteps sjs
on sj.job_id = sjs.job_id where command like '%dtsrun /~%' order by sj.name, step_id asc
_________________________
Viewing 13 posts - 1 through 12 (of 12 total)
You must be logged in to reply to this topic. Login to reply