Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


select with subquery in select clause


select with subquery in select clause

Author
Message
rchavez
rchavez
Forum Newbie
Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)

Group: General Forum Members
Points: 4 Visits: 13
Hi I need to make a select from 2 tables whit this layout always with the newest datetime exchange currency.
The local cuurency is Mexican Pesos

Table 1 Currencies example:
CurrencyID Key Description
1 USD USA Dollar
2 EUR European Euro
3 Yen Japan Yen


Tabla 2 is Day exchange Currency
CurrencyID Equivalent DateTime
1 12.50 2010-08-07 08:00:00
1 12.55 2010-08-07 08:10:00
1 12.49 2010-08-07 08:20:00
1 12.60 2010-08-07 08:30:00
1 12.51 2010-08-07 08:40:00
1 12.52 2010-08-07 08:50:00
1 12.48 2010-08-07 09:00:00
1 12.61 2010-08-07 09:10:00 <-- the newest xchange for USD
2 16.87 2010-08-07 08:00:00
2 16.90 2010-08-07 08:10:00
2 16.88 2010-08-07 08:20:00
2 16.85 2010-08-07 08:30:00
2 16.87 2010-08-07 08:40:00
2 16.92 2010-08-07 08:50:00
2 16.80 2010-08-07 09:00:00
2 16.95 2010-08-07 09:10:00 <-- the newest xchange for Euro
3 6.73 2010-08-07 08:00:00
3 6.70 2010-08-07 08:10:00
3 6.78 2010-08-07 08:20:00
3 6.75 2010-08-07 08:30:00
3 6.77 2010-08-07 08:40:00
3 6.72 2010-08-07 08:50:00
3 6.70 2010-08-07 09:00:00
3 6.75 2010-08-07 09:10:00 <-- the newest xchange for Euro

The select query I need is always the newest exchange currency for each currency in table 1, something like this

CurrencyID Key Description Equivalent DateTime
1 USD USA Dollar 12.61 2010-08-07 09:10:00
2 EUR European Euro 16.95 2010-08-07 09:10:00
3 Yen Japan Yen 6.75 2010-08-07 09:10:00

How can i do the select?

Plese help me
Jose Roberto Chavez
drew.allen
drew.allen
SSCrazy
SSCrazy (2.7K reputation)SSCrazy (2.7K reputation)SSCrazy (2.7K reputation)SSCrazy (2.7K reputation)SSCrazy (2.7K reputation)SSCrazy (2.7K reputation)SSCrazy (2.7K reputation)SSCrazy (2.7K reputation)

Group: General Forum Members
Points: 2687 Visits: 9960
If you want to improve your chances of getting help, you really should post the DDL statements to create your tables and the DML statements to insert sample data into your tables. It's usually a good idea to use table variables for doing this so that people don't have to drop the tables afterward.

DECLARE @Currencies TABLE (
CurrencyID int
, CurrencyCode char(3)
, CurrencyDesc varchar(50)
)

INSERT @Currencies
SELECT 1,'USD','USA Dollar'
UNION
SELECT 2,'EUR','European Euro'
UNION
SELECT 3,'Yen','Japan Yen'

DECLARE @ExchangeRate TABLE (
CurrencyID int
, Equivalent float
, ExchangeRateDate datetime
)




You also might want to avoid using keywords (like KEY or DATETIME) as column or table names. If you forgot to correctly delimit them, you could get SQL errors.

I would use a CTE and the Row_Number() function to solve your problem. Since you want the most recent for each currency, you need to use the PARTITION BY clause, and since you want the most recent, you need to sort your ORDER BY clause in DESC order. The WHERE clause in the final select gives you the most recent exchange rate.


WITH OrderedExchangeRates AS (
SELECT CurrencyID, Equivalent, ExchangeRateDate
-- The following is the key to getting the latest rate.
, ROW_NUMBER() OVER( PARTITION BY CurrencyID ORDER BY ExchangeRateDate DESC ) AS RowNum
FROM @ExchangeRate
)

SELECT c.CurrencyID, c.CurrencyCode, c.CurrencyDesc, er.Equivalent, er.ExchangeRateDate
FROM @Currencies AS c
INNER JOIN OrderedExchangeRates AS er
ON c.CurrencyID = er.CurrencyID
WHERE er.RowNum = 1



Drew

J. Drew Allen
Business Intelligence Analyst
Philadelphia, PA
How to post data/code on a forum to get the best help.
How to Post Performance Problems
Make sure that you include code in the appropriate IFCode tags, e.g. [code=sql]<your code here>[/code]. You can find the IFCode tags under the INSERT options when you are writing a post.
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search