SQL Server Forums
Profile | Register | Active Topics | Members | Search | Forum FAQ
 
Register Now and get your question answered!
Username:
Password:
Save Password
Forgot your Password?

 All Forums
 SQL Server 2008 Forums
 Transact-SQL (2008)
 search levels
 New Topic  Reply to Topic
 Printer Friendly
Author Previous Topic Topic Next Topic  

MikeSaunders
Starting Member

11 Posts

Posted - 09/30/2012 :  04:57:28  Show Profile  Reply with Quote
Hello all,

I'm wondering if it is possible to do the following. I have a table with locations in the world.
All locations have the locationtype continent, country, state, city, neigbourhood or street.

Also i have a table that tell contains all parent locations of a location (e.g. the parent location of a state is a country) That table looks like:

LocationID, Locationname, ParentlocationID

The parentlocationID refers to the locationID of the parent Location.

Now I want to make a query that shows me all underlying locations of a given location. E.g. when i search for a location that is a country i get all states, cities, neigbourhoods and streets for that country. But when i search for a city it will show only all neighbourhoods and streets.

Does somebody know how to solve this?

Any suggestions are welcome!!

Thanks!!

Mike

HenryFulmer
Posting Yak Master

USA
110 Posts

Posted - 09/30/2012 :  10:24:17  Show Profile  Reply with Quote
Not sure what you need the parentlocation table for? You already seem to have all parameters in one table, so wouldn't it be just a simple select?


SELECT state, city, neigborhood, street
FROM Locations 
WHERE country ='yourcountry'


Maybe I misunderstand your question.
Go to Top of Page

MikeSaunders
Starting Member

11 Posts

Posted - 09/30/2012 :  10:40:46  Show Profile  Reply with Quote
In addition to my question some examples:

CREATE TABLE [ParentRegionList](
[RegionID] [int] NOT NULL,
[RegionType] [nvarchar](50) NULL,
[RegionName] [nvarchar](255) NULL,
[ParentRegionID] [int] NULL
)

INSERT INTO [ParentRegionList] ([RegionID],[RegionType],[RegionName],[ParentRegionID]) VALUES (1,'Continent','Europe',0)
INSERT INTO [ParentRegionList] ([RegionID],[RegionType],[RegionName],[ParentRegionID]) VALUES (2,'Continent','North America',0)
INSERT INTO [ParentRegionList] ([RegionID],[RegionType],[RegionName],[ParentRegionID]) VALUES (500,'Country','The Netherlands',1)
INSERT INTO [ParentRegionList] ([RegionID],[RegionType],[RegionName],[ParentRegionID]) VALUES (501,'Country','Germany',1)
INSERT INTO [ParentRegionList] ([RegionID],[RegionType],[RegionName],[ParentRegionID]) VALUES (502,'Country','Belgium',1)
INSERT INTO [ParentRegionList] ([RegionID],[RegionType],[RegionName],[ParentRegionID]) VALUES (550,'Country','United States of America',2)
INSERT INTO [ParentRegionList] ([RegionID],[RegionType],[RegionName],[ParentRegionID]) VALUES (800,'State','New York',550)
INSERT INTO [ParentRegionList] ([RegionID],[RegionType],[RegionName],[ParentRegionID]) VALUES (1000,'City','New York',800)
INSERT INTO [ParentRegionList] ([RegionID],[RegionType],[RegionName],[ParentRegionID]) VALUES (1001,'City','Amsterdam',500)
INSERT INTO [ParentRegionList] ([RegionID],[RegionType],[RegionName],[ParentRegionID]) VALUES (1002,'City','Rotterdam',500)
INSERT INTO [ParentRegionList] ([RegionID],[RegionType],[RegionName],[ParentRegionID]) VALUES (1003,'City','Brussels',502)
INSERT INTO [ParentRegionList] ([RegionID],[RegionType],[RegionName],[ParentRegionID]) VALUES (5000,'Neighborhood','Amsterdam Center',1001)
INSERT INTO [ParentRegionList] ([RegionID],[RegionType],[RegionName],[ParentRegionID]) VALUES (5001,'Neighborhood','The Pijp',1001)
INSERT INTO [ParentRegionList] ([RegionID],[RegionType],[RegionName],[ParentRegionID]) VALUES (10001,'Street','Damrak',5000)
INSERT INTO [ParentRegionList] ([RegionID],[RegionType],[RegionName],[ParentRegionID]) VALUES (10002,'Street','Rue de Brussels',1003)


In this example the search variable 1 (Europe) has to show all records that are (in)direct (top down) connected to RegionID 1 so:
500 The Netherlands
501 Germany
502 Belgium
1001 Amsterdam
1002 Rotterdam
1003 Brussels
5000 Amsterdam Center
5001 The Pijp
10001 Damrak
10002 Rue de Brussels

In this example the search variable 800 (state new york) has to show all records that are (in)direct (top down) connected to RegionID 800 so:
1000 New York

In this example the search variable 1001 (Amsterdam) has to show all records that are (in)direct (top down) connected to RegionID 1001 so:
5000 Amsterdam Center
5001 The Pijp
10001 Damrak
Go to Top of Page

sunitabeck
Flowing Fount of Yak Knowledge

5155 Posts

Posted - 09/30/2012 :  19:03:36  Show Profile  Reply with Quote
You can use a recursive CTE like shown below:
DECLARE @searchId INT = 1;
;WITH cte AS
(
	SELECT * FROM ParentRegionList WHERE RegionID = @searchId
	UNION ALL
	SELECT p.* FROM ParentRegionList p
	INNER JOIN cte c ON c.RegionId = p.ParentRegionID
)
SELECT * FROM cte
-- where regionId <> @searchId -- if you want to exclude the search region id.
Go to Top of Page

MikeSaunders
Starting Member

11 Posts

Posted - 10/01/2012 :  04:06:33  Show Profile  Reply with Quote
Thanks, This works!!!

quote:
Originally posted by sunitabeck

You can use a recursive CTE like shown below:
DECLARE @searchId INT = 1;
;WITH cte AS
(
	SELECT * FROM ParentRegionList WHERE RegionID = @searchId
	UNION ALL
	SELECT p.* FROM ParentRegionList p
	INNER JOIN cte c ON c.RegionId = p.ParentRegionID
)
SELECT * FROM cte
-- where regionId <> @searchId -- if you want to exclude the search region id.


Go to Top of Page
  Previous Topic Topic Next Topic  
 New Topic  Reply to Topic
 Printer Friendly
Jump To:
SQL Server Forums © 2000-2009 SQLTeam Publishing, LLC Go To Top Of Page
This page was generated in 0.06 seconds. Powered By: Snitz Forums 2000