On May 1, 10:47 pm, [EMAIL PROTECTED] wrote:
> Hello all,
> I have a table with 2 issues, issue_A and issue_B, a table with action
> items related to the issues,
>
> issue_A AI_A1
> issue_A AI_A2
> issue_A AI_A3
> issue_B AI_B1
> issue_B AI_B2
>
> and network elements that the issues affect:
>
> issue_A NE_A1
> issue_A NE_A2
> issue_B NE_B1
> issue_B NE_B2
> issue_B NE_B3
>
> and I would like a query whose result juxtaposes those 2 tables, as
> follows:
>
> issue_A AI_A1   NE_A1
> issue_A AI_A2   NE_A2
> issue_A AI_A3   NULL
> issue_B AI_B1   NE_B1
> issue_B AI_B2   NE_B2
> issue_B NULL    NE_B3
>
> where the top and bottom NULLs could also be NE_A2, AI_B2
> respectively, I wouldn't mind.
> Any idea how to do that?
> Thanks, Robin

----------------------------------------

t=# select * from ai;
    i    |  ai
---------+-------
 issue_A | AI_A1
 issue_A | AI_A2
 issue_A | AI_A3
 issue_B | AI_B1
 issue_B | AI_B2

t=# select * from ne;
    i    |  ne
---------+-------
 issue_A | NE_A1
 issue_A | NE_A2
 issue_B | NE_B1
 issue_B | NE_B2
 issue_B | NE_B3

t=# SELECT COALESCE(ai.i, ne.i) AS i, ai.ai, ne.ne
t-# FROM ai FULL JOIN ne ON
t-# REPLACE(ai.ai, 'AI', '') = REPLACE(ne.ne, 'NE', '');
    i    |  ai   |  ne
---------+-------+-------
 issue_A | AI_A1 | NE_A1
 issue_A | AI_A2 | NE_A2
 issue_A | AI_A3 |
 issue_B | AI_B1 | NE_B1
 issue_B | AI_B2 | NE_B2
 issue_B |       | NE_B3

----------------------------------------

HINT: You might want to normalize your tables further to avoid
unnecessary string handling.


---------------------------(end of broadcast)---------------------------
TIP 5: don't forget to increase your free space map settings

Reply via email to