Need help in building a SQL query?

  • Hi Experts,

    I have table called "Entries" having general information of Employees as...

    TableName: Entries

    Select * from Entries where mskey = 1234

    MSKEY, ATTRNAME, AVALUE

    1234, NUMBER, 3

    1234, FNAME, DAVID

    1234, MNAME, M

    1234, LNAME, HUDSON

    Select * from Entries where mskey = 2345

    MSKEY, ATTRNAME, AVALUE

    2345, NUMBER, 5

    2345, FNAME, MARK

    2345, LNAME, WOOD

    2345, EMAIL, mwood@email.com

    NOTE: MSKEY is the Primary Key for the table Entries. NUMBER is also primary key.

    I need to write a SQL query and the output should look like...

    NUMBER, FNAME, MNAME, LNAME, EMAIL

    1234, DAVID, M, HUDSON, NULL (Blank)

    2345, MARK, NULL (Blank), WOOD, mwood@email.com

    I did a SQL query as...

    select a.avalue as [NUMBER], b.avalue as [FNAME], c.avalue as [MNAME],

    d.avalue as [LNAME], e.avalue as

    from Entries.a, Entries.b, Entries.c, Entries.d, Entries.e

    where a.mskey = b.mskey and b.mskey = c.mskey and c.mskey = d.mskey and

    d.mskey = e.mskey and a.attrname = 'NUMBER' and b.attrname = 'FNAME' and

    c.attrname = 'MNAME' and d.attrname = 'LNAME' and e.attrname = 'EMAIL' and

    a.mskey in

    (select mskey from Entries where avalue in ('1234','2345'))

    Please help me to write a SQL query using the table "Entries". Thanks in advance.

    Regards,

    Arun

  • Hi and welcome to the forums. It is difficult to provide you a lot of direction because you didn't provide ddl and sample data for the table. Please take a few minutes and read the first article in my signature for best practices when posting questions.

    One thing I can say for sure. You have an EAV "design" pattern. This is one of the most difficult patterns to work with and the performance can horribly wrong very quickly.

    I would recommend that you use ANSI-92 style joins instead of the ANSI-89 style joins. They are easier to read and less prone to accidental cross joins.

    _______________________________________________________________

    Need help? Help us help you.

    Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

    Need to split a string? Try Jeff Modens splitter http://www.sqlservercentral.com/articles/Tally+Table/72993/.

    Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
    Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
    Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
    Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/

  • Below is some DDL and a solution:

    --DDL

    USE tempdb

    IF OBJECT_ID('tempdb..Entries') IS NOT NULL DROP TABLE Entries;

    CREATE TABLE Entries (MSKEY int, ATTRNAME varchar(20), AVALUE varchar(20), primary key (MSKEY, ATTRNAME));

    INSERT Entries (MSKEY, ATTRNAME, AVALUE)

    SELECT 1234, 'NUMBER', '3' UNION ALL

    SELECT 1234, 'FNAME', 'DAVID' UNION ALL

    SELECT 1234, 'MNAME', 'M' UNION ALL

    SELECT 1234, 'LNAME', 'HUDSON' UNION ALL

    SELECT 2345, 'NUMBER', '5' UNION ALL

    SELECT 2345, 'FNAME', 'MARK' UNION ALL

    SELECT 2345, 'LNAME', 'WOOD' UNION ALL

    SELECT 2345, 'EMAIL', 'mwood@email.com';

    --OUTPUT

    SELECT DISTINCT

    e.MSKEY AS NUMBER,

    ISNULL(fn.AVALUE,'') AS FNAME,

    ISNULL(mn.AVALUE,'') AS MNAME,

    ISNULL(ln.AVALUE,'') AS LNAME,

    ISNULL(em.AVALUE,'') AS EMAIL

    FROM Entries e

    LEFT JOIN Entries fn

    ON e.MSKEY=fn.MSKEY AND fn.ATTRNAME='FNAME'

    LEFT JOIN Entries mn

    ON e.MSKEY=mn.MSKEY AND mn.ATTRNAME='MNAME'

    LEFT JOIN Entries ln

    ON e.MSKEY=ln.MSKEY AND ln.ATTRNAME='LNAME'

    LEFT JOIN Entries em

    ON e.MSKEY=em.MSKEY AND em.ATTRNAME='EMAIL'

    The solution I provided is not optimal - it uses a very expensive DISTINCT. I'm going to try to put together a faster query (unless someone beats me to it) . This will, however, get you the results you need.

    "I cant stress enough the importance of switching from a sequential files mindset to set-based thinking. After you make the switch, you can spend your time tuning and optimizing your queries instead of maintaining lengthy, poor-performing code."

    -- Itzik Ben-Gan 2001

  • This could still be optimized but will perform a little better than my previous query:

    --OUTPUT

    SELECT e.MSKEY AS NUMBER,

    ISNULL(fn.AVALUE,'') AS FNAME,

    ISNULL(mn.AVALUE,'') AS MNAME,

    ISNULL(ln.AVALUE,'') AS LNAME,

    ISNULL(em.AVALUE,'') AS EMAIL

    FROM Entries e

    LEFT JOIN Entries fn

    ON e.MSKEY=fn.MSKEY AND fn.ATTRNAME='FNAME'

    LEFT JOIN Entries ln

    ON e.MSKEY=ln.MSKEY AND ln.ATTRNAME='LNAME'

    LEFT JOIN Entries mn

    ON e.MSKEY=mn.MSKEY AND mn.ATTRNAME='MNAME'

    LEFT JOIN Entries em

    ON e.MSKEY=em.MSKEY AND em.ATTRNAME='EMAIL'

    WHERE e.ATTRNAME=fn.ATTRNAME

    "I cant stress enough the importance of switching from a sequential files mindset to set-based thinking. After you make the switch, you can spend your time tuning and optimizing your queries instead of maintaining lengthy, poor-performing code."

    -- Itzik Ben-Gan 2001

  • There is no need for all those joins.

    select e.MSKEY

    , max(case when e.ATTRNAME='FNAME' then e.AVALUE end) AS FNAME

    , max(case when e.ATTRNAME='MNAME' then e.AVALUE end) AS MNAME

    , max(case when e.ATTRNAME='LNAME' then e.AVALUE end) AS LNAME

    , max(case when e.ATTRNAME='EMAIL' then e.AVALUE end) AS EMAIL

    from Entries AS e

    group by e.MSKEY

    MM



    select geometry::STGeomFromWKB(0x0106000000020000000103000000010000000B0000001000000000000840000000000000003DD8CCCCCCCCCC0840000000000000003DD8CCCCCCCCCC08408014AE47E17AFC3F040000000000104000CDCCCCCCCCEC3F9C999999999913408014AE47E17AFC3F9C99999999991340000000000000003D0000000000001440000000000000003D000000000000144000000000000000400400000000001040000000000000F03F100000000000084000000000000000401000000000000840000000000000003D0103000000010000000B000000000000000000143D000000000000003D009E99999999B93F000000000000003D009E99999999B93F8014AE47E17AFC3F400000000000F03F00CDCCCCCCCCEC3FA06666666666FE3F8014AE47E17AFC3FA06666666666FE3F000000000000003D1800000000000040000000000000003D18000000000000400000000000000040400000000000F03F000000000000F03F000000000000143D0000000000000040000000000000143D000000000000003D, 0);

  • Forum Etiquette: How to post Reporting Services problems
  • [/url]
  • Forum Etiquette: How to post data/code on a forum to get the best help - by Jeff Moden
  • [/url]
  • How to Post Performance Problems - by Gail Shaw
  • [/url]

  • Just to backup Maggo's solution... the method he used is called a "CROSSTAB". You could also use a PIVOT although the CROSSTAB solution is usually a touch faster. Such a solution is one of the better ones because it only has to make a pass at the table one time. To wit, it's a common solution for "pivoting" EAV tables of this nature.

    --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)

  • Well done Magoo; I knew there was a much better way but drew a blank.

    Jeff Moden (9/16/2013)


    Just to backup Maggo's solution... the method he used is called a "CROSSTAB". You could also use a PIVOT although the CROSSTAB solution is usually a touch faster. Such a solution is one of the better ones because it only has to make a pass at the table one time. To wit, it's a common solution for "pivoting" EAV tables of this nature.

    I wish I had read Cross Tabs and Pivots, Part 1 – Converting Rows to Columns[/url] before putting my query together.

    "I cant stress enough the importance of switching from a sequential files mindset to set-based thinking. After you make the switch, you can spend your time tuning and optimizing your queries instead of maintaining lengthy, poor-performing code."

    -- Itzik Ben-Gan 2001

  • Alan.B (9/17/2013)


    Well done Magoo; I knew there was a much better way but drew a blank.

    Jeff Moden (9/16/2013)


    Just to backup Maggo's solution... the method he used is called a "CROSSTAB". You could also use a PIVOT although the CROSSTAB solution is usually a touch faster. Such a solution is one of the better ones because it only has to make a pass at the table one time. To wit, it's a common solution for "pivoting" EAV tables of this nature.

    I wish I had read Cross Tabs and Pivots, Part 1 – Converting Rows to Columns[/url] before putting my query together.

    🙂

    --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)

  • Viewing 8 posts - 1 through 7 (of 7 total)

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