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
 SQL Server 2008 Forums
 Transact-SQL (2008)
 Insert, Select from same request?

Author  Topic 

Jack3r
Starting Member

4 Posts

Posted - 2012-12-12 : 16:27:48
Hi,

I am trying to write a stored procedure to populate a table with a column (integer) the number follow a sequence, for example, from 450000 to 450999. In the column I already have some records, but with spaces between them (eg 450002,450008,450012 ...) I want my new record fill these gaps. I tried to make a list of possible values, and use it when inserting, I do a join to be sure not to reuse a number already in the table. On paper it looks ok, but in fact it does not work. I guess I am not the first who want to do that ... I'm a little stuck now.

There an example of what I'm trying.
---------------------------------------------------------------------
DECLARE @NewDN integer = 0
DECLARE @tOutput TABLE (OutputId Integer IDENTITY(1,1) PRIMARY KEY, DN nvarchar(7), NAME nvarchar(20))
DECLARE @tListNo TABLE (DN nvarchar(7) PRIMARY KEY)
DECLARE @tUsers TABLE (UserId Integer IDENTITY(1,1) PRIMARY KEY, [UserName] nvarchar(20))

-- Fill a table with a list of possible number
WHILE (@NewDN < 1000)
BEGIN
SELECT @NewDN = @NewDN + 1
INSERT INTO @tListNo (DN) VALUES ('450' + RIGHT('00000' + CONVERT(VARCHAR,@NewDN),3))
END

-- Put some dummy records for the demonstration
INSERT INTO @tOutput (DN,NAME) VALUES ('450002','Pierre')
INSERT INTO @tOutput (DN,NAME) VALUES ('450004','Jean')
INSERT INTO @tOutput (DN,NAME) VALUES ('450006','Jacques')
INSERT INTO @tOutput (DN,NAME) VALUES ('450008','Fred')

-- Put some dummy records here too
INSERT INTO @tUsers ([UserName]) VALUES ('Annie')
INSERT INTO @tUsers ([UserName]) VALUES ('Lise')
INSERT INTO @tUsers ([UserName]) VALUES ('Sophie')
INSERT INTO @tUsers ([UserName]) VALUES ('Francoise')

-- Get a the first Free number (For Debug - We Get 450000)
SELECT TOP 1 t1.DN FROM @tListNo t1 LEFT JOIN @tOutput t2 ON t1.DN=t2.DN WHERE t2.DN IS NULL; -- Debug

-- Insert the new entries
INSERT INTO @tOutput (DN, NAME)
SELECT (SELECT TOP 1 t1.DN FROM @tListNo t1 LEFT JOIN @tOutput t2 ON t1.DN=t2.DN WHERE t2.DN IS NULL ) as DN,[UserName]
FROM @tUsers

-- Now we should get 450009 as the new free number, baut get 450001
SELECT TOP 1 t1.DN FROM @tListNo t1 LEFT JOIN @tOutput t2 ON t1.DN=t2.DN WHERE t2.DN IS NULL; -- Debug

SELECT * FROM @tListNo
SELECT * FROM @tOutput
-- All new entries got 450000 as number

All help appreciated,
Jacques

khtan
In (Som, Ni, Yak)

17689 Posts

Posted - 2012-12-12 : 22:36:21
you get 45000 for all the new entries because the sub-query will return the 45000 and it is used to insert into the @tOutput table

-- Insert the new entries
INSERT INTO @tOutput (DN, NAME)
SELECT (SELECT TOP 1 t1.DN FROM @tListNo t1 LEFT JOIN @tOutput t2 ON t1.DN=t2.DN WHERE t2.DN IS NULL ) as DN,
[UserName]
FROM @tUsers


you can use row_number() to generate a continuous running no.

SELECT (SELECT TOP 1 t1.DN FROM @tListNo t1 LEFT JOIN @tOutput t2 ON t1.DN=t2.DN WHERE t2.DN IS NULL )
+ row_number() over ( order by [UserName] ) - 1
as DN


That will give you 45000, 45001, 45002 etc. However that may not give you the ultimate result that you wanted as i don't really understand what you are wanted to achieve here. Perhaps you can also post the expected result then we can suggest a better solution


KH
[spoiler]Time is always against us[/spoiler]

Go to Top of Page

Jack3r
Starting Member

4 Posts

Posted - 2012-12-13 : 08:21:19
Thanks for your reply khtan,

I get for the first select 450000, it is what I expect, but as I write in the same table I read, the second select should return 450001, and the third, 450003, an so on 450005,450007,4500009, because of the NULL clause and the even numbers are already use. Row number will not work.

Jacques
Go to Top of Page

khtan
In (Som, Ni, Yak)

17689 Posts

Posted - 2012-12-13 : 20:09:15
[code]; with
DNFree as
(
SELECT t1.DN, RN = row_number() over (order by t1.DN)
FROM @tListNo t1
WHERE NOT EXISTS
(
SELECT *
FROM @tOutput t2
WHERE t2.DN = t1.DN
)

),
NewUsers as
(
select [UserName], RN = row_number() over (order by [UserId])
from @tUsers
)
INSERT INTO @tOutput (DN, NAME)
select t1.DN, t2.[UserName]
from DNFree t1
inner join NewUsers t2 on t1.RN = t2.RN[/code]


KH
[spoiler]Time is always against us[/spoiler]

Go to Top of Page
   

- Advertisement -