Multiple values in some columns single value in another

  • Hi,

    I'm a first time poster long time reader of SSC (so perhaps I should already know this!). But...

    I'm having trouble isolating some rows in a table. Its an audit table that can have the same values repeated in some fields. See the table below. I'm only interested in selecting the row where EMG ID is 1267202 as it has a Backscan value of 1 AND 0 instead of only 1 or only 0. (The real life audit table has many more rows but these are the key ones I need for my query)

    Any idea how I can isolate these two rows only?

    DECLARE @t TABLE (EMGID Varchar(7), Reference Varchar(8), Backscan Int)

    INSERT INTO @t

    SELECT '1267202', '32655185', 1

    UNION ALL SELECT '1267202', '32655185', 0

    UNION ALL SELECT '1239667', '33264522', 1

    UNION ALL SELECT '1239667', '33264522', 1

    UNION ALL SELECT '1234000', '33674689', 0

    UNION ALL SELECT '1234000', '33674689', 0

    UNION ALL SELECT '1235670', '33674689', 1

    UNION ALL SELECT '1237830', '33674689', 0

    select * from @t

    I should also state that I'm not interested in EMGID rows '1235670' or '1237830' as these are single entries.

    Many thanks,

    Eamonn

  • How about this:

    DECLARE @t TABLE (EMGID Varchar(7), Reference Varchar(8), Backscan Int);

    INSERT INTO @t

    SELECT '1267202', '32655185', 1

    UNION ALL SELECT '1267202', '32655185', 0

    UNION ALL SELECT '1239667', '33264522', 1

    UNION ALL SELECT '1239667', '33264522', 1

    UNION ALL SELECT '1234000', '33674689', 0

    UNION ALL SELECT '1234000', '33674689', 0;

    select * from @t t

    where

    exists(select 1 from @t t1 where t1.EMGID = t.EMGID and Backscan = 0) and

    exists(select 1 from @t t1 where t1.EMGID = t.EMGID and Backscan = 1);

  • That looks like it could do the trick, thanks Lynn. I'll use that method for my production tables and see how I get on

  • Yep that definately works. It took you 5 seconds to fix what had me scratching my head for a couple of hours. :ermm:

    Cheers!

  • Glad I could help.

  • CELKO (9/15/2012)


    >> I'm having trouble isolating some rows in a table. Its an audit table that can have the same values repeated in some fields [sic: columns are not fields]. See the table below. I'm only interested in selecting the row where EMG ID is 1267202 as it has a something_backscan value of 1 AND 0 instead of only 1 or only 0. (The real life audit table has many more rows but these are the key ones I need for my query) <<

    It would really help if we has DDL, a key, constraints and proper data element names. This is a form of relational division.

    CREATE TABLE Foobar

    (emg_id VARCHAR(7) NOT NULL

    CHECK (emg_id LIKE '[0-9][0-9][0-9][0-9][0-9][0-9][0-9]'),

    vague_reference VARCHAR(8) NOT NULL

    CHECK (vague_reference

    LIKE '[0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9]'),

    something_backscan SMALLINT DEFAULT 0 NOT NULL

    CHECK (something_backscan IN (0,1));

    INSERT INTO Foobar

    VALUES

    ('1267202', '32655185', 1), ('1267202', '32655185', 0),

    ('1239667', '33264522', 1), ('1239667', '33264522', 1),

    ('1234000', '33674689', 0), ('1234000', '33674689', 0),

    ('1235670', '33674689', 1),

    ('1237830', '33674689', 0);

    SELECT emg_id, vague_reference

    FROM Foobar

    GROUP BY emg_id, vague_reference

    HAVING MIN(something_backscan) = 0

    AND MAX(something_backscan) = 1;

    Mr. Celko,

    It would be nice if you would test your code before you post, especially since you are the worlds formost SQL expert. The following code errors in SQL Server 2008 R2 and I really don't feel like figuring out why. That is going to have to be up to you.

    CREATE TABLE Foobar

    (emg_id VARCHAR(7) NOT NULL

    CHECK (emg_id LIKE '[0-9][0-9][0-9][0-9][0-9][0-9][0-9]'),

    vague_reference VARCHAR(8) NOT NULL

    CHECK (vague_reference

    LIKE '[0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9]'),

    something_backscan SMALLINT DEFAULT 0 NOT NULL

    CHECK (something_backscan IN (0,1));

    Here is the error message:

    Msg 102, Level 15, State 1, Line 8

    Incorrect syntax near ';'.

  • Also, after modifying your code to use the table variable provided by the OP, it only returned one row, not both rows (one with backscan = 0 and one with backscan = 1).

  • eamonn.byrne (9/14/2012)


    Yep that definately works. It took you 5 seconds to fix what had me scratching my head for a couple of hours. :ermm:

    Cheers!

    Before you use it, Joe is right.

    1. What is the key here? Is it just EmgID or is it EmgID and Reference together.

    2. Regardless of what the answer to 1 is, is there anything special you want done for an EmgID with multiple Reference values?

    --Jeff Moden


    RBAR is pronounced "ree-bar" and is a "Modenism" for Row-By-Agonizing-Row.
    First step towards the paradigm shift of writing Set Based code:
    ________Stop thinking about what you want to do to a ROW... think, instead, of what you want to do to a COLUMN.

    Change is inevitable... Change for the better is not.


    Helpful Links:
    How to post code problems
    How to Post Performance Problems
    Create a Tally Function (fnTally)

  • Jeff Moden (9/16/2012)


    eamonn.byrne (9/14/2012)


    Yep that definately works. It took you 5 seconds to fix what had me scratching my head for a couple of hours. :ermm:

    Cheers!

    Before you use it, Joe is right.

    1. What is the key here? Is it just EmgID or is it EmgID and Reference together.

    2. Regardless of what the answer to 1 is, is there anything special you want done for an EmgID with multiple Reference values?

    Thanks for the further replies gus and apologies if I wasn't clear. Yes the key is the combined EMGID and Reference fields. Lynn was on the money though and I was able to work out the rest of what I needed from what she provided.

    Cheers

  • eamonn.byrne (9/17/2012)


    Jeff Moden (9/16/2012)


    eamonn.byrne (9/14/2012)


    Yep that definately works. It took you 5 seconds to fix what had me scratching my head for a couple of hours. :ermm:

    Cheers!

    Before you use it, Joe is right.

    1. What is the key here? Is it just EmgID or is it EmgID and Reference together.

    2. Regardless of what the answer to 1 is, is there anything special you want done for an EmgID with multiple Reference values?

    Thanks for the further replies gus and apologies if I wasn't clear. Yes the key is the combined EMGID and Reference fields. Lynn was on the money though and I was able to work out the rest of what I needed from what she provided.

    Cheers

    Glad I could help. One small thing, I am not a she, I am a he.

  • Oops. Sorry! :blush:

Viewing 11 posts - 1 through 10 (of 10 total)

You must be logged in to reply to this topic. Login to reply