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

How to combine two tables when one table is in different database and this table will determine the value to be shown on the first table. Expand / Collapse
Author
Message
Posted Monday, January 14, 2013 9:36 AM


SSC Rookie

SSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC Rookie

Group: General Forum Members
Last Login: Tuesday, December 9, 2014 12:12 PM
Points: 29, Visits: 180
Dear members,
Hello, a pleasant day to everyone.
I would want to ask help about this query that I need for reporting.
Let’s for example I have a database named DBMain, and I want to combine two tables by means of their key named InvTrackNo, eventually here is the query:
SELECT 
A.ConsInvNumber AS [Consolidated Invoice No],
A.InvTrackNo AS [Invoice TrackNo],
B.SaleOrderNo AS [Sales OrderNo],
B.OrderLine AS [Sales Order LineNo],
A.CtrlNo

FROM DBMain.dbo.ConsInvoiceDetail AS A INNER JOIN
DBMain.dbo.IndInvDetail AS B ON A.InvTrackNo = B.InvTrackNo
WHERE A.ConsInvNumber=980029768

And here is the output of my main query:
Consolidated InvoiceNo	    Invoice TrackNo	Sales OrderNo	   Sales Order LineNo	CtrlNo
980029768 0901164982 162194751 100 407633405
980029768 0901164982 162194751 200 407633405
980029768 0901164982 162194751 100 407633405
980029768 0901164982 162194751 200 407633405
980029768 0901192336 161891209 40 0
980029768 0901192337 161891209 100 0
980029768 0901192338 161891209 160 0
980029768 0901204388 162044081 100 406488527
980029768 0901204389 162044081 200 406488589


I noticed that some Control Number (A.CtrlNo) are zeros, my superior said I should look for the archive table and somehow “combine” them to this first query.

I tried to query first the archive table named OrderSummaryArchive that is located in a different database named DBArchive:

SELECT CtrlNo, 
SalesOrderNo,
SalesOrderLineNo
FROM OrderSummaryArchive
WHERE SalesOrderNo = 161891209

And here is the output of my second query:
CtrlNo	  SalesOrderNo    SalesOrderLineNo
405290666 161891209 20
405290666 161891209 40
405290669 161891209 60
405290669 161891209 80
405290669 161891209 100
405290674 161891209 120
405290674 161891209 140
405290674 161891209 160

As you can see, the highlighted result will complete my first query, I just do not how how to combine them if the second table is in another database, and how to check the appropriate CtrlNo for each record.


My expected result would be:

ConsInvoiceNo      InvoiceTrackNo	Sales OrderNo	   Sales Order LineNo	CtrlNo     CameFromArchive
980029768 0901164982 162194751 100 407633405 0
980029768 0901164982 162194751 200 407633405 0
980029768 0901164982 162194751 100 407633405 0
980029768 0901164982 162194751 200 407633405 0
980029768 0901192336 161891209 40 405290666 1
980029768 0901192337 161891209 100 405290669 1
980029768 0901192338 161891209 160 405290674 1
980029768 0901204388 162044081 100 406488527 0
980029768 0901204389 162044081 200 406488589 0

The report should include an additional column called CameFromArchive so that the database administrator would determine what CtrlNo came from the archive table (0-NO 1-YES).


I hope someone could help me fix my first query. Thank you.


Respectfully Yours,

Mark Squall


________________________________
"Listen to advice and accept instruction, and in the end you will be wise." -Proverbs 19:20
Post #1406814
Posted Monday, January 14, 2013 12:33 PM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Today @ 3:05 PM
Points: 13,320, Visits: 12,804
This is somewhat of a shot in the dark because we don't have ddl or sample data to work with.

SELECT 
A.ConsInvNumber AS [Consolidated Invoice No],
A.InvTrackNo AS [Invoice TrackNo],
B.SaleOrderNo AS [Sales OrderNo],
B.OrderLine AS [Sales Order LineNo],
case when A.CtrlNo = 0 then osa.CtrlNo else a.CtrlNo end as CtrlNo
FROM DBMain.dbo.ConsInvoiceDetail AS A INNER JOIN
DBMain.dbo.IndInvDetail AS B ON A.InvTrackNo = B.InvTrackNo
Left Join (select top 1 CtrlNo from DBArchive.dbo.OrderSummaryArchive where SalesOrderNo = B.SaleOrderNo) osa
WHERE A.ConsInvNumber=980029768

I would suggest that when aliasing your tables you don't use A, B, C. Instead use some sort of abbreviation of the table name. It makes debugging a lot easier and anybody looking at your code doesn't have to scratch out their eyeballs trying to figure out which table certain columns come from.


_______________________________________________________________

Need help? Help us help you.

Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

Need to split a string? Try Jeff Moden's splitter.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
Post #1406909
Posted Monday, January 14, 2013 5:13 PM


SSC Rookie

SSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC Rookie

Group: General Forum Members
Last Login: Tuesday, December 9, 2014 12:12 PM
Points: 29, Visits: 180
Hello Sean. Thank you for the sample query, it works just fine (with some minor modifications). Awesome!
I apologize to you (and to the readers) for making my aliases so short, actually I am just in a "hurry" that is why I used short aliases. In my query here, I (really) used full table abbreviation. (silly me).

Just one last thing, how would I add an additional column called CameFromArchive so that the database administrator would determine what CtrlNo came from the archive table (0-NO 1-YES)?

Thank you so much and more power!


Respectfully Yours,

Mark Squall


________________________________
"Listen to advice and accept instruction, and in the end you will be wise." -Proverbs 19:20
Post #1406988
Posted Tuesday, January 15, 2013 3:19 AM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Yesterday @ 3:02 AM
Points: 2, Visits: 223
marksquall (1/14/2013Just one last thing, how would I add an additional column called CameFromArchive so that the database administrator would determine what CtrlNo came from the archive table (0-NO 1-YES)?


I think you can use a case just like the one that was allready included in the query posted by Sean, like so :
SELECT 
A.ConsInvNumber AS [Consolidated Invoice No],
A.InvTrackNo AS [Invoice TrackNo],
B.SaleOrderNo AS [Sales OrderNo],
B.OrderLine AS [Sales Order LineNo],
case when A.CtrlNo = 0 then osa.CtrlNo else a.CtrlNo end as CtrlNo,
case when OSA.CtrlNo is NULL then 'No' else 'Yes' end as CameFromArchive
FROM DBMain.dbo.ConsInvoiceDetail AS A INNER JOIN
DBMain.dbo.IndInvDetail AS B ON A.InvTrackNo = B.InvTrackNo
Left Join (select top 1 CtrlNo from DBArchive.dbo.OrderSummaryArchive where SalesOrderNo = B.SaleOrderNo) osa
WHERE A.ConsInvNumber=980029768



EDIT: forgot a comma


MCSA, MCITP
SQL Server / Windows Server (2008)
Post #1407126
Posted Thursday, January 17, 2013 7:19 AM


SSC Rookie

SSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC Rookie

Group: General Forum Members
Last Login: Tuesday, December 9, 2014 12:12 PM
Points: 29, Visits: 180
Hello Geomorian. That was really cool. I am thinking it has be another technique, like for example, using a variable (BIT type) to set to either 1 or 0, then "convert" it to "YES" or "NO". (I guess I am just making my life too hard, silly me.). But for the record, is this possible? If yes, can someone give a little example?

Well anyway, this is straight to the point, and it is awesome!

Thank you Geomorian and Sean Lange.

Warm regards,

Mark Squall


________________________________
"Listen to advice and accept instruction, and in the end you will be wise." -Proverbs 19:20
Post #1408415
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse