To use the connections collection use something like the following:
ConnectionManager cm = Dts.Connections.Add("OLEDB");
cm.ConnectionString = "Data Source=localhost;Initial Catalog=AdventureWorks;Provider=SQLNCLI10;Integrated Security=SSPI;Auto Translate=False;";
Why is this advice bad? Let me count the ways:
- The connection string is hardcoded inside the script.
- The connection can't be used with Package Configurations.
- The connection string (and name) imply that OLEDB connections can be used.
- As presented, the connection won't participate in MSDTC transactions.
The poor advice boils down to the fact that it appears to create a "managed" connection, but doesn't truly do so. In fact, if you attempt to use code in the comment as is - you're only halfway there. How do you actually use this "ConnectionManager" object anyway? There's no "Open" method, or Command object - just weird methods and properties that would be entirely unfamiliar to you even if you know .Net data access! And to add insult to injury, even if you did know where to go from here, the example provided will only cause an error, and will never work.
What is a Managed Connection?
Lets start with describing what a "managed" connection is (in the context of SQL Server Integration Services). It is simply a connection that's defined and controlled by an entry in the "Connection Managers" window at the bottom of the design surface in BIDS.- Their properties (primarily the connection string) can be manipulated with Package Configurations.
- Their properties (again, the connection string) can be manipulated with Property Expressions.
- They can participate in SSIS (MSDTC) transactions.
- The connection is tested by default when the package is loaded, before any (potentially unrecoverable) work is started.
How is the Advice Wrong?
The comment in the Script Task counsels you to use Dts.Connections.Add to get a reference to a ConnectionManager object. This is the correct type of object - it's a managed connection. Unfortunately, using that syntax, you're creating a new one, not using one of the managed connections you've already defined in the package. Since it's an entirely new connection, you have to set up the connection string. You could pass the connection string in to the script using an SSIS variable, or read it from a file - but these are both non-standard practices. Another ETL developer or administrator familiar with SSIS won't anticipate your decision to implement a connection that way.
Additionally, since it's a brand new object, none of the regular design time facilities are available to you; Package Configurations, Property Expressions, the TransactionOption property, and runtime validation don't work.
The Right Way to Use Managed Connections
Ignore the comments in the Script Task - use managed connections properly by following these steps.
1. Create an ADO.Net Connection
Add a Connection Manager to your package the same way you'd make one for use in a Data Flow or Execute SQL Task. Right-click in the Connection Managers pane and add a new ADO.Net connection. You can use OLEDB type connections and other connection types - but they're more difficult to use and have fewer capabilities inside a Script.
2. Retrieve a Reference to the Connection
Inside your Script Task, instead of using Dts.Connections.Add, retrieve a reference to an existing connection manager by using the Dts.Connections indexer. For example, if you happen to have a connection manager named "(local).master", then use this code to retrieve a reference to the ConnectionManager object:
ConnectionManager cm = Dts.Connections["(local).master"];
3. For Connections with Providers, Acquire a Connection
(A "provider" means any connection that has code supporting and managing the connection - like an ADO, OLEDB, or Excel connection, but unlike a Flat File connection.)
Even though you now have a reference to the ConnectionManager object, you need to acquire an actual connection to the resource, and request that connection be established in a way that SSIS can manage it. This step is necessary to ensure that your work with the connection participates in transactions and connection pooling (or lack of it).
The specific details for each connection type vary, but the general method is consistent.
// For an ADO.Net ConnectionManager using a SqlClient provider
System.Data.SqlClient.SqlConnection sqlConn = (System.Data.SqlClient.SqlConnection)cm.AcquireConnection(Dts.Transaction);
// For an ADO.Net ConnectionManager using an ODBC provider
System.Data.Odbc.OdbcConnection odbcConn = (System.Data.Odbc.OdbcConnection)cm.AcquireConnection(Dts.Transaction);
Be aware that it is NOT necessary (or advisable) to use the Open method on the connection object you just retrieved... it's already open. (Check the connection's State property if you don't believe me.)
4. Use the Connection
At this point, you can use the connection to retrieve datasets, execute commands, or do just about anything else you'd want to do with your connection.
5. Release the Connection Properly
Once you've finished your work, you need to clean up after yourself - but NOT by using the Close method on the connection! You'll need to use the ReleaseConnection method of the ConnectionManager instead.
How Hard Was That?
Hopefully not so hard as to make you want to go the other direction and use completely unmanaged connections in your scripts! To recap, here's a complete code listing of how to correctly use an ADO.Net managed connection for a SqlClient provider within a Script Task:
bool fireAgain = true;
ConnectionManager cm;
System.Data.SqlClient.SqlConnection sqlConn;
System.Data.SqlClient.SqlCommand sqlComm;
int rowsAffected;
// Retrieve the reference to the managed connection
cm = Dts.Connections["(local).master"];
// Request an open connection
sqlConn = (System.Data.SqlClient.SqlConnection)cm.AcquireConnection(Dts.Transaction);
Dts.Events.FireInformation(0, "", "Connection is: " + sqlConn.State.ToString(), "", 0, ref fireAgain);
// Do your work
sqlComm = new System.Data.SqlClient.SqlCommand("UPDATE YourTable SET YourColumn = 'SomeValue'", sqlConn);
rowsAffected = sqlComm.ExecuteNonQuery();
// Inform SSIS you're done your work
cm.ReleaseConnection(sqlConn);
Dts.Events.FireInformation(0, "", rowsAffected.ToString() + " rows updated.", "", 0, ref fireAgain);
Dts.TaskResult = (int)ScriptResults.Success;
Thanks for the tip on using ReleaseConnection - I'd never run into that before.
ReplyDeleteWhen I use the line to convert the acquired connection to a SQLConnection, I get the following error:
ReplyDeleteError: System.Reflection.TargetInvocationException: Exception has been thrown by the target of an invocation. ---> System.InvalidCastException: Unable to cast COM object of type 'System.__ComObject' to class type 'System.Data.SqlClient.SqlConnection'. Instances of types that represent COM components cannot be cast to types that do not represent COM components; however they can be cast to interfaces as long as the underlying COM component supports QueryInterface calls for the IID of the interface
I have been getting the same error did you find a soluion to it
DeleteThis only works with ADO.Net connections...
Deletethanks..Had to work it out but it did work... Anon..Did you make a ado.net connection?
ReplyDeleteI had trouble using with a stored proc with params, finally passed as sqltext = "exec myProc " + "'" myParam + "'"
thanks again..
I have been scouring posts for days. Your post was right on the money. A HUGE thanks to you!
ReplyDeleteHey, thanks! Ran into major problems after using some sloppy example I found and I used up all the connetions in the pool. :) Now, in my non-SSIS data access code I always perform cleanup of db-objects in case of an exception as well. Would that be a good idea for the managed connection too?
ReplyDelete/Bjorn
here is a similar approach using C# in the script task to solve the issue of reusing your connection manager -
ReplyDeletehttp://saldeloera.wordpress.com/2012/04/09/ssis-how-to-reuse-existing-connection-manager-to-execute-sql-in-script-task/
Sal, I actually find a few things in that post that I would counsel against doing. I do like your use of the "using" keyword, it does make some cleanup more automated. However, I do prefer the non-code variable access (it leaves lock handling to SSIS), use of the AquireConnection/ReleaseConnection pair, transaction support, and a few other minor items.
ReplyDeleteI'm trying to do this using an OleDbConnection. I set a breakpoint on the script task and my variable is coming back as {System.Data.OleDb.OleDbCommand} instead of the value the sql query grabs. Can you see anything wrong with my code? SSIS makes it tough to debut the actual code in the script task.
ReplyDeletepublic void Main()
{
ConnectionManager cm;
System.Data.OleDb.OleDbCommand sqlComm;
cm = Dts.Connections["WTDB.webtrends_user"];
IDTSConnectionManagerDatabaseParameters100 cmParams = cm.InnerObject as IDTSConnectionManagerDatabaseParameters100;
OleDbConnection sqlConn = cmParams.GetConnectionForSchema() as OleDbConnection;
sqlConn = (System.Data.OleDb.OleDbConnection)cm.AcquireConnection(Dts.Transaction);
sqlComm = new System.Data.OleDb.OleDbCommand("select value from etl_markers where type=1", sqlConn);
Dts.Variables["User::etl_markers"].Value = sqlComm.ToString();
cm.ReleaseConnection(sqlConn);
Dts.TaskResult = (int)ScriptResults.Success;
}
The big problem I can see with the above code is that you're taking the connection manager and casting it to a Parameters object... I can't understand why you'd try to do that. Please review the SSIS Team Blog on using OLE DB Connections. If you still need more help, post up the details on the MSDN Forums.
ReplyDeleteI figured it out, here's what I did in case anyone was interested.
ReplyDeletepublic void Main()
{
System.Data.OleDb.OleDbCommand sqlComm;
ConnectionManager cm = Dts.Connections["WTDB.webtrends_user"];
IDTSConnectionManagerDatabaseParameters100 cmParams = cm.InnerObject as IDTSConnectionManagerDatabaseParameters100;
OleDbConnection sqlConn = cmParams.GetConnectionForSchema() as OleDbConnection;
sqlComm = new System.Data.OleDb.OleDbCommand("select value from etl_markers where type=1", sqlConn);
Dts.Variables["User::etl_markers"].Value = Convert.ToString(sqlComm.ExecuteScalar());
cm.ReleaseConnection(sqlConn);
Dts.TaskResult = (int)ScriptResults.Success;
}
Thanks this really helped me push some values from a web service into Mysql using Odbc.
ReplyDeleteI'm experiencing some issues with timeout on using that method. My sql statement returns data as expected when it runs on Development Studio, but when it runs through SSIS 2008 it returns the following error:
ReplyDeleteError: System.Reflection.TargetInvocationException: Exception has been thrown by the target of an invocation. ---> System.Data.SqlClient.SqlException: Timeout expired. The timeout period elapsed prior to completion of the operation or the server is not responding.
I've already tried changing the Connect Timeout property into my connection to 0, 60, 3600... Nothing helps.
Here's my code:
ConnectionManager cm = Dts.Connections["Connection"];
System.Data.SqlClient.SqlConnection conn;
System.Data.SqlClient.SqlCommand cmd;
System.Data.SqlClient.SqlDataReader rdr;
conn = (System.Data.SqlClient.SqlConnection)cm.AcquireConnection(Dts.Transaction);
string sSql = ""; // My SQL goes here
cmd = new System.Data.SqlClient.SqlCommand(sSql, conn);
rdr = cmd.ExecuteReader();
while (rdr.Read()) {
(...)
}
cm.ReleaseConnection(conn);
Dts.TaskResult = (int)ScriptResults.Success;
Can you please help me?
I'm assuming that when you say you're having problems with "this method" you mean that another method worked OK for you? If so, what method worked for you?
DeleteSecond, the timeout on the Connection Manager may not be the one you're really interested in - I'm not overly familiar with how the timeouts work, but there are settings on the connection itself as well as commands you issue in code. But I'd be more concerned about why you're experiencing a timeout at all. Is the server different? Is the data set different? What does server monitoring show you? Perhaps your query "on the server" can't complete in a timely fashion. You might be able to address that by optmizing the query, or the schema (indexes, etc...) of the data.
No, sorry. I only used your method.
DeleteOn SQL Server Management Studio, the query runs on about 37 seconds. I have used a sample SQL that runs in under a second, and everything works fine with it, indicating that your code works (that's what mathers for me). But, for some reason, when I apply the 37-seconds one SQL query, the task fails with the same timeout message, so I think it's something related with the ADO.NET connection itself and the way it communicates through our database server).
Thanks for sharing this good information here, thanks for the good insight and keep posting more.
ReplyDeleteThis is a great information!
ReplyDeleteOne quick question on this Todd. Is there a way to close the managed connections as well or use release connection on them. I have near to 8 connections all ADO.NET, but I was not able to close them out. The problem is that these 8 connections are showing up in the perfmon tool, till the time package is unloaded. Any suggestions for closing them up? I even tried with the Dispose method, but still no luck.
Thanks in advance.
Regds,
Kumar
There is no way to close managed connections. SSIS decides when to close them - that's what the "managed" word means. You can - if you wish - create and open your own connection within a script, but then you lose the other benefits of the managed nature of those connections.
DeleteI'd have to ask why you want to close the connection. Every other connection in your package - whether you use it in a script or not - behaves the same way. Is this a problem?
How do I connect to an oracle database from SSIS script task?
DeleteIt really depends on a lot of different factors - what kind of connection manager you're using... if you're using a connection manager... explaining your entire situation won't be easy in the comments section here - nor am I an Oracle expert. I recommend that you post your situation over at the MSDN SSIS forums. Make a post that lays out what you're attempting to accomplish in the Script Task - don't forget to say why you're using a Script instead of an Execute SQL Task, because that will be the first recommendation that probably won't solve your problem :). Also include the connection manager type, or your wish not to use a connection manager (and why).
DeleteI'm trying to come up with a C# code on Script Task. My C# is not that great. What I'm trying to achieve looks like this in TSQL:
ReplyDeleteSELECT * INTO Server2.DatabaseNameXX.Sample.@MyTable
FROM Server1.DatabaseName.dbo.@MyTable
How do I handle multiple server connections along with the @MyTable variable in the code?
You've got the same limitations in Script as you have in SQL - those servers have to be linked.
DeleteBut perhaps I'm reading it too literally. If you're doing a "table copy" from one server to another, I'm going to assume you're not using a Data Flow because of a good reason (that's what it's for) - like you don't know the columns that will be involved.
In that case, you'd need TWO connection managers, one to Server1, and one to Server2. Look at Tiago Cesar's comment for half of the code you need - the half to "read" from Server 1. That will get you a DataReader object filled with Server1's table. Then inside the loop, you can write to Server2. You'd do that by connecting to Server2 (with a different set of C# variables), making another SqlCommand object with your INSERT statement, and calling ExecuteNonQuery method on it.
Hi Todd,
ReplyDeleteI really find your articles insightful and very helpful, thanks for taking the time to prepare them.
I have a package that opens up csv files using a script task and analyses their structure using while and for loops in C# .Net.
This is necessary as we don't control the source of our data as it comes from a number of different sources with the columns in different orders or ommitted entirely.
I am having an issue with an SSIS pwhereby the below code runs fine when debugging the package through BIDS.
When I deploy the package to the SSISDB Catalog, the package is stopping at rowsAffected = cmd.ExecuteNonQuery();
I have run SQL Profiler whilst I ran it from SQL Agent as a package deployed to the Catalog the only code that I am getting is:
-- network protocol: LPC
set quoted_identifier on
set arithabort off
set numeric_roundabort off
set ansi_warnings on
set ansi_padding on
set ansi_nulls on
set concat_null_yields_null on
set cursor_close_on_commit off
set implicit_transactions off
set language us_english
set dateformat mdy
set datefirst 7
set transaction isolation level read committed
This looks like the Package is trying to connect to the database to run the query but it is
timing out or something which is strange because I have two connection managers in the package and the first is connected to an Execute SQL task and this runs fine.
I have tried running the package in 32 Bit (in case there was a driver issue on the server) from the agent but it doesn't fix the issue.
Any help you can provide would be appreciated.
private bool InsertRecord(string ClientName, DateTime dt)
{
bool bSuccess = true;
bool fireAgain = true;
int rowsAffected;
// need path to write file
string path = (String)Dts.Variables["User::vSourcePath"].Value;
// Retrieve reference to connection manager
ConnectionManager cm = Dts.Connections["ADO.Server"];
// Acquire connection to the ADO.VSQL.Landfill Connection manager
using (System.Data.SqlClient.SqlConnection con = (System.Data.SqlClient.SqlConnection)cm.AcquireConnection(Dts.Transaction))
{
using (SqlCommand cmd = new System.Data.SqlClient.SqlCommand("[db_ddladmin].[usp_InsertRecord]", con))
{
cmd.CommandType = CommandType.StoredProcedure;
cmd.Parameters.Add("@Name", SqlDbType.VarChar).Value = ClientName;
cmd.Parameters.Add("@Date", SqlDbType.DateTime).Value = dt;
writetotextfile(path + "err.txt", DateTime.Now.ToString("yyyy-MM-dd HHmm tt") + ": GOT Connection line 548 cmd = " + cmd.CommandText.ToString());
try
{
rowsAffected = cmd.ExecuteNonQuery();
}
catch (SqlException e)
{
writetotextfile(path + "err.txt", DateTime.Now.ToString("yyyy-MM-dd HHmm tt") + " " + e.ToString());
return false;
}
writetotextfile(path + "err.txt", DateTime.Now.ToString("yyyy-MM-dd HHmm tt") + ": GOT Connection line 550 cmd = " + con.ToString());
cm.ReleaseConnection(con);
}
}
return bSuccess;
}
Thanks for the support, Mike.
DeleteI don't see anything specific in the script that would cause such behaviour... so my first thoughts are towards permissions. What account is the package using to connect to SQL when run from the job, and is that different from an interactive run? When you say the package "stops"... do you mean it hangs indefinitely, or stops running? What information is shown in the Agent Job History? What's shown in your text log file? The package runs in BIDS in development, not under SQL Agent - but does it run on-demand command line on the server?
Hope you get to the bottom of it...
Hi Todd,
DeleteIt's been ages but just thought I'd update this, I did manage to get it working in the end.
It was a permissions issue, I needed to give the proxy that calls the package additional permissions.
Thanks for your assistance.
Looks very useful, but I'm having trouble at the start point. Using SSIS 2012, are there any particular references to be added as the "ConnectionManager cm = Dts.Connections["(local).master"];" line doesn't parse for me, highlighting the "Dts" bit.... I've tried adding managedDTS and a few others, but can't get past it.... any suggestions on missing "using" statements or references to add would be much appreciated. thanks
ReplyDeleteAre you sure you're trying to do this in a Script >Task<? On the Control Flow? "Dts" should be very usable inside a Script Task - but not from a Script component (on the data flow).
DeleteIt's usually a bad sign to want to use a connection in a script in a data flow... except when you're making a source or destination ;) But perhaps you can fill out more details of what you're looking to do?
Good info, thanks!
ReplyDeleteOne question though - how to use SQL login? It seems that the saved password is not used in the script. Is it related to package security or package configuration?
The script doesn't directly connect to the database, that's all the job of the connection manager. So if you want to use SQL authentication, you need to set it up just like you would if you weren't using a script. So yes, this means package protection level is in control of whether and how the password gets saved. And package configurations can supply passwords when they're not saved in the package due to protection level.
ReplyDelete