Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


VBscript hacks for DTS packages


VBscript hacks for DTS packages

Author
Message
alfreitas
alfreitas
Grasshopper
Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)

Group: General Forum Members
Points: 11 Visits: 25
Comments posted to this topic are about the item VBscript hacks for DTS packages
igor.bustiuc
igor.bustiuc
Forum Newbie
Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)

Group: General Forum Members
Points: 1 Visits: 8
Hello!

Still working with VBScript in 2008 year?

Something about .NET it could be very, very interesting.

Regards.
Christian Buettner-167247
Christian Buettner-167247
Hall of Fame
Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)

Group: General Forum Members
Points: 3263 Visits: 3889
.NET will not work with DTS...

But very good article. I have had similar "problems" in the past but used different strategies:

When executing other packages within a package I usually use the ExecuteProcess task and build the command line with the parameters in VBScript.
Function fn_BuildArgument(astrType, astrArg1, astrArg2, astrArg3) ' As String
Dim lstrSQLServerName ' As String
Dim lstrCommand ' As String
Dim lstrArgument ' As String

lstrSQLServerName = DTSGlobalVariables("gstrSQLServerName")

' If the parameters are supplied through the command line, neither the percent sign nor the equality sign can be used and therefore must be substituted.
astrArg2 = Replace(astrArg2,"=","decodeequals")
astrArg2 = Replace(astrArg2,"%","decodepercent")
astrArg3 = Replace(astrArg3,"=","decodeequals")
astrArg3 = Replace(astrArg3,"%","decodepercent")

lstrCommand = """C:\Program Files\Microsoft SQL Server\80\Tools\Binn\DTSRun.exe"" "
lstrArgument = "/S " & lstrSQLServerName & " " ' The server where the package is located
lstrArgument = lstrArgument & " /E /N""The Package Name " & astrType & """" ' The Package to be executed
lstrArgument = lstrArgument & " /A gstrArg1:8=""" & astrArg1 & """" ' Argument 1
lstrArgument = lstrArgument & " /A gstrArg2:8=""" & astrArg2 & """" ' Argument 2
lstrArgument = lstrArgument & " /A gstrArg3:8=""" & astrArg3 & """" ' Argument 3
fn_BuildArgument = lstrCommand & lstrArgument
End Function

Of course this only can be used to submit variables to the called package since they are passed by value and not by ref.

The template method is being used a little differently as well.
I created the template and used special strings (that would never appear in code) as place holders.
During run time, a simple Replace(lstrTemplate,'specialstring', gstrVarName) generates the required SQL String.

For both strategies, it is important to note that these were used by system processes that do not get any user input.

Best Regards,

Chris Büttner
SuperDBA-207096
SuperDBA-207096
SSCommitted
SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)

Group: General Forum Members
Points: 1739 Visits: 711
Well done!

I thought the article was very informative..
Alan Robbins-417146
Alan Robbins-417146
Forum Newbie
Forum Newbie (9 reputation)Forum Newbie (9 reputation)Forum Newbie (9 reputation)Forum Newbie (9 reputation)Forum Newbie (9 reputation)Forum Newbie (9 reputation)Forum Newbie (9 reputation)Forum Newbie (9 reputation)

Group: General Forum Members
Points: 9 Visits: 20
This is a good article although it would help folks if the typo "bidding parameters" got fixed to "binding parameters" as that threw me at first.

Given how flexible the XML parser is, and what with CROSS APPLY and CTE queries, what we do is setup parameters in the database in a table dedicated to that purpose. Might not work for everybody...
Antares686
Antares686
SSCrazy Eights
SSCrazy Eights (9.7K reputation)SSCrazy Eights (9.7K reputation)SSCrazy Eights (9.7K reputation)SSCrazy Eights (9.7K reputation)SSCrazy Eights (9.7K reputation)SSCrazy Eights (9.7K reputation)SSCrazy Eights (9.7K reputation)SSCrazy Eights (9.7K reputation)

Group: Moderators
Points: 9730 Visits: 780
First off I will say it was a nice article and offers so good alternatives. However I will point out two things.

First, in part one there is a " missing in your build of the function right in front of Scripting.Dictionary in the line that reads

sCode = sCode & "Set dictionary = CreateObject(" & chr(34)_ 
& Scripting.Dictionary" & chr(34) & ")" & vbCRLF
For Each sKey in aEntries.Keys()



This is minimal but for those who cannot figure out why this isn't working it should read

sCode = sCode & "Set dictionary = CreateObject(" & chr(34)_ 
& "Scripting.Dictionary" & chr(34) & ")" & vbCRLF
For Each sKey in aEntries.Keys()



In addition I am not sure I would consider it helpfull to hide the parameters with this method as you really don't save a lot (and even on a large number of variables you have to resolve somehow the errors). Your statement that you can change variables also does not work as you will have to resolve any issues you get.


Second, I completely disagree with part two, at least based on the example, as I think many people just have not figure out how to manage the things the parameter button cannot parse.

I have worked with DTS for a while now and found this limitation a pain and then discovered via code and ultimately directly how to get around.

For you example just insert the standard parameterized code into the ExcuteSQL task like so


SELECT
MAX(SALES_ORG) AS SALES_ORG,
MAX(DISTR_CHANNEL) AS DISTR_CHANNEL,
DATEADD( hh, ?, MIN( START_DT ) ) AS START_DATE,
DATEADD( hh, ?, MIN( START_DT ) ) AS EFFECTIVE_START_DATE,
PRODUCT_NAME AS PLI_PROD_NAME,
MAX( RATE_ZPMC ) AS MAX_PRICE,
VENDR_NAME,
VENDR_LOC,
VENDR_BU,
DATEADD( hh, ?, MAX( END_DT ) ) AS END_DATE,
DATEADD( hh, ?, MAX( END_DT ) ) AS EFFECTIVE_END_DATE
FROM
TMP_PRI_LST
WHERE
ROW_STATUS = 'FOR_IMPORT'
AND ERROR_MSG IS NULL
GROUP BY
PRODUCT_NAME,
VENDR_NAME,
VENDR_LOC,
VENDR_BU



Now of course if you hit the "Parameters" button you get the error message

"An error occurred while parsing the SQL Statement for parameters. Please ..."

but this is only the parsing code for the button that fails.

To get around this you just need open "Disconnected Edit" (right click on any whitespace of the design area or under Package menu). Once open then expand Tasks and pick the correct item with a name similar to "DTSTask_DTSExecuteSQLTask_" it will have the same description as what you just set if you bothered changing it. Anyway, there you will find an entry titled "InputGlobalVariableNames", edit this item and enter your variable input value like so

"fix_utcdatetime"

and since you have multiple values you have to enter it multiple times and in order like so

"fix_utcdatetime";"fix_utcdatetime";"fix_utcdatetime";"fix_utcdatetime"

The ; is the seperator and the variables are replaced in order. So if you had different values you place in orderinal fashion compared to the ? variable in our query. This works in every case, at least every case I ever tried, where you need it and the button wouldn't work.



Anipaul
Anipaul
SSCertifiable
SSCertifiable (6.8K reputation)SSCertifiable (6.8K reputation)SSCertifiable (6.8K reputation)SSCertifiable (6.8K reputation)SSCertifiable (6.8K reputation)SSCertifiable (6.8K reputation)SSCertifiable (6.8K reputation)SSCertifiable (6.8K reputation)

Group: General Forum Members
Points: 6819 Visits: 1407
I also thought VBScript now, but after going through the article I found very interesting and nice. It is a informative article.



Christian Buettner-167247
Christian Buettner-167247
Hall of Fame
Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)

Group: General Forum Members
Points: 3263 Visits: 3889
Hello Antares,

Regarding your suggestion on the second example (disconnected edit for parameter declaration): It would be very interesting, but I cannot seem to get it to work with Oracle. Do you have any information on this? I have tried various parameter declarations and they all throw errors.

With SQL Server Parameters I have had no issues so far, I was always able to use the Parameter Button for them.

Thanks!

Best Regards,

Chris Büttner
Antares686
Antares686
SSCrazy Eights
SSCrazy Eights (9.7K reputation)SSCrazy Eights (9.7K reputation)SSCrazy Eights (9.7K reputation)SSCrazy Eights (9.7K reputation)SSCrazy Eights (9.7K reputation)SSCrazy Eights (9.7K reputation)SSCrazy Eights (9.7K reputation)SSCrazy Eights (9.7K reputation)

Group: Moderators
Points: 9730 Visits: 780
Yeah, just PM the details of how you are doing you oracle pulls and not what objects you use. Also include the message as I found instances where I had to manipulate formats on dates otherwise it still failed. I usually use Data Drive Query Tasks and there is a completely different way of dealing with them.



Christian Buettner-167247
Christian Buettner-167247
Hall of Fame
Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)

Group: General Forum Members
Points: 3263 Visits: 3889
Hm, i tried to get the error message from a new package, but it actually ran successfully this time. Both the oracle and the oledb parameter syntax returned the correct results.

When I tried the same this morning with an existing package I got an error that contained somthing like "Invalid Library" or so. But I cannot reproduce this anymore, so I guess I just had a typo somewhere or something missing.

Thanks for your awesome tip!

Best Regards,

Chris Büttner
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search