Openquery with parameters

Ludmil G 101 Reputation points
2022-02-24T10:03:42.497+00:00

I need to use Openquery to join a linked server. I am trying to filter the linked server by a string and I need to exclude the blank records.

DECLARE @Test1 NVARCHAR(10);
SET @Test1 = '111';
SELECT * from Test1 t1 
   JOIN OPENQUERY(TestServer, 'SELECT * FROM T2 WHERE Column1 = ''' +  @Test1 + ''' and Column2 != ''')t2 ON t1.Column3 = t2.Column3
SQL Server
SQL Server
A family of Microsoft relational database management and analysis systems for e-commerce, line-of-business, and data warehousing solutions.
13,785 questions
Transact-SQL
Transact-SQL
A Microsoft extension to the ANSI SQL language that includes procedural programming, local variables, and various support functions.
4,637 questions
0 comments No comments
{count} votes

3 answers

Sort by: Most helpful
  1. Viorel 117.2K Reputation points
    2022-02-24T20:15:32.687+00:00

    Consider using sp_executesql according to https://learn.microsoft.com/en-US/troubleshoot/sql/admin/pass-variable-linked-server-query:

    EXEC TestServer.master.dbo.sp_executesql N'SELECT * FROM MyDatabase.dbo.T2 WHERE Column1 = @Test1 and Column2 != ''''',  
        N'@Test1 nvarchar(10)', @Test1  
    
    0 comments No comments

  2. Erland Sommarskog 111.1K Reputation points MVP
    2022-02-24T22:54:07.76+00:00

    I have some tips on how to do this without losing your sanity in my article on dynamic SQL: https://www.sommarskog.se/dynamic_sql.html#remotedata.

    0 comments No comments

  3. LiHong-MSFT 10,051 Reputation points
    2022-02-28T02:04:00.75+00:00

    Hi @Ludmil G
    Please check this:

    DECLARE @Test1 NVARCHAR(10);  
    SET @Test1 = '111';  
    SELECT *   
    FROM Test1 t1   
    JOIN OPENQUERY(TestServer, 'SELECT * FROM T2 WHERE Column1 = ''' +  @Test1 + ''' and Column2 != ''''')t2 ON t1.Column3 = t2.Column3  
    

    Best regards,
    LiHong


    If the answer is the right solution, please click "Accept Answer" and kindly upvote it. If you have extra questions about this answer, please click "Comment".
    Note: Please follow the steps in our Documentation to enable e-mail notifications if you want to receive the related email notification for this thread.

    0 comments No comments

Your answer

Answers can be marked as Accepted Answers by the question author, which helps users to know the answer solved the author's problem.