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


need help with using data in a certain way


need help with using data in a certain way

Author
Message
slatinsky
slatinsky
SSC Rookie
SSC Rookie (26 reputation)SSC Rookie (26 reputation)SSC Rookie (26 reputation)SSC Rookie (26 reputation)SSC Rookie (26 reputation)SSC Rookie (26 reputation)SSC Rookie (26 reputation)SSC Rookie (26 reputation)

Group: General Forum Members
Points: 26 Visits: 187
Hello, I seem to be having a problem arranging my data in a way that can be utilized by a specific report

To simplify, after all the processing I end up with a table of column pairs (should not be more than a hundred records at most) that will look like so: (SQL Server 2005)


CREATE TABLE Links(
LinkID INT NOT NULL IDENTITY(1,1)
CONSTRAINT PK_Links_linkID PRIMARY KEY (LinkID),
Col1 INT NOT NULL,
Col2 INT NOT NULL
)

INSERT INTO Links (Col1, Col2)
SELECT 1,2
UNION ALL
SELECT 1,3
UNION ALL
SELECT 2,4
UNION ALL
SELECT 5, 3
UNION ALL
SELECT 3,2
UNION ALL
SELECT 7, 8
UNION ALL
SELECT 6,7
UNION ALL
SELECT 4, 1
UNION ALL
SELECT 1, 4



I need to write a select that will rearrange
the values in this table so that all the relationships between the 2 columns are presented
in a way that col1 contains the minimum value of the relationship and all others belong to this minimum value

Like so:

Col1 Col2
1 2
1 3
1 4
1 5
6 7
6 8

I was trying to use the recursive CTEs but did not succeed - I am hopeful there is a decent way of doing this - I would hate to use any kind of "row by row" approach

Thank you
Sean Lange
Sean Lange
One Orange Chip
One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)

Group: General Forum Members
Points: 26069 Visits: 17532
Excellent job posting ddl and sample data. However I don't understand at all how you came up with the desired output.

_______________________________________________________________

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.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
Evil Kraig F
Evil Kraig F
SSCrazy Eights
SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)

Group: General Forum Members
Points: 8597 Visits: 7660
Sean,

It's an orgchart chain with the upper root level removed. You want to find the sublevel's highest association. Highest Association is decided by the lowest ID.

I just wanted to clarify that for the moment. I know of a way to do it but I've got a meeting coming up. I'll be back in a bit with the answer if someone doesn't beat me to it.


- Craig Farrell

Never stop learning, even if it hurts. Ego bruises are practically mandatory as you learn unless you've never risked enough to make a mistake.

For better assistance in answering your questions | Forum Netiquette
For index/tuning help, follow these directions. |Tally Tables

Twitter: @AnyWayDBA
slatinsky
slatinsky
SSC Rookie
SSC Rookie (26 reputation)SSC Rookie (26 reputation)SSC Rookie (26 reputation)SSC Rookie (26 reputation)SSC Rookie (26 reputation)SSC Rookie (26 reputation)SSC Rookie (26 reputation)SSC Rookie (26 reputation)

Group: General Forum Members
Points: 26 Visits: 187
Craig, thank you, that's exactly what it is. I am trying to figure it out with recursion but bo luck so far, I will be very curious to see what you came up with
Luis Cazares
Luis Cazares
SSCoach
SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)

Group: General Forum Members
Points: 16530 Visits: 19091
Something like this?


;WITH Ordered AS(
SELECT DISTINCT
CASE WHEN l.Col1 <= l.Col2 THEN l.Col1 ELSE l.Col2 END AS Col1,
CASE WHEN l.Col1 <= l.Col2 THEN l.Col2 ELSE l.Col1 END AS Col2
FROM Links l
),
rCTE AS(
SELECT Col1 AS Parent,
Col1,
Col2
FROM Ordered l
UNION ALL
SELECT c.Parent,
l.Col1,
l.Col2
FROM Ordered l
JOIN rCTE c ON l.Col1 = c.Col2
),
Row_Values AS(
SELECT Parent Col1,
Col2,
ROW_NUMBER() OVER( PARTITION BY Col2 ORDER BY Parent) rn
FROM rCTE
)
SELECT Col1, Col2
FROM Row_Values
WHERE rn = 1
ORDER BY Col1, Col2



Unless someone finds a more effective way to do it.


Luis C.
General Disclaimer:
Are you seriously taking the advice and code from someone from the internet without testing it? Do you at least understand it? Or can it easily kill your server?


How to post data/code on a forum to get the best help: Option 1 / Option 2
slatinsky
slatinsky
SSC Rookie
SSC Rookie (26 reputation)SSC Rookie (26 reputation)SSC Rookie (26 reputation)SSC Rookie (26 reputation)SSC Rookie (26 reputation)SSC Rookie (26 reputation)SSC Rookie (26 reputation)SSC Rookie (26 reputation)

Group: General Forum Members
Points: 26 Visits: 187
Luis! Thank you for saving me from thinking about this problem for the whole weekend!
slatinsky
slatinsky
SSC Rookie
SSC Rookie (26 reputation)SSC Rookie (26 reputation)SSC Rookie (26 reputation)SSC Rookie (26 reputation)SSC Rookie (26 reputation)SSC Rookie (26 reputation)SSC Rookie (26 reputation)SSC Rookie (26 reputation)

Group: General Forum Members
Points: 26 Visits: 187
I think it's a very elegant solution
Thank you again
Luis Cazares
Luis Cazares
SSCoach
SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)

Group: General Forum Members
Points: 16530 Visits: 19091
I used a similar code at work a few weeks ago and I just adapted to your problem, so if someone has something better it will be benefitial for both of us.
I'm glad you can forget about work for the weekend.


Luis C.
General Disclaimer:
Are you seriously taking the advice and code from someone from the internet without testing it? Do you at least understand it? Or can it easily kill your server?


How to post data/code on a forum to get the best help: Option 1 / Option 2
slatinsky
slatinsky
SSC Rookie
SSC Rookie (26 reputation)SSC Rookie (26 reputation)SSC Rookie (26 reputation)SSC Rookie (26 reputation)SSC Rookie (26 reputation)SSC Rookie (26 reputation)SSC Rookie (26 reputation)SSC Rookie (26 reputation)

Group: General Forum Members
Points: 26 Visits: 187
Definitely much more efficient than what I was trying to put together
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