SQL Functions in Excel?

  • 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?

  • 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

  • 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

  • That function worked like a charm for me thank you.

  • I know this is a bit of a late replay, but I am currently working on a problem similar to this one.

    you can create in excel a sql query of table in the same data base as your function (data tab--> from Other sources --> From SQL server) after you select a random table you can right click on the table and select table--> External Data properties --> connection properties --> Definition tab , here in the command line you can put the sql code to call your function

    you can do the same thing for table function as well

    this has the benefit of not running the macro to refresh, you can right click the table and click refresh or just set it to refresh whenever.

  • Hi viacheslav.gorelik,

    have you been able to pass a parameter to the udf function that way ? my sql function works fine in Excel when the Command text in the Connection Properties is like this:

    select * from fnMyInlineTableFunction ('123456')

    but I can't find a way to male it use a parameter (read from a cell in the excel file for instance), something like:

    select * from fnMyInlineTableFunction (?)

    thanks,

    andrea

Viewing 6 posts - 1 through 5 (of 5 total)

You must be logged in to reply to this topic. Login to reply