Please start any new threads on our new site at https://forums.sqlteam.com. We've got lots of great SQL Server experts to answer whatever question you can come up with.

 All Forums
 General SQL Server Forums
 Database Design and Application Architecture
 Best way to design table that references it's self

Author  Topic 

Eagle_f90
Constraint Violating Yak Guru

424 Posts

Posted - 2012-10-16 : 14:49:34
I am creating a table for my gaming site that will house locations in the game. Some location can be sub-areas (i.e The Regon of Bla in area Na) so in the table I added the colum "Parent Location" but this makes the table reference it's self which seems wrong in it's design to me. Is this the right way to do this or someother way better? Here is my code:

CREATE TABLE dbo.tblLocations
(
LocationID int IDENTITY(0,1) NOT NULL,
LocationName varchar(250) NOT NULL,
SectionID smallint NOT NULL,
LocationType smallint NOT NULL,
ParentLocation int NULL,
MapFileID int NULL,
CONSTRAINT PK_Locations_LocationID PRIMARY KEY CLUSTERED (LocationID ASC),
CONSTRAINT FK_Locations_SectionID FOREIGN KEY (SectionID) REFERENCES dbo.tblSectionInfo (SectionID),
CONSTRAINT FK_Locations_LocationType FOREIGN KEY (LocationType) REFERENCES dbo.tblLocationTypes (LocationTypeID),
CONSTRAINT FK_Locations_ParentLocation FOREIGN KEY (ParentLocation) REFERENCES dbo.tblLocations (LocationID),
CONSTRAINT FK_Locations_MapFileID FOREIGN KEY (MapFileID) REFERENCES dbo.tblFiles (FileID)
)


--
If I get used to envying others...
Those things about my self I pride will slowly fade away.
-Stellvia

sunitabeck
Master Smack Fu Yak Hacker

5155 Posts

Posted - 2012-10-16 : 15:30:38
What you have is not a bad design at all. Your other alternatives are:

a) to have a separate table that lists the Id's for the parents and children. That really adds no benefit in most cases

b) use the hierarchyid data type that is available in SQL 2008 or later. It has some benefits, especially if your tree is deep, or if you need to reconfigure your tree frequently etc. But, if I understood correctly, your tree is only one level deep, so I would not really recommend it.

So go with what you have, and let us see if the experts on the forum have anything to add/suggest.
Go to Top of Page

Eagle_f90
Constraint Violating Yak Guru

424 Posts

Posted - 2012-10-16 : 16:03:56
I would agree with your assessment of a and b. The part I am hooked up on is how (in SQL code) to translate the ParentLocation into the LocationName. As you can see the ParentLocation is an INT that referances LocationID so if I wanted to print the ParentLocation's name I am not sure how to do that.

--
If I get used to envying others...
Those things about my self I pride will slowly fade away.
-Stellvia
Go to Top of Page

sunitabeck
Master Smack Fu Yak Hacker

5155 Posts

Posted - 2012-10-16 : 20:03:37
You can join the table onto itself to find that information. Below are couple of different questions that you may be asked and how to query for those:
-- 1 include the parent name in the query
SELECT
a.*,
b.LocationName AS [ParentLocationName]
FROM
dbo.tblLocations a
LEFT JOIN dbo.tblLocations b ON
a.ParentLocation = b.LocationID


-- 2 List all child locations of a parent location
SELECT
a.*,
b.LocationName AS [ChildLocationName]
FROM
dbo.tblLocations a
LEFT JOIN dbo.tblLocations b ON
a.LocationID = b.ParentLocation
WHERE
a.LocationName = 'SomeParentLocation';

-- 3 Number of child locations each location has
SELECT
a.LocationName,
COUNT(*) AS Childcount
FROM
dbo.tblLocations a
LEFT JOIN dbo.tblLocations b ON
a.LocationID = b.ParentLocation
GROUP BY
a.LocationName;
Go to Top of Page
   

- Advertisement -