SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


How to transform this result?


How to transform this result?

Author
Message
yingchai
yingchai
SSC-Enthusiastic
SSC-Enthusiastic (103 reputation)SSC-Enthusiastic (103 reputation)SSC-Enthusiastic (103 reputation)SSC-Enthusiastic (103 reputation)SSC-Enthusiastic (103 reputation)SSC-Enthusiastic (103 reputation)SSC-Enthusiastic (103 reputation)SSC-Enthusiastic (103 reputation)

Group: General Forum Members
Points: 103 Visits: 467
Hi SQL Gurus,

I have this default master data table below:


ITEM | CNT | DESCRIPTION
----------------------------------------
HMMEDA | | HYH Med Oil
HMMEDA | G01 | HYH Med Oil No 1 (56ml)
HMMEDA | G02 | HYH Med Oil No 2 (96ml)
HMMEDA | G03 | HYH Med Oil No 3 (136ml)


How can I transform into this view below by adding an item description column to represent the item code?


ITEM | ITEM_DESC | CNT | DESCRIPTION
----------------------------------------
HMMEDA | HYH Med Oil | | HYH Med Oil
HMMEDA | HYH Med Oil | G01 | HYH Med Oil No 1 (56ml)
HMMEDA | HYH Med Oil | G02 | HYH Med Oil No 2 (96ml)
HMMEDA | HYH Med Oil | G03 | HYH Med Oil No 3 (136ml)


p/s: In my real database, I will have many types of item code in the ITEM column.

Below is the DDL and sample data:

DECLARE @ITEM TABLE
(
ITEM CHAR(10) NOT NULL,
CNT CHAR(3) NOT NULL,
DESCRIPTION CHAR(50) NOT NULL
)

INSERT @ITEM
VALUES ('HMMEDA', '', 'HYH Med Oil'),
('HMMEDA', 'G01', 'HYH Med Oil No 1 (56ml)'),
('HMMEDA', 'G02', 'HYH Med Oil No 2 (96ml)'),
('HMMEDA', 'G03', 'HYH Med Oil No 3 (136ml)')



Thanks Smile
Mark Cowne
Mark Cowne
Hall of Fame
Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)

Group: General Forum Members
Points: 3099 Visits: 24076
SELECT a.ITEM,b.DESCRIPTION AS ITEM_DESC,a.CNT,a.DESCRIPTION
FROM @ITEM a
INNER JOIN @ITEM b ON b.CNT='' AND b.ITEM=a.ITEM



____________________________________________________

Deja View - The strange feeling that somewhere, sometime you've optimised this query before

How to get the best help on a forum

http://www.sqlservercentral.com/articles/Best+Practices/61537




dwain.c
dwain.c
SSCertifiable
SSCertifiable (7.3K reputation)SSCertifiable (7.3K reputation)SSCertifiable (7.3K reputation)SSCertifiable (7.3K reputation)SSCertifiable (7.3K reputation)SSCertifiable (7.3K reputation)SSCertifiable (7.3K reputation)SSCertifiable (7.3K reputation)

Group: General Forum Members
Points: 7261 Visits: 6431
Here's another method that uses a correlated subquery:


SELECT ITEM
,ITEM_DESC=(
SELECT DESCRIPTION
FROM @ITEM b
WHERE a.ITEM = b.ITEM AND CNT='')
,CNT
,DESCRIPTION
FROM @ITEM a




The INNER JOIN method is probably faster but it also may depend on indexing and primary key field(s).


My mantra: No loops! No CURSORs! No RBAR! Hoo-uh!

My thought question: Have you ever been told that your query runs too fast?

My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.


Need to UNPIVOT? Why not CROSS APPLY VALUES instead?
Since random numbers are too important to be left to chance, let's generate some!
Learn to understand recursive CTEs by example.
Splitting strings based on patterns can be fast!
My temporal SQL musings: Calendar Tables, an Easter SQL, Time Slots and Self-maintaining, Contiguous Effective Dates in Temporal Tables
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search