Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase

Query on Linked Server Expand / Collapse
Author
Message
Posted Thursday, July 24, 2014 2:52 AM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Tuesday, August 5, 2014 10:27 PM
Points: 14, Visits: 34
Hi,

I have a query if we can populate the same table A in a database D with data coming from 2 different Linked servers connected to 2 different data source (via ODBC) connection.

I'm new to SQL server and trying to figure the role of Linked server in SQL server 2008 scenario. I have a production SQL server 2008 in place with reports getting created through various procedures created on it. Currently it has a database with tables and procedures and a Linked server created over 1 data source which connects to a sybase database through ODBC.

In new scenario we'll have data devided over 2 data sources and thus we'll create 2 ODBC connections to fetch the data. It is required to get data loaded in the same table A of database D from the 2 data sources.

So is creating a new Linked server with new data connection the correct solution to this.

Thanks in advance.
Post #1595823
Posted Thursday, July 24, 2014 5:19 AM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: 2 days ago @ 1:30 PM
Points: 12,895, Visits: 32,089
certainly possible.
remember linked servers are slow, especially if you are joining the data together with local or other rmeote data.

the reason is if you did something like this:
SELECT * From myTable
INNER JOIN MyLinkedServer.SandBox.dbo.AnotherTable myAlias
ON MyTable.ID = MyAlias.ID
WHERE myAlias.CustomerID = 12

looks pretty simple, right? with a WHERE statement that specific, i'd expect very few rows, since how many rows have that specific customerID?

the problem is behind the scenes, the entire contents of the linked server table MyLinkedServer.SandBox.dbo.AnotherTable gets copied over into tempDB, and then joined to the local table, and then that gets filtered like a normal query.

so if the remote tables are MillionBillion row tables, you see a massive performance hit.


to avoid things like that, you want to use a divide and conquer strategy to minimize the data being copied.
using OPENQUERY for example,

SELECT *
INTO #tmp
FROM OPENQUERY( [MyLinkedServer],'SET FMTONLY OFF; EXEC (''USE SandBox; SELECT * FROM dbo.AnotherTable WHERe CustmerID = 12'')')


SELECT * From myTable
INNER JOIN #tmp myAlias
ON MyTable.ID = MyAlias.ID
WHERE myAlias.CustomerID = 12

in the above example, the linked server pre-filtered all the rows on it's server side, before passing the results....that's a smaller temp table, so it's quicker.
the rest of the command barely changed.


Lowell

--There is no spoon, and there's no default ORDER BY in sql server either.
Actually, Common Sense is so rare, it should be considered a Superpower. --my son
Post #1595856
Posted Thursday, July 24, 2014 3:49 PM
SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: 2 days ago @ 3:14 PM
Points: 2,098, Visits: 3,155
Lowell (7/24/2014)
SELECT * From myTable
INNER JOIN MyLinkedServer.SandBox.dbo.AnotherTable myAlias
ON MyTable.ID = MyAlias.ID
WHERE myAlias.CustomerID = 12

looks pretty simple, right? with a WHERE statement that specific, i'd expect very few rows, since how many rows have that specific customerID?

the problem is behind the scenes, the entire contents of the linked server table MyLinkedServer.SandBox.dbo.AnotherTable gets copied over into tempDB, and then joined to the local table, and then that gets filtered like a normal query.


I don't believe that's true. SQL does not always have to copy the rows over to the local server, and of course it won't if it can avoid it.


SQL DBA,SQL Server MVP('07, '08, '09)

"We came in spastic, Like tameless horses /
We left in plastic, As numbered corpses / ...
Remember Charlie, Remember Baker /
They left their childhood On every acre /
And who was wrong? And who was right? /
It didn't matter in the thick of the fight." : the inimitable Mr. Billy Joel, about the Vietnam War
Post #1596036
Posted Friday, July 25, 2014 2:06 AM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Tuesday, August 5, 2014 10:27 PM
Points: 14, Visits: 34
Thanks Lowell and Scott for the reply.

Please help me with following queries:
1. Where and how can we access and check the temp table .
2. Why is Linked servers required.
3. And can we load a same table with data coming from 2 different data sources connected through ODBC.

If the scenario is non descriptive than do let me know what additional information is required.

Thanks in advance
Post #1596112
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse