Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase

How to transform this result? Expand / Collapse
Author
Message
Posted Thursday, September 20, 2012 2:15 AM
SSC Journeyman

SSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC Journeyman

Group: General Forum Members
Last Login: Yesterday @ 7:54 PM
Points: 78, Visits: 418
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 :)
Post #1361783
Posted Thursday, September 20, 2012 2:19 AM


SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Tuesday, April 8, 2014 6:13 AM
Points: 1,694, Visits: 19,550
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



____________________________________________________

How to get the best help on a forum

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

Never approach a goat from the front, a horse from the rear, or a fool from any direction.
Post #1361785
Posted Tuesday, September 25, 2012 9:32 PM


Hall of Fame

Hall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of Fame

Group: General Forum Members
Last Login: Yesterday @ 4:14 AM
Points: 3,618, Visits: 5,254
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!
Post #1364410
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse