April 30, 2010 at 10:06 am
For a given County, I am returning the cities in that County
SELECT DISTINCT CITY FROM DEMO WHERE COUNTY = @COUNTY
CITY
-----
EDINA
BLOOMINGTON
EDEN PRAIRIE
SHAKOPEE
How do I display this data in a row like
CITY1 CITY2 CITY3 CITY4 CITY5 CITY6
--------------------------------------------------------------------------
EDINA BLOOMINGTON EDEN PRAIRIE SHAKOPEE
Thanks for great help
C
April 30, 2010 at 10:32 am
Write a cursor.
Fetch each county into it.
Create a variable and keep concat'ing the new county + a space
When the cursor is done, print the variable that contains the string with the individual rows
/* ----------------------------- */
Tochter aus Elysium, Wir betreten feuertrunken, Himmlische, dein Heiligtum!
April 30, 2010 at 10:53 am
Forget the cursor... try this instead.
-- See how this starts off with a table and data in it?
-- If you had provided us the data in this format,
-- it would have made things easier for all of the
-- volunteers on this site to help you out.
DECLARE @test-2 table (Country varchar(50), City varchar(50))
INSERT INTO @test-2
SELECT 'USA','Washington' UNION ALL
SELECT 'USA', 'Portland' UNION ALL
SELECT 'USA', 'San Antonio' UNION ALL
SELECT 'USA', 'Houston' UNION ALL
SELECT 'USA', 'Tampa' UNION ALL
SELECT 'USA', 'Boston'
;WITH CTE AS
(
SELECT Country,
RowID = ROW_NUMBER() OVER (ORDER BY (SELECT 0)),
City
FROM @test-2
WHERE Country = 'USA'
)
SELECT City1 = MAX(CASE WHEN RowID = 1 THEN CITY ELSE NULL END),
City2 = MAX(CASE WHEN RowID = 2 THEN CITY ELSE NULL END),
City3 = MAX(CASE WHEN RowID = 3 THEN CITY ELSE NULL END),
City4 = MAX(CASE WHEN RowID = 4 THEN CITY ELSE NULL END),
City5 = MAX(CASE WHEN RowID = 5 THEN CITY ELSE NULL END)
FROM CTE
You might want to check out this article by MVP Jeff Moden[/url] on generating dynamic cross-tab data.
Wayne
Microsoft Certified Master: SQL Server 2008
Author - SQL Server T-SQL Recipes
April 30, 2010 at 11:00 am
How the heck will that work with a country like USA or Canada where you have 1000s of cities?
April 30, 2010 at 11:00 am
Cnu2010 (4/30/2010)
For a given County, I am returning the cities in that CountySELECT DISTINCT CITY FROM DEMO WHERE COUNTY = @COUNTY
CITY
-----
EDINA
BLOOMINGTON
EDEN PRAIRIE
SHAKOPEE
How do I display this data in a row like
CITY1 CITY2 CITY3 CITY4 CITY5 CITY6
--------------------------------------------------------------------------
EDINA BLOOMINGTON EDEN PRAIRIE SHAKOPEE
Thanks for great help
C
What's the big picture of the project here? This seems like a reporting need rather than simple DML.
April 30, 2010 at 6:57 pm
GregoryF (4/30/2010)
Write a cursor.Fetch each county into it.
Create a variable and keep concat'ing the new county + a space
When the cursor is done, print the variable that contains the string with the individual rows
Heh... nah... no cursors... too slow. Besides, the OP wants it in separate columns.
--Jeff Moden
Change is inevitable... Change for the better is not.
April 30, 2010 at 6:59 pm
Ninja's_RGR'us (4/30/2010)
How the heck will that work with a country like USA or Canada where you have 1000s of cities?
Heh... one can only hope that the criteria presented is "example only" and would be a little tighter. 😉
--Jeff Moden
Change is inevitable... Change for the better is not.
April 30, 2010 at 7:00 pm
Cnu2010 (4/30/2010)
For a given County, I am returning the cities in that CountySELECT DISTINCT CITY FROM DEMO WHERE COUNTY = @COUNTY
CITY
-----
EDINA
BLOOMINGTON
EDEN PRAIRIE
SHAKOPEE
How do I display this data in a row like
CITY1 CITY2 CITY3 CITY4 CITY5 CITY6
--------------------------------------------------------------------------
EDINA BLOOMINGTON EDEN PRAIRIE SHAKOPEE
Thanks for great help
C
You're almost brand new to the forum... take a look at the article at the first link in my signature line below. People will trip over each other to help you with a coded example...
--Jeff Moden
Change is inevitable... Change for the better is not.
May 2, 2010 at 11:01 pm
DECLARE @test-2
TABLE (
Country VARCHAR(50),
City VARCHAR(50)
);
INSERT @test-2
SELECT 'USA', 'Washington' UNION ALL
SELECT 'USA', 'Portland' UNION ALL
SELECT 'USA', 'San Antonio'UNION ALL
SELECT 'USA', 'Houston' UNION ALL
SELECT 'USA', 'Tampa' UNION ALL
SELECT 'USA', 'Boston' UNION ALL
SELECT 'NZ', 'Wellington' UNION ALL
SELECT 'NZ', 'Auckland' UNION ALL
SELECT 'NZ', 'Christchurch'UNION ALL
SELECT 'NZ', 'Dunedin';
SELECT P.Country,
P.City1,
P.City2,
P.City3,
P.City4,
P.City5,
P.City6,
P.City7,
P.City8,
P.City9
FROM (
SELECT T.Country,
value = T.City,
name = 'City' + CONVERT(VARCHAR(20), ROW_NUMBER() OVER (PARTITION BY T.Country ORDER BY (SELECT 0)))
FROM @test-2 T
) Source
PIVOT (
MAX(value)
FOR name IN (City1, City2, City3, City4, City5, City6, City7, City8, City9)
) P;
Viewing 9 posts - 1 through 8 (of 8 total)
You must be logged in to reply to this topic. Login to reply