[AccessD] Query Question

Drew Wutka DWUTKA at Marlow.com
Wed Apr 30 10:45:45 CDT 2008


Sounds like a job for a subquery:

SELECT T1.LookupValue, (SELECT Result1 FROM LKUP WHERE
RangeStart<=T1.LookupValue AND RangeEnd>=T1.LookupValue) AS Result1,
(SELECT Result2 FROM LKUP WHERE RangeStart<=T1.LookupValue AND
RangeEnd>=T1.LookupValue) AS Result2
FROM Table1 as T1

-----Original Message-----
From: accessd-bounces at databaseadvisors.com
[mailto:accessd-bounces at databaseadvisors.com] On Behalf Of Andy Lacey
Sent: Wednesday, April 30, 2008 10:30 AM
To: Access Developers discussion and problem solving
Subject: [AccessD] Query Question

Hi folks
Looking for best solution to a simple problem. It's of the "if var is
anything between x and y return this value, if anywhere between xx and
yy
return that etc". I'll express it in its most basic form:

Table LKUP has fields
[RangeStart], [RangeEnd], [Result1], [Result2] and looks like this

0   14.9  1500  1700
15  24.9  2000  2500
25  99.9  2350  2900

([RangeEnd] is probably superfluous but I hope it makes the example
clearer)

Table1 has (among others) field [LookupValue]

I want a query which if [LookupValue] on Table1 is anywhere between 0
and
14.9 returns 1500 and 1700 from Lkup, if it's between 15 and 24.9
returns
2000 and 2500, and anything from 25 upwards returns 2350 and 2900.

My solution is this:
SELECT Table1.[LookupValue],Max([Lkup].Result1) ,Max([Lkup].Result2)
FROM Table1 LEFT JOIN [Lkup] ON Table1.[LookupValue] >=
[Lkup].[RangeStart]
GROUP BY Table1.[LookupValue];

Seems to work but because it uses Max it depends on the values in
Result1
and Result2 getting larger as the lookups get larger. If they didn't
then
the Max would return the wrong results (I think).

Any other, or better, ideas?

--
Andy Lacey
http://www.minstersystems.co.uk

________________________________________________
Message sent using UebiMiau 2.7.2

-- 
AccessD mailing list
AccessD at databaseadvisors.com
http://databaseadvisors.com/mailman/listinfo/accessd
Website: http://www.databaseadvisors.com
The information contained in this transmission is intended only for the person or entity to which it is addressed and may contain II-VI Proprietary and/or II-VI Business Sensitive material. If you are not the intended recipient, please contact the sender immediately and destroy the material in its entirety, whether electronic or hard copy. You are notified that any review, retransmission, copying, disclosure, dissemination, or other use of, or taking of any action in reliance upon this information by persons or entities other than the intended recipient is prohibited.





More information about the AccessD mailing list