Thread: Help writing a piece of SQL

Help writing a piece of SQL

From
"Nigel Bishop"
Date:
<div class="Section1"><p class="MsoNormal"><font face="Courier New" size="2"><span lang="EN-GB"
style="font-size:10.0pt;font-family:"CourierNew"">Hi, I would appreciate some help writing a piece of
SQL</span></font><pclass="MsoNormal"><font face="Courier New" size="2"><span lang="EN-GB"
style="font-size:10.0pt;font-family:"CourierNew""> </span></font><p class="MsoNormal"><font face="Courier New"
size="2"><spanlang="EN-GB" style="font-size:10.0pt;font-family:"Courier New"">PG803</span></font><p
class="MsoNormal"><fontface="Courier New" size="2"><span lang="EN-GB" style="font-size:10.0pt;font-family:"Courier
New""> </span></font><pclass="MsoNormal"><font face="Courier New" size="2"><span lang="EN-GB"
style="font-size:10.0pt;font-family:"CourierNew"">My table/data looks like this:</span></font><p
class="MsoNormal"><fontface="Courier New" size="2"><span lang="EN-GB" style="font-size:10.0pt;font-family:"Courier
New""> </span></font><pclass="MsoNormal"><font face="Courier New" size="2"><span lang="EN-GB"
style="font-size:10.0pt;font-family:"CourierNew"">     username     |            domain         |           
sendto           </span></font><p class="MsoNormal"><font face="Courier New" size="2"><span lang="EN-GB"
style="font-size:10.0pt;font-family:"Courier
New"">+-------------+-------------------------------+------------------------------</span></font><p
class="MsoNormal"><fontface="Courier New" size="2"><span lang="EN-GB" style="font-size:10.0pt;font-family:"Courier
New""> Postmaster      | intthit08.uk.rabbit.com   | root</span></font><p class="MsoNormal"><font face="Courier New"
size="2"><spanlang="EN-GB" style="font-size:10.0pt;font-family:"Courier New""> root             |
intthit08.uk.rabbit.com  | is-unix@rabbit.com</span></font><p class="MsoNormal"><font face="Courier New" size="2"><span
lang="EN-GB"style="font-size:10.0pt;font-family:"Courier New""> stoat.griffin    | trusting.co.uk            |
stoat.griffin@rabbit.com</span></font><pclass="MsoNormal"><font face="Courier New" size="2"><span lang="EN-GB"
style="font-size:10.0pt;font-family:"CourierNew""> stoat.griffin    | trusting.com              |
stoat.griffin@rabbit.com</span></font><pclass="MsoNormal"><font face="Courier New" size="2"><span lang="EN-GB"
style="font-size:10.0pt;font-family:"CourierNew""> stoat.griffin    | rusty.co.uk               |
stoat.griffin@rabbit.com</span></font><pclass="MsoNormal"><font face="Courier New" size="2"><span lang="EN-GB"
style="font-size:10.0pt;font-family:"CourierNew""> stoat.griffin    | rusty.com                 |
stoat.griffin@rabbit.com</span></font><pclass="MsoNormal"><font face="Courier New" size="2"><span lang="EN-GB"
style="font-size:10.0pt;font-family:"CourierNew""> matilda.clematis | trusting.com              |
matilda.clematis@rabbit.com</span></font><pclass="MsoNormal"><font face="Courier New" size="2"><span lang="EN-GB"
style="font-size:10.0pt;font-family:"CourierNew""> matilda.clematis | trusting.co.uk            |
matilda.clematis@rabbit.com</span></font><pclass="MsoNormal"><font face="Courier New" size="2"><span lang="EN-GB"
style="font-size:10.0pt;font-family:"CourierNew""> matilda.clematis | rusty.co.uk               |
matilda.clematis@rabbit.com</span></font><pclass="MsoNormal"><font face="Courier New" size="2"><span lang="EN-GB"
style="font-size:10.0pt;font-family:"CourierNew""> matilda.clematis | rusty.com                 |
matilda.clematis@rabbit.com</span></font><pclass="MsoNormal"><font face="Courier New" size="2"><span lang="EN-GB"
style="font-size:10.0pt;font-family:"CourierNew""> *                | trusting.com              |
rusty@rabbit.com</span></font><pclass="MsoNormal"><font face="Courier New" size="2"><span lang="EN-GB"
style="font-size:10.0pt;font-family:"CourierNew""> *                | trusting.co.uk            |
rusty@rabbit.com</span></font><pclass="MsoNormal"><font face="Courier New" size="2"><span lang="EN-GB"
style="font-size:10.0pt;font-family:"CourierNew""> *                | rusty.co.uk               |
rusty@rabbit.com</span></font><pclass="MsoNormal"><font face="Courier New" size="2"><span lang="EN-GB"
style="font-size:10.0pt;font-family:"CourierNew""> *                | rusty.com                 |
rusty@rabbit.com</span></font><pclass="MsoNormal"><font face="Courier New" size="2"><span lang="EN-GB"
style="font-size:10.0pt;font-family:"CourierNew""> *                | windoze.com               |
windoze@badger.com</span></font><pclass="MsoNormal"><font face="Courier New" size="2"><span lang="EN-GB"
style="font-size:10.0pt;font-family:"CourierNew""> *                | windoze.co.uk             |
windoze@badger.com</span></font><pclass="MsoNormal"><font face="Courier New" size="2"><span lang="EN-GB"
style="font-size:10.0pt;font-family:"CourierNew""> admin            | windoze.co.uk             |
matilda.clematis@rabbit.com</span></font><pclass="MsoNormal"><font face="Courier New" size="2"><span lang="EN-GB"
style="font-size:10.0pt;font-family:"CourierNew""> admin            | windoze.com               |
matilda.clematis@rabbit.com</span></font><pclass="MsoNormal"><font face="Courier New" size="2"><span lang="EN-GB"
style="font-size:10.0pt;font-family:"CourierNew""> *                | saxon.co.uk               |
superR@uk.diamond.com</span></font><pclass="MsoNormal"><font face="Courier New" size="2"><span lang="EN-GB"
style="font-size:10.0pt;font-family:"CourierNew""> *                | saxon.com                 |
superR@uk.diamond.com</span></font><pclass="MsoNormal"><font face="Courier New" size="2"><span lang="EN-GB"
style="font-size:10.0pt;font-family:"CourierNew""> </span></font><p class="MsoNormal"><font face="Courier New"
size="2"><spanlang="EN-GB" style="font-size:10.0pt;font-family:"Courier New""> </span></font><p class="MsoNormal"><font
face="CourierNew" size="2"><span lang="EN-GB" style="font-size:10.0pt;font-family:"Courier New"">The query will have
theusername and domain passed in as variables.</span></font><p class="MsoNormal"><font face="Courier New"
size="2"><spanlang="EN-GB" style="font-size:10.0pt;font-family:"Courier New""> </span></font><p class="MsoNormal"><font
face="CourierNew" size="2"><span lang="EN-GB" style="font-size:10.0pt;font-family:"Courier New"">If the username and
domainexist then return the sendto</span></font><p class="MsoNormal"><font face="Courier New" size="2"><span
lang="EN-GB"style="font-size:10.0pt;font-family:"Courier New""> </span></font><p class="MsoNormal"><font face="Courier
New"size="2"><span lang="EN-GB" style="font-size:10.0pt;font-family:"Courier New"">The bit I’m struggling with is if
theusername doesn’t exist then return the sendto where the domain exists</span></font><p class="MsoNormal"><font
face="CourierNew" size="2"><span lang="EN-GB" style="font-size:10.0pt;font-family:"Courier New""> </span></font><p
class="MsoNormal"><fontface="Courier New" size="2"><span lang="EN-GB" style="font-size:10.0pt;font-family:"Courier
New"">e.g. username=fred (this doesn’t exist) and domain=rusty.com then return <a
href="mailto:rusty@rabbit.com">rusty@rabbit.com</a>,<a
href="mailto:matilda.clematis@rabbit.com">matilda.clematis@rabbit.com</a>,<a
href="mailto:stoat.griffin@rabbit.com">stoat.griffin@rabbit.com</a></span></font><pclass="MsoNormal"><font
face="CourierNew" size="2"><span lang="EN-GB" style="font-size:10.0pt;font-family:"Courier New""> </span></font><p
class="MsoNormal"><fontface="Courier New" size="2"><span lang="EN-GB" style="font-size:10.0pt;font-family:"Courier
New"">Anyhelp on this would very much appreciated; it’s been driving me mad for the last day.</span></font><p
class="MsoNormal"><fontface="Courier New" size="2"><span lang="EN-GB" style="font-size:10.0pt;font-family:"Courier
New""> </span></font><pclass="MsoNormal"><font face="Courier New" size="2"><span lang="EN-GB"
style="font-size:10.0pt;font-family:"CourierNew"">Thanks</span></font><p class="MsoNormal"><font face="Courier New"
size="2"><spanlang="EN-GB" style="font-size:10.0pt;font-family:"Courier New""> </span></font><p class="MsoNormal"><font
face="CourierNew" size="2"><span lang="EN-GB" style="font-size:10.0pt;font-family:"Courier New""> </span></font><p
class="MsoNormal"><fontface="Courier New" size="2"><span lang="EN-GB" style="font-size:10.0pt;font-family:"Courier
New"">Nigel</span></font><spanlang="EN-GB"></span></div><br /><br />Communications on or through ioko's computer
systemsmay be monitored or recorded to secure effective system operation and for other lawful purposes.<br /><br
/>Unlessotherwise agreed expressly in writing, this communication is to be treated as confidential and the information
init may not be used or disclosed except for the purpose for which it has been sent. If you have reason to believe that
youare not the intended recipient of this communication, please contact the sender immediately. No employee is
authorisedto conclude any binding agreement on behalf of ioko with another party by e-mail without prior express
writtenconfirmation.<br /><br />ioko365 Ltd. VAT reg 656 2443 31. Reg no 3048367. All rights reserved. 

Re: Help writing a piece of SQL

From
Richard Huxton
Date:
Nigel Bishop wrote:
> 
>      username     |            domain         |            sendto
> +-------------+-------------------------------+-------------------------
> -----
> 
>  Postmaster       | intthit08.uk.rabbit.com   | root
>  root             | intthit08.uk.rabbit.com   | is-unix@rabbit.com
>  stoat.griffin    | trusting.co.uk            | stoat.griffin@rabbit.com
>  stoat.griffin    | trusting.com              | stoat.griffin@rabbit.com
>  stoat.griffin    | rusty.co.uk               | stoat.griffin@rabbit.com
>  stoat.griffin    | rusty.com                 | stoat.griffin@rabbit.com

>  *                | trusting.com              | rusty@rabbit.com
>  *                | trusting.co.uk            | rusty@rabbit.com
>  *                | rusty.co.uk               | rusty@rabbit.com
>  *                | rusty.com                 | rusty@rabbit.com

> The query will have the username and domain passed in as variables.
> If the username and domain exist then return the sendto
> The bit I'm struggling with is if the username doesn't exist then return
> the sendto where the domain exists
> 
> e.g.  username=fred (this doesn't exist) and domain=rusty.com then
> return rusty@rabbit.com, matilda.clematis@rabbit.com,
> stoat.griffin@rabbit.com

So: if the username doesn't exist then you return ALL rows with a 
matching domain? Not just username="*"?

I'm guessing I've mis-understood and you just want username="*", which 
would be something like this:

SELECT sendto, 1 AS priority FROM tbl WHERE username=$1 AND domain=$2
UNION ALL
SELECT sendto, 2 AS priority FROM tbl WHERE username='*' AND domain=$2
ORDER BY priority
LIMIT 1;

Does that help at all?
--   Richard Huxton  Archonet Ltd


Re: Help writing a piece of SQL

From
"Nigel Bishop"
Date:
Thanks for that Richard, it's almost what I'm after:

So where the un and dm exist then return 1 row

Where the un doestn't exist and dm does then return all sendtos' where
the dm exists not just where the un='*'

I hope that makes sense.

Thanks for you help


Nigel Bishop
ioko
T:  +44 (0)1904 435 458
M:  +44 (0)7881 624 386
F:  +44 (0)1904 435 450
E:  nigel.bishop@ioko.com
W:  www.ioko.com
-----Original Message-----
From: Richard Huxton [mailto:dev@archonet.com]
Sent: 03 February 2006 11:02
To: Nigel Bishop
Cc: pgsql-sql@postgresql.org
Subject: Re: [SQL] Help writing a piece of SQL

Nigel Bishop wrote:
>
>      username     |            domain         |            sendto
>
+-------------+-------------------------------+-------------------------
> -----
>
>  Postmaster       | intthit08.uk.rabbit.com   | root
>  root             | intthit08.uk.rabbit.com   | is-unix@rabbit.com
>  stoat.griffin    | trusting.co.uk            |
stoat.griffin@rabbit.com
>  stoat.griffin    | trusting.com              |
stoat.griffin@rabbit.com
>  stoat.griffin    | rusty.co.uk               |
stoat.griffin@rabbit.com
>  stoat.griffin    | rusty.com                 |
stoat.griffin@rabbit.com

>  *                | trusting.com              | rusty@rabbit.com
>  *                | trusting.co.uk            | rusty@rabbit.com
>  *                | rusty.co.uk               | rusty@rabbit.com
>  *                | rusty.com                 | rusty@rabbit.com

> The query will have the username and domain passed in as variables.
> If the username and domain exist then return the sendto
> The bit I'm struggling with is if the username doesn't exist then
return
> the sendto where the domain exists
>
> e.g.  username=fred (this doesn't exist) and domain=rusty.com then
> return rusty@rabbit.com, matilda.clematis@rabbit.com,
> stoat.griffin@rabbit.com

So: if the username doesn't exist then you return ALL rows with a
matching domain? Not just username="*"?

I'm guessing I've mis-understood and you just want username="*", which
would be something like this:

SELECT sendto, 1 AS priority FROM tbl WHERE username=$1 AND domain=$2
UNION ALL
SELECT sendto, 2 AS priority FROM tbl WHERE username='*' AND domain=$2
ORDER BY priority
LIMIT 1;

Does that help at all?
--   Richard Huxton  Archonet Ltd


Communications on or through ioko's computer systems may be monitored or recorded to secure effective system operation
andfor other lawful purposes. 

Unless otherwise agreed expressly in writing, this communication is to be treated as confidential and the information
init may not be used or disclosed except for the purpose for which it has been sent. If you have reason to believe that
youare not the intended recipient of this communication, please contact the sender immediately. No employee is
authorisedto conclude any binding agreement on behalf of ioko with another party by e-mail without prior express
writtenconfirmation. 

ioko365 Ltd.  VAT reg 656 2443 31. Reg no 3048367. All rights reserved.


Re: Help writing a piece of SQL

From
Niklas Johansson
Date:
On 3 feb 2006, at 11.43, Nigel Bishop wrote:
> The query will have the username and domain passed in as variables.
> If the username and domain exist then return the sendto
> The bit I’m struggling with is if the username doesn’t exist then
> return the sendto where the domain exists
>
> e.g.  username=fred (this doesn’t exist) and domain=rusty.com then
> returnrusty@rabbit.com, matilda.clematis@rabbit.com,
> stoat.griffin@rabbit.com

I think this could do the trick for you:

SELECT sendto FROM users t1
WHERE domain='rusty.com' AND (username='fred') = EXISTS(SELECT 1 FROM
users t2 WHERE username='fred' and domain=t1.domain);



Sincerely,

Niklas Johansson





Re: Help writing a piece of SQL

From
"Nigel Bishop"
Date:
Niklas,

Thank you very much, that did the business

Cheers

Nigel Bishop

-----Original Message-----
From: Niklas Johansson [mailto:spot@tele2.se]
Sent: 03 February 2006 13:00
To: Nigel Bishop
Cc: pgsql-sql@postgresql.org
Subject: Re: [SQL] Help writing a piece of SQL


On 3 feb 2006, at 11.43, Nigel Bishop wrote:
> The query will have the username and domain passed in as variables.
> If the username and domain exist then return the sendto
> The bit I'm struggling with is if the username doesn't exist then
> return the sendto where the domain exists
>
> e.g.  username=fred (this doesn't exist) and domain=rusty.com then
> returnrusty@rabbit.com, matilda.clematis@rabbit.com,
> stoat.griffin@rabbit.com

I think this could do the trick for you:

SELECT sendto FROM users t1
WHERE domain='rusty.com' AND (username='fred') = EXISTS(SELECT 1 FROM
users t2 WHERE username='fred' and domain=t1.domain);



Sincerely,

Niklas Johansson





Communications on or through ioko's computer systems may be monitored or recorded to secure effective system operation
andfor other lawful purposes. 

Unless otherwise agreed expressly in writing, this communication is to be treated as confidential and the information
init may not be used or disclosed except for the purpose for which it has been sent. If you have reason to believe that
youare not the intended recipient of this communication, please contact the sender immediately. No employee is
authorisedto conclude any binding agreement on behalf of ioko with another party by e-mail without prior express
writtenconfirmation. 

ioko365 Ltd.  VAT reg 656 2443 31. Reg no 3048367. All rights reserved.


Re: Help writing a piece of SQL

From
Niklas Johansson
Date:
On 3 feb 2006, at 14.06, Nigel Bishop wrote:

> Thank you very much, that did the business


This should generate the same plan as the previous query, but be a  
little bit more clean and easy to read:

SELECT sendto FROM users t1
WHERE domain='rusty.com' AND
username = COALESCE((SELECT username FROM users WHERE username='fred'  
and domain=t1.domain), username);



Sincerely,

Niklas Johansson