SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


SQL Functions in Excel?


SQL Functions in Excel?

Author
Message
MNsql
MNsql
Grasshopper
Grasshopper (10 reputation)Grasshopper (10 reputation)Grasshopper (10 reputation)Grasshopper (10 reputation)Grasshopper (10 reputation)Grasshopper (10 reputation)Grasshopper (10 reputation)Grasshopper (10 reputation)

Group: General Forum Members
Points: 10 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?
A. Harmon
A. Harmon
SSC Journeyman
SSC Journeyman (75 reputation)SSC Journeyman (75 reputation)SSC Journeyman (75 reputation)SSC Journeyman (75 reputation)SSC Journeyman (75 reputation)SSC Journeyman (75 reputation)SSC Journeyman (75 reputation)SSC Journeyman (75 reputation)

Group: General Forum Members
Points: 75 Visits: 219
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
A. Harmon
A. Harmon
SSC Journeyman
SSC Journeyman (75 reputation)SSC Journeyman (75 reputation)SSC Journeyman (75 reputation)SSC Journeyman (75 reputation)SSC Journeyman (75 reputation)SSC Journeyman (75 reputation)SSC Journeyman (75 reputation)SSC Journeyman (75 reputation)

Group: General Forum Members
Points: 75 Visits: 219
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



digitalox
digitalox
SSC-Enthusiastic
SSC-Enthusiastic (193 reputation)SSC-Enthusiastic (193 reputation)SSC-Enthusiastic (193 reputation)SSC-Enthusiastic (193 reputation)SSC-Enthusiastic (193 reputation)SSC-Enthusiastic (193 reputation)SSC-Enthusiastic (193 reputation)SSC-Enthusiastic (193 reputation)

Group: General Forum Members
Points: 193 Visits: 458
That function worked like a charm for me thank you.
viacheslav.gorelik
viacheslav.gorelik
Forum Newbie
Forum Newbie (7 reputation)Forum Newbie (7 reputation)Forum Newbie (7 reputation)Forum Newbie (7 reputation)Forum Newbie (7 reputation)Forum Newbie (7 reputation)Forum Newbie (7 reputation)Forum Newbie (7 reputation)

Group: General Forum Members
Points: 7 Visits: 22
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.
andreacuozzo
andreacuozzo
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: 0
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
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