Database Journal
MS SQL Oracle DB2 Access MySQL PostgreSQL Sybase PHP SQL Etc SQL Scripts & Samples Links Database Forum

» Database Journal Home
» Database Articles
» Database Tutorials
MS SQL
Oracle
DB2
MS Access
MySQL
» RESOURCES
Database Tools
SQL Scripts & Samples
Links
» Database Forum
» Sitemap
Free Newsletters:
DatabaseDaily  
News Via RSS Feed


follow us on Twitter
Database Journal |DBA Support |SQLCourse |SQLCourse2
 

Featured Database Articles

MS SQL

Posted Mar 5, 2004

MS SQL Server Distributed Partitioned Views - Page 2

By Don Schlichting

Create Table

For this example, we will be working with a subset of the pubs Authors table. We will imagine the table was very large and most of our lookups were done by last name. In this case, we could split the Authors table in half, with one server getting records with a last name beginning with A - M, and the other server getting records N - Z. From server1, create and load a test table.

CREATE DATABASE test
GO

USE test
GO

CREATE TABLE AuthorsAM(
    au_lname varchar(40) NOT NULL,
    au_fname varchar(20) NULL,
        CONSTRAINT CHK_AuthorsAM CHECK (au_lname < 'N')
	)

GO

INSERT INTO AuthorsAM
    (au_lname, au_fname)
    SELECT au_lname, au_fname
    FROM pubs..authors
    WHERE au_lname < 'N'

From server2, almost identical code is run again. The check will be changed for our new range of last names. Notice the tables do not need to have the same name on each server. Server1s' table is called AuthorsAM, server2s' table is called AuthorsNZ. Our view will take care of sorting this out.

CREATE DATABASE test
GO

USE test
GO

CREATE TABLE AuthorsNZ(
	au_lname varchar(40) NOT NULL,
	au_fname varchar(20) NULL,
             CONSTRAINT CHK_AuthorsNZ CHECK (au_lname >= 'N')
	)

GO

INSERT INTO AuthorsNZ
	(au_lname, au_fname)
	SELECT au_lname, au_fname
	FROM pubs..authors
	WHERE au_lname >= 'N'	

The critical section of code is the constraint. The check must insure that a row has only one exclusive table in which to be located. When our views are run, the Query Optimizer will use these constraints to determine which servers will receive the distributed work.

Distributed Partitioned Views

The last step is the actual creation of the views. The UNION operator is used to merge the results from both tables into one result set. See BOL "Union operator" for detailed Union explanations and rules.

From server1:

CREATE VIEW AllAuthors
AS
SELECT * 
FROM AuthorsAM

UNION ALL

SELECT *
FROM server2.test.dbo.AuthorsNZ

GO

From server2 the code again is almost identical. Only the server names are changed.

CREATE VIEW AllAuthors
AS
SELECT * 
FROM AuthorsNZ

UNION ALL

SELECT *
FROM server1.test.dbo.AuthorsAM

GO

Running a simple select from server1 produced this Execution Plan:

We can see the local table scan on server1 is merged with a remote query on server1. Our view follows all the standard rules for views. So returning only subsets requires nothing more than a standard where clause:

SELECT *
FROM AllAuthors
WHERE au_lname BETWEEN 'F' AND 'W'

Conclusion

While setting up Federated servers is not a quick task, the performance gains produced by Distributed Partitioned Views on large tables can make it more than worth while. We will continue next month with the requirements for DML on Federated servers, and optimization techniques.

» See All Articles by Columnist Don Schlichting



MS SQL Archives

Comment and Contribute

 


(Maximum characters: 1200). You have characters left.

 

 




Latest Forum Threads
MS SQL Forum
Topic By Replies Updated
SQL 2005: SSIS: Error using SQL Server credentials poverty 3 August 17th, 07:43 AM
Need help changing table contents nkawtg 1 August 17th, 03:02 AM
SQL Server Memory confifuration bhosalenarayan 2 August 14th, 05:33 AM
SQL Server Primary Key and a Unique Key katty.jonh 2 July 25th, 10:36 AM


















Thanks for your registration, follow us on our social networks to keep up-to-date