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
 Inventory by LocationId

Author  Topic 

elriba
Starting Member

2 Posts

Posted - 2014-01-21 : 08:53:23
Hi,

I have a problem with an inventory system I'm designing. It is an inventory system by LocationId. The problem I have is that the locations are hierarchical. By hierarchical I mean that a given location might belong to a next location.

For example given the following (simplified) schema of 3 tables (Locations, Articles and Inventory)

CREATE TABLE Locations (
LocationId INTEGER NOT NULL,
ParentLocationId INTEGER NULL,
CONSTRAINT w_Ub_LLAVE PRIMARY KEY (LocationId)
)
GO

INSERT INTO Locations (LocationId,ParentLocationId) VALUES (1,NULL);
INSERT INTO Locations (LocationId,ParentLocationId) VALUES (2,NULL);
INSERT INTO Locations (LocationId,ParentLocationId) VALUES (3,NULL);
INSERT INTO Locations (LocationId,ParentLocationId) VALUES (4,1);
INSERT INTO Locations (LocationId,ParentLocationId) VALUES (5,4);
INSERT INTO Locations (LocationId,ParentLocationId) VALUES (6,4);
INSERT INTO Locations (LocationId,ParentLocationId) VALUES (7,5);


CREATE TABLE Articles (
ItemId INTEGER NOT NULL,
Description VARCHAR(50),
CONSTRAINT ArticlePK PRIMARY KEY (ItemId)
)
GO

INSERT INTO Articles (ItemId,Description) VALUES (100,'BREAD');


CREATE TABLE Inventory (
LocationId INTEGER NOT NULL,
ItemId INTEGER NOT NULL,
Qty DECIMAL(14,4) NULL,
CONSTRAINT InventoryPK PRIMARY KEY (LocationId,ItemId)
)
GO

INSERT INTO Inventory (LocationId,ItemId,Qty) VALUES (1,100,5);
INSERT INTO Inventory (LocationId,ItemId,Qty) VALUES (2,100,5);
INSERT INTO Inventory (LocationId,ItemId,Qty) VALUES (3,100,5);
INSERT INTO Inventory (LocationId,ItemId,Qty) VALUES (4,100,5);
INSERT INTO Inventory (LocationId,ItemId,Qty) VALUES (5,100,5);
INSERT INTO Inventory (LocationId,ItemId,Qty) VALUES (6,100,5);
INSERT INTO Inventory (LocationId,ItemId,Qty) VALUES (7,100,5);



I would like to list the contents by locationId.

For example, if I list LocationId=1 I should get
5 (in LocationId = 1) +
5 (in LocationId = 4 which belongs to 1) +
5 (in LocationId=5 which belongs to 4 which belongs to 1) +
5 (in LocationId=6 which belongs to 4 which belongs to 1) +
5 (in LocationId=7 which belongs to 5 which belongs to 4 which belongs to 1)
= 25

If I list LocationId=7 I would only get 5 (those in locationId=7)

If I list LocationId=5 I would bet 10 (those in LocationId=5 and those in LocationId=7).


Hopefully I was able to explain myself. Does anybody know how this could be done?

Thanks,
Edgard

visakh16
Very Important crosS Applying yaK Herder

52326 Posts

Posted - 2014-01-21 : 09:36:03
[code]
DECLARE @LOcationID int
SET @LocationID = 1

;With location_CTE
AS
(
SELECT LocationId,ParentLocationId
FROM Locations
WHERE LocationId = @LOcationID
UNION ALL
SELECT l.LocationId,l.ParentLocationId
FROM LOcation_CTE c
JOIN Locations l
ON l.ParentLocationId = c.LocationId
)
SELECT SUM(Qty) AS Total
FROM location_CTE c
INNER JOIN Inventory i
ON i.LocationId = c.LocationId
OPTION (NMAXRECURSION 0)
[/code]

------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/
https://www.facebook.com/VmBlogs
Go to Top of Page

elriba
Starting Member

2 Posts

Posted - 2014-01-21 : 09:54:13
Thanks!
This works.
best regards,
Edgard
Go to Top of Page

visakh16
Very Important crosS Applying yaK Herder

52326 Posts

Posted - 2014-01-22 : 08:43:15
welcome

------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/
https://www.facebook.com/VmBlogs
Go to Top of Page
   

- Advertisement -