Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase

SQL Functions in Excel? Expand / Collapse
Author
Message
Posted Tuesday, May 11, 2010 11:19 AM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Tuesday, May 27, 2014 3:57 PM
Points: 4, Visits: 32
I have a scalar SQL function that I need to use within Excel. Otherwise, I'll need to use Excel formulas to do the same thing this function does, which I'd love to avoid (the function is pretty complex). Is there a way?

So the function is something like:
myDatabase.dbo.myFunction(integerVal).

I'd like to pull integerVal from one column in Excel and put the function's result in another column. Can this be done? How?
Post #919889
Posted Tuesday, May 11, 2010 11:28 AM
SSC Rookie

SSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC Rookie

Group: General Forum Members
Last Login: Yesterday @ 11:35 AM
Points: 27, Visits: 98
I don't think there is an easy way to do this. I believe you'd have to write a user defined function in Excel to make a connection to the database and utilize the scalar function from SQL. It's certainly not an option out of the box
Post #919895
Posted Tuesday, May 11, 2010 12:12 PM
SSC Rookie

SSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC Rookie

Group: General Forum Members
Last Login: Yesterday @ 11:35 AM
Points: 27, Visits: 98
I'm a little bored, so I put together a quick excel UDF in VBA that would do what you need.

This was done quickly, so there is probably a better way to do some of it, but it works. It also assumes the input and output of the SQL scalar function are integers

Public Function SQL_UDF(intInput As Integer) As Integer

Dim cnt As ADODB.Connection
Dim rst As ADODB.Recordset
Dim cmd As ADODB.Command
Dim stCon As String 'SQL Connection string
Dim stQuery As String 'Query string


'Set ADODB requirements
Set cnt = New ADODB.Connection
Set rst = New ADODB.Recordset
Set cmd = New ADODB.Command

'Define database connection string
stCon = "Provider=SQLOLEDB.1;"
stCon = stCon + "Integrated Security=SSPI;"
stCon = stCon + "Persist Security Info=True;"
stCon = stCon + "Data Source=SQLSERVER;"
stCon = stCon + "Initial Catalog=TestDB"

'Open database connection
cnt.ConnectionString = stCon
cnt.Open

' Defines the stored procedure commands
stQuery = "select dbo.TestFunction(" & intInput & ")" 'Define name of Stored Procedure to execute.
'cmd.CommandType = adCmdStoredProc 'Define the ADODB command
cmd.CommandType = adCmdText
cmd.ActiveConnection = cnt 'Set the command connection string
cmd.CommandText = stQuery 'Define Stored Procedure to run


'Execute query and return to a recordset
rst.Open cmd.Execute

SQL_UDF = rst.Fields(0).Value

'Close database connection and clean up
If CBool(rst.State And adStateOpen) = True Then rst.Close
Set rst = Nothing

If CBool(cnt.State And adStateOpen) = True Then cnt.Close
Set cnt = Nothing


End Function


Post #919926
Posted Thursday, May 22, 2014 2:16 PM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Saturday, November 15, 2014 7:30 PM
Points: 101, Visits: 362
That function worked like a charm for me thank you.
Post #1573779
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse