SQL SERVER – Using Stored Procedure in SELECT Statement

A very popular question I often receive during my Comprehensive Database Performance Health Check is about how to use stored procedures in SELECT Statement. Well, there are many methods to do that, let us learn the easiest way today.

SQL SERVER - Using Stored Procedure in SELECT Statement procselect-800x280

There are many different methods to get Stored Procedure’s results in the SELECT statement, such as creating a temp table, creating a table variable, using functions, and many more. However, here is the easiest method to run the stored procedure in SELECT statement.

For example here is the SP which you want to execute:

EXEC [AdventureWorks].[dbo].[uspGetManagerEmployees] 5
GO

You can run the following SELECT statement with the help of OPENROWSET and execute the stored procedure.

SELECT *
FROM OPENROWSET('SQLNCLI',
'server=localhost;trusted_connection=yes;',
'EXEC [AdventureWorks].[dbo].[uspGetManagerEmployees] 5')
GO

Yes, indeed it is that easy. When you run the SELECT statement with OPENROWSET and if you get an error about ad hoc queries, you can run the following command to fix the error.

Msg 15281, Level 16, State 1
SQL Server blocked access to STATEMENT ‘OpenRowset/OpenDatasource’ of component ‘Ad Hoc Distributed Queries’ because this component is turned off as part of the security configuration for this server. A system administrator can enable the use of ‘Ad Hoc Distributed Queries’ by using sp_configure. For more information about enabling ‘Ad Hoc Distributed Queries’, search for ‘Ad Hoc Distributed Queries’ in SQL Server Books Online.

sp_configure 'Show Advanced Options', 1
GO
RECONFIGURE
GO
sp_configure 'Ad Hoc Distributed Queries', 1
GO
RECONFIGURE
GO

Well, that’s it for today. Isn’t it easy to learn about Using Stored Procedure in SELECT Statement? If you want me to create a video on this topic, just leave a comment, and I will be happy to do so.

Here are my few recent videos and I would like to know what is your feedback about them. Do not forget to subscribe SQL in Sixty Seconds series. I hope you appreciate learning about the last few SQL in Sixty Seconds Video.

If you have any questions, you can always reach out to me on Twitter.

Reference: Pinal Dave (http://blog.SQLAuthority.com)

Ad Hoc Query, SQL Server, SQL Stored Procedure
Previous Post
SQL SERVER – Most Used Database Files – Script
Next Post
SQL SERVER – Find Missing Identity Values

Related Posts

8 Comments. Leave new

  • Can You include parámetros on it?

    Reply
  • @Andry – Yes, at least for pass through queries run via Microsoft Access as the client, which use ODBC instead of OLE DB. I’m pretty sure you can also include parameters with an ADO command text, which does use OLE DB. I’d include some pictures, but it doesn’t look like I can with this comment.

    Reply
  • I get this error when I try to run
    Named Pipes Provider: Could not open a connection to SQL Server [2].

    Reply
  • Md. Abu Sayeed (from Bangladesh)
    February 28, 2022 9:30 am

    How can i pass parameter

    ALTER PROC spTest
    @EmpID INT
    AS
    BEGIN
    SELECT *FROM (SELECT 1 EmpID,’Sayeed’ EmpName
    UNION
    SELECT 2 EmpID,’Runju’ EmpName
    UNION
    SELECT 3 EmpID,’Makhlesure’ EmpName
    ) A WHERE A.EmpID= @EmpID
    END
    GO
    spTest 2
    sp_configure ‘Show Advanced Options’, 1
    GO
    RECONFIGURE
    GO
    sp_configure ‘Ad Hoc Distributed Queries’, 1
    GO
    RECONFIGURE
    GO

    DECLARE @EmpID INT
    SET @EmpID=2
    SELECT *
    FROM OPENROWSET(‘SQLNCLI’,
    ‘server=192.168.97.12,1440;Database=AMBSKE;password= oLdViCtOrY2008;trusted_connection=yes;’,
    ‘exec [dbo].[spTest] 3’)

    Reply
  • Thank you so much for the useful article Mr. Dave. Just one point. In the configuration code, “EXEC” is left out before sp_configure statement.

    Reply
  • EXEC (or EXECUTE) is an optional keyword.

    Reply
  • Ye, it works, but 2 will never be accepted as a “variable/parameter” ej: ‘exec Test.dbo.spTest @EmpID=@EmpID=’)

    Reply
  • Ed Eaglehouse
    June 5, 2024 9:16 pm

    Using OPENROWSET has permission and security issues. It’s usually disabled with good reason. While you can insert into a table or table variable by executing a stored procedure, selecting directly from a stored procedure is not possible.

    Reply

Leave a Reply