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.
Author |
Topic |
balaji
Starting Member
8 Posts |
Posted - 2002-02-25 : 06:40:22
|
i have a table which contains the following fieldsnamely refererid,code,namethis is just like a referral programa guy can refer 3 guys under him i.e,3 is referring three guys namely 4 5 8 similarly 4 is referring 9 10 and 11 likewise 8 is referring 12, 13 it goes like this..i want a query to get the total no of downline members under a guy say 3refererid code201 204203 206204 207 205 208207 209206 210210 214210 213refererid code201 204204 207 207 209very urgent |
|
dsdeming
479 Posts |
Posted - 2002-02-25 : 08:38:34
|
You could try something like this:CREATE PROCEDURE ab @iReferID intASSET NOCOUNT ONDECLARE @iCode intIF NOT EXISTS( SELECT 1 FROM sysobjects WHERE NAME = 'ReferralOutput' ) CREATE TABLE ReferralOutput( ReferID int, Code int )SELECT @iCode = Code FROM AA where ReferID = @iReferIDIF @iCode IS NOT NULLBEGIN INSERT INTO ReferralOutput SELECT @iReferID, @iCode EXECUTE ab @iCodeENDSELECT * FROM ReferralOutputDROP TABLE ReferralOutputGO |
|
|
balaji
Starting Member
8 Posts |
Posted - 2002-02-26 : 04:49:33
|
Dear dsdeming,Thank you very much for your valuable reply.my exact requirement is as follows:i have a about say 10,000 rows in a table i need a query which gives the total no of downline members under a particular guy. for examplemy code is 3 i am referring three guys say 7,8,9 similarly 7 referring three guys say 11,12,13 similarly 8 is referring 14,15 and 9 is referring only one guy now say 14 if i execute the query i should get the total no of downline members under me (ie under 3) as 9 members the query has to search the whole available records and finally it should display the total members under a guy say 3. If possible you can also contact me on Yahoo Chat @ k_bhaskar6@yahoo.com. Expecting your valuable feedback reg thisi followed your instructions but still i am getting the following error:While creating the procedure ab i got :"Cannot add rows to sysdepends for the current stored procedure because it depends on the missing object 'ab'. The stored procedure will still be created."While executing the procedure ab i got:_________________ReferID Code ----------- ----------- 2 55 1717 37Server: Msg 208, Level 16, State 1, Procedure ab, Line 21Invalid object name 'ReferralOutput'.Server: Msg 208, Level 16, State 1, Procedure ab, Line 21Invalid object name 'ReferralOutput'.Server: Msg 208, Level 16, State 1, Procedure ab, Line 21Invalid object name 'ReferralOutput'._________________quote: You could try something like this:CREATE PROCEDURE ab @iReferID intASSET NOCOUNT ONDECLARE @iCode intIF NOT EXISTS( SELECT 1 FROM sysobjects WHERE NAME = 'ReferralOutput' ) CREATE TABLE ReferralOutput( ReferID int, Code int )SELECT @iCode = Code FROM AA where ReferID = @iReferIDIF @iCode IS NOT NULLBEGIN INSERT INTO ReferralOutput SELECT @iReferID, @iCode EXECUTE ab @iCodeENDSELECT * FROM ReferralOutputDROP TABLE ReferralOutputGO
|
|
|
samrat
Yak Posting Veteran
94 Posts |
Posted - 2002-02-26 : 07:21:50
|
Your requirement doesn't sound too bad.. can u put your actual table structure.. i mean a script that would help me to create the table and few records in it..Awaiting your reply Samrat |
|
|
balaji
Starting Member
8 Posts |
Posted - 2002-02-27 : 00:49:52
|
Dear Samrat,Thank you verymuch for your reply.I AM USING MICROSOFT SQL SERVER 7.0my table structure is given below:CREATE TABLE [usr] ( [referer_id] [int] NOT NULL , [code] [int] IDENTITY (1, 1) NOT NULL , [name] [varchar] (50) NOT NULL ,) ON [PRIMARY]GOinsert into usr values(2,'abc1')insert into usr values(2,'abc2')insert into usr values(2,'abc3')insert into usr values(3,'abc4')insert into usr values(3,'abc5')insert into usr values(3,'abc6')insert into usr values(6,'abc7')insert into usr values(4,'abc8')insert into usr values(7,'abc9')insert into usr values(9,'abc10')insert into usr values(9,'abc11')insert into usr values(10,'abc12')insert into usr values(6,'abc13')i need a query to get the total no of downline members referred by a guy.A guy can refer at a max of three under him.Example 1: total no of downline members referred by NO 2 is 13Example 2: total no of downline members referred by NO 6 is 6 (no 6 referred abc7,abc9,abc10,abc11,abc12,abc13)Example 3 : total no of downline members referred by NO 4 is 1 (no 4 referred abc8)Like this it goes... The query or Stored procedure should seach entire records for the downline membersfor a given guy.Awaiting your reply - Regards K BhaskarEdited by - balaji on 02/27/2002 01:10:17Edited by - balaji on 02/27/2002 01:18:52 |
|
|
byrmol
Shed Building SQL Farmer
1591 Posts |
Posted - 2002-02-27 : 01:07:45
|
balji,Try this....create proc upDownLine@Name varchar(50)asSet nocount ondeclare @Code intdeclare @Temp table(Referer_ID int, Code int)Select @Code = Code from Usr where Name = @Namewhile @@Rowcount > 0begin insert @Temp (Referer_ID, Code) Select Referer_id, Code from Usr where code = @Code Select @Code = Code from Usr where referer_id = @CodeendSelect * from @Tempgo HTHDavidMTomorrow is the same day as Today was the day before. |
|
|
balaji
Starting Member
8 Posts |
Posted - 2002-02-27 : 01:23:37
|
Dear DavidM,Thank you for your reply.I TRIED YOUR PROCEDURE BUT I AM GETTING THE FOLLOWING ERROR:I AM USING MICROSOFT SQL SERVER VERSION 7.0*********E R R O R STARTS HERE***********************Server: Msg 156, Level 15, State 1, Procedure upDownLine, Line 6Incorrect syntax near the keyword 'table'.Server: Msg 170, Level 15, State 1, Procedure upDownLine, Line 10Line 10: Incorrect syntax near '@Temp'.Server: Msg 170, Level 15, State 1, Procedure upDownLine, Line 14Line 14: Incorrect syntax near '@Temp'.*********E R R O R ENDS HERE***********************quote: balji,Try this....create proc upDownLine@Name varchar(50)asSet nocount ondeclare @Code intdeclare @Temp table(Referer_ID int, Code int)Select @Code = Code from Usr where Name = @Namewhile @@Rowcount > 0begin insert @Temp (Referer_ID, Code) Select Referer_id, Code from Usr where code = @Code Select @Code = Code from Usr where referer_id = @CodeendSelect * from @Tempgo HTHDavidMTomorrow is the same day as Today was the day before.
|
|
|
byrmol
Shed Building SQL Farmer
1591 Posts |
Posted - 2002-02-27 : 01:40:19
|
Sorry Balaji....Version 7.. you will need a temp table.DavidMTomorrow is the same day as Today was the day before. |
|
|
balaji
Starting Member
8 Posts |
Posted - 2002-02-27 : 02:53:45
|
Dear Davidm,Thank you very much for your immediate response.Can you please guide me how to proceed further?Regards,Balajiquote: Sorry Balaji....Version 7.. you will need a temp table.DavidMTomorrow is the same day as Today was the day before.
|
|
|
Nazim
A custom title
1408 Posts |
Posted - 2002-02-27 : 03:57:31
|
create proc upDownLine@Name varchar(50)asSet nocount ondeclare @Code intcreate table #Temp(Referer_ID int, Code int)Select @Code = Code from Usr where Name = @Namewhile @@Rowcount > 0begin insert #Temp (Referer_ID, Code) Select Referer_id, Code from Usr where code = @Code Select @Code = Code from Usr where referer_id = @CodeendSelect * FROM ReferralOutputDROP TABLE ReferralOutputGO-------------------------------------------------------------- |
|
|
balaji
Starting Member
8 Posts |
Posted - 2002-02-27 : 05:45:32
|
dear nazim,thank you for your suggestion.I executed as suggested by U but i am getting the following error:Server: Msg 208, Level 16, State 1, Procedure bc, Line 15Invalid object name 'ReferralOutput'.Please replyRgds - balajiMSB |
|
|
AndrewMurphy
Master Smack Fu Yak Hacker
2916 Posts |
Posted - 2002-02-27 : 07:00:00
|
I think if you subsitiute "#temp" for "ReferralOutput" things should work..... |
|
|
balaji
Starting Member
8 Posts |
Posted - 2002-02-27 : 07:10:59
|
Dear Andrew,i subsitiuted "#temp" for "ReferralOutput" it is working but i am not getting any output (o rows)Rgds - balajiMSB |
|
|
Nazim
A custom title
1408 Posts |
Posted - 2002-02-27 : 07:25:39
|
This is the code given by David, i have replaced the Table variable with temp table.Try this create proc upDownLine@Name varchar(50)asSet nocount ondeclare @Code intcreate table #Temp(Referer_ID int, Code int)Select @Code = Code from Usr where Name = @Namewhile @@Rowcount > 0begin insert #Temp (Referer_ID, Code) Select Referer_id, Code from Usr where code = @Code Select @Code = Code from Usr where referer_id = @CodeendSelect * from #Tempdrop table #tempgo-------------------------------------------------------------- |
|
|
balaji
Starting Member
8 Posts |
Posted - 2002-02-27 : 07:40:00
|
Dear Nazim,Thank you for your responseit is working but i am not getting any output (o rows)rgdsmsbMSB |
|
|
Nazim
A custom title
1408 Posts |
Posted - 2002-02-27 : 07:45:10
|
i would suggest you to Follow this link and search fo "Recursion"http://www.sqlteam.com/forums/search.asp .there are couple of good discussion relative to your problem. you should be able to pick some valuable hints to solve yours.HTH-------------------------------------------------------------- |
|
|
jcelko
Esteemed SQL Purist
547 Posts |
Posted - 2002-03-11 : 12:20:02
|
The usual example of a tree structure in SQL books is called an adjacency list model and it looks like this: CREATE TABLE Personnel (emp CHAR(10) NOT NULL PRIMARY KEY, boss CHAR(10) DEFAULT NULL REFERENCES Personnel(emp), salary DECIMAL(6,2) NOT NULL DEFAULT 100.00); Personnel emp boss salary =========================== 'Albert' 'NULL' 1000.00 'Bert' 'Albert' 900.00 'Chuck' 'Albert' 900.00 'Donna' 'Chuck' 800.00 'Eddie' 'Chuck' 700.00 'Fred' 'Chuck' 600.00Another way of representing trees is to show them as nested sets. Since SQL is a set oriented language, this is a better model than the usual adjacency list approach you see in most text books. Let us define a simple Personnel table like this, ignoring the left (lft) and right (rgt) columns for now. This problem is always given with a column for the employee and one for his boss in the textbooks. This table without the lft and rgt columns is called the adjacency list model, after the graph theory technique of the same name; the pairs of nodes are adjacent to each other. CREATE TABLE Personnel (emp CHAR(10) NOT NULL PRIMARY KEY, lft INTEGER NOT NULL UNIQUE CHECK (lft > 0), rgt INTEGER NOT NULL UNIQUE CHECK (rgt > 1), CONSTRAINT order_okay CHECK (lft < rgt) ); Personnel emp lft rgt ====================== 'Albert' 1 12 'Bert' 2 3 'Chuck' 4 11 'Donna' 5 6 'Eddie' 7 8 'Fred' 9 10 The organizational chart would look like this as a directed graph: Albert (1,12) / / Bert (2,3) Chuck (4,11) / | / | / | / | Donna (5,6) Eddie (7,8) Fred (9,10)The first table is denormalized in several ways. We are modeling both the personnel and the organizational chart in one table. But for the sake of saving space, pretend that the names are job titles and that we have another table which describes the personnel that hold those positions.Another problem with the adjacency list model is that the boss and employee columns are the same kind of thing (i.e. names of personnel), and therefore should be shown in only one column in a normalized table. To prove that this is not normalized, assume that "Chuck" changes his name to "Charles"; you have to change his name in both columns and several places. The defining characteristic of a normalized table is that you have one fact, one place, one time. The final problem is that the adjacency list model does not model subordination. Authority flows downhill in a hierarchy, but If I fire Chuck, I disconnect all of his subordinates from Albert. There are situations (i.e. water pipes) where this is true, but that is not the expected situation in this case.To show a tree as nested sets, replace the nodes with ovals, then nest subordinate ovals inside each other. The root will be the largest oval and will contain every other node. The leaf nodes will be the innermost ovals with nothing else inside them and the nesting will show the hierarchical relationship. The rgt and lft columns (I cannot use the reserved words LEFT and RIGHT in SQL) are what shows the nesting. If that mental model does not work, then imagine a little worm crawling anti-clockwise along the tree. Every time he gets to the left or right side of a node, he numbers it. The worm stops when he gets all the way around the tree and back to the top. This is a natural way to model a parts explosion, since a final assembly is made of physically nested assemblies that final break down into separate parts. At this point, the boss column is both redundant and denormalized, so it can be dropped. Also, note that the tree structure can be kept in one table and all the information about a node can be put in a second table and they can be joined on employee number for queries. To convert the graph into a nested sets model think of a little worm crawling along the tree. The worm starts at the top, the root, makes a complete trip around the tree. When he comes to a node, he puts a number in the cell on the side that he is visiting and increments his counter. Each node will get two numbers, one of the right side and one for the left. Computer Science majors will recognize this as a modified preorder tree traversal algorithm. Finally, drop the unneeded Personnel.boss column which used to represent the edges of a graph.This has some predictable results that we can use for building queries. The root is always (left = 1, right = 2 * (SELECT COUNT(*) FROM TreeTable)); leaf nodes always have (left + 1 = right); subtrees are defined by the BETWEEN predicate; etc. Here are two common queries which can be used to build others:1. An employee and all their Supervisors, no matter how deep the tree. SELECT P2.* FROM Personnel AS P1, Personnel AS P2 WHERE P1.lft BETWEEN P2.lft AND P2.rgt AND P1.emp = :myemployee;2. The employee and all subordinates. There is a nice symmetry here. SELECT P1.* FROM Personnel AS P1, Personnel AS P2 WHERE P1.lft BETWEEN P2.lft AND P2.rgt AND P2.emp = :myemployee;3. Add a GROUP BY and aggregate functions to these basic queries and you have hierarchical reports. For example, the total salaries which each employee controls: SELECT P2.emp, SUM(S1.salary) FROM Personnel AS P1, Personnel AS P2, Salaries AS S1 WHERE P1.lft BETWEEN P2.lft AND P2.rgt AND P1.emp = S1.emp GROUP BY P2.emp;4. To find the level of each node, so you can print the tree as an indented listing. DECLARE Out_Tree CURSOR FOR SELECT P1.lft, COUNT(P2.emp) AS indentation, P1.emp FROM Personnel AS P1, Personnel AS P2 WHERE P1.lft BETWEEN P2.lft AND P2.rgt GROUP BY P1.emp ORDER BY P1.lft;5. The nested set model has an implied ordering of siblings which the adjacency list model does not. To insert a new node as the rightmost sibling.BEGINDECLARE right_most_sibling INTEGER;SET right_most_sibling = (SELECT rgt FROM Personnel WHERE emp = :your_boss);UPDATE Personnel SET lft = CASE WHEN lft > right_most_sibling THEN lft + 2 ELSE lft END, rgt = CASE WHEN rgt >= right_most_sibling THEN rgt + 2 ELSE rgt END WHERE rgt >= right_most_sibling;INSERT INTO Personnel (emp, lft, rgt)VALUES ('New Guy', right_most_sibling, (right_most_sibling + 1))END;6. To convert a nested sets model into an adjacency list model:SELECT B.emp AS boss, P.emp FROM Personnel AS P LEFT OUTER JOIN Personnel AS B ON B.lft = (SELECT MAX(lft) FROM Personnel AS S WHERE P.lft > S.lft AND P.lft < S.rgt);For details, see the chapter in my book JOE CELKO'S SQL FOR SMARTIES (Morgan-Kaufmann, 1999, second edition) http://searchdatabase.techtarget.com/tip/1,289483,sid13_gci537290,00.htmlhttp://searchdatabase.techtarget.com/tip/1,289483,sid13_gci801943,00.html--CELKO--Joe Celko, SQL Guru |
|
|
|
|
|
|
|