Listing all Tables of a Linked SQL Server Database

In this article, we will be discussing about, how you can easily list all tables of a linked SQL Server database.

Introduction

There are many scenarios in the DBMSs world where you might need to use a linked server between two different SQL Server instances in order to execute direct queries between them. However, the majority of T-SQL auto-complete tools have difficulties to list the objects (i.e. tables) of the linked server’s database.

 

Custom Stored Procedure to Retrieve Linked SQL Server Database Tables

A way to see these objects, is to browse via SSMS’s Object Explorer. What about however if you want to have a quick view of all the available tables in the linked server’s database while writing your T-SQL script?

The answer is easy! You can do this by using the Information Schema Views. Below you will find a stored procedure that I created which can help you to list all the tables of linked server’s database.

Here’s the code:

------------------------------------------------------------------------------------------
-- Sample Code for Blog Post: Listing all Tables of a Linked Server's Database
-- Author: Artemakis Artemiou, Former Microsoft Data Platform MVP
--
-- Disclaimer: This is a sample code. Do not use it in Production Systems before properly
-- testing it. You bear sole responsibility for usage of any content of this T-SQL code. 
-- You are responsible for any loss of data, loss of peace or any damages due to usage of 
-- this code. Always take backup of your data.
------------------------------------------------------------------------------------------
USE [ENTER_DATABASE_NAME];
GO

CREATE PROCEDURE [dbo].[DBTableInfo] (@LinkedServerName varchar(50), @DBName varchar(50))
AS

--variables declaration
DECLARE @LinkedServerNameFiltered VARCHAR(50)
DECLARE @LinkedServerNameFound int
DECLARE @DBsFound int
DECLARE @DBNameFiltered varchar(50)
DECLARE @Command nvarchar(500)

--check if specified linked server exists
SET @LinkedServerNameFiltered=QUOTENAME(@LinkedServerName);
SET @LinkedServerNameFound=0;
SET @LinkedServerNameFound=(SELECT COUNT(*) FROM sys.servers s WHERE s.name=@LinkedServerName);

--report findings
IF @LinkedServerNameFound=0
BEGIN
PRINT 'Error: Linked server ' + @LinkedServerNameFiltered+ ' not found.';
RETURN;
END

--check if specified database exists
DECLARE @QUERY nvarchar(250);
SET @DBNameFiltered = QUOTENAME(@DBName,'''');
SET @DBsFound=0;
SET @QUERY='(SELECT @DBs=COUNT(*) FROM ' + @LinkedServerNameFiltered +'.[master].sys.sysdatabases s WHERE s.name='+@DBNameFiltered+')';
EXEC sp_executesql @QUERY, N'@DBs int OUTPUT', @DBs=@DBsFound OUTPUT;

--report findings
IF @DBsFound=0
BEGIN
PRINT 'Error: Database ' + @DBNameFiltered + ' not found.';
RETURN;
END

--construct dynamic T-SQL statement
SET @DBNameFiltered = QUOTENAME(@DBName);
SET @LinkedServerNameFiltered=QUOTENAME(@LinkedServerName);

SET @Command= 'SELECT TABLE_SCHEMA as TableSchema, TABLE_NAME as TableName,(''SELECT TOP 10 * FROM '+ @LinkedServerNameFiltered +'.'+ @DBNameFiltered +'.'' + QUOTENAME(TABLE_SCHEMA) + ''.'' + QUOTENAME(TABLE_NAME)) as SampleQuery
FROM ' + @LinkedServerNameFiltered+'.' + @DBNameFiltered+'.INFORMATION_SCHEMA.TABLES i WHERE i.TABLE_TYPE LIKE ''%TABLE%'' ORDER BY 1';

--execute the command
EXEC sp_executesql @command;
------------------------------------------------------------------------------------------
You can call the stored procedure as follows:
USE [ENTER_DATABASE_NAME];
GO

EXEC [dbo].[DBTableInfo] 'LINKED_SERVER_NAME', 'LINKED_SERVER_DB'
GO

 

The stored procedure displays three columns for each record: (i) Table Schema, (ii) Table Name, (iii) A sample query that can be executed and returns the top 10 rows for the specific table.

Sample output of the stored procedure:

 

Listing all tables of a linked server - SQL Server - SQLNetHub

 

Strengthen you SQL Server Development Skills – Enroll to our Online Course!

Feel free to check our online course titled “Essential SQL Server Development Tips for SQL Developers(special limited-time discount included in link).

Sharpen your SQL Server database programming skills via a large set of tips on T-SQL and database development techniques. The course, among other, features over than 30 live demonstrations!

Essential SQL Server Development Tips for SQL Developers - Online Course
(Lifetime Access, Certificate of Completion, Downloadable resources and more!)

Recommended Online Courses:

 

 

Featured Database Productivity Tools

Develop T-SQL code faster with Snippets Generator: Create and modify T-SQL snippets for use in SQL Management Studio, fast, easy and efficiently.

Snippets Generator - SQL Snippets Creation Tool

Learn more

 

Dynamic SQL Generator: Convert static T-SQL code to dynamic and vice versa, easily and fast.

Dynamic SQL Generator: Easily convert static SQL Server T-SQL scripts to dynamic and vice versa.

Learn more

 

Did you find this article useful and interesting? Feel free to leave your comment!

If you enjoy my SQL Server development tips and articles, I have something special just for you. It is one of my eBooks and it is called “Developing with SQL Server“. Check it out!

Subscribe to our newsletter and stay up to date with our latest articles on SQL Server and related technologies!

Check out our latest software releases! All our software tools have free trial versions to download.

 

Rate this article: 1 Star2 Stars3 Stars4 Stars5 Stars (2 votes, average: 5.00 out of 5)

Loading...

Reference: SQLNetHub.com (https://www.sqlnethub.com)

© SQLNetHub