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 |
|
ywb
Yak Posting Veteran
55 Posts |
Posted - 2006-04-05 : 19:57:15
|
| Hi,I have 3 tables tblUser, tblColor and tblShape like the following.CREATE TABLE tblUser (userID smallint PRIMARY KEY IDENTITY NOT NULL, username nvarchar (20) NOT NULL);INSERT INTO tblUser (username) VALUES ('Peter');INSERT INTO tblUser (username) VALUES ('Paul');INSERT INTO tblUser (username) VALUES ('Mary');CREATE TABLE tblColor (colorID smallint PRIMARY KEY IDENTITY NOT NULL, color nvarchar (20) NOT NULL);INSERT INTO tblColor (color) VALUES ('Red');INSERT INTO tblColor (color) VALUES ('Green');INSERT INTO tblColor (color) VALUES ('Blue');INSERT INTO tblColor (color) VALUES ('Yellow');CREATE TABLE tblShape (shapeID smallint PRIMARY KEY IDENTITY NOT NULL, shape nvarchar (20) NOT NULL);INSERT INTO tblShape (shape) VALUES ('Circle');INSERT INTO tblShape (shape) VALUES ('Triangle');INSERT INTO tblShape (shape) VALUES ('Square');There is a 4th table that stores the users' favorite color and shape and the table is like this:CREATE TABLE tblUserFav (favID smallint PRIMARY KEY IDENTITY NOT NULL, userID smallint NOT NULL, colorID smallint NOT NULL, shapeID smallint NOT NULL)Now I would like to write a SQL statement that will pull every user ID in the tblUser table, populate into the tblUserFav table, and also randomly select a color and shape and assign to each user.How can I accomplish this?Thanks,ywb. |
|
|
nr
SQLTeam MVY
12543 Posts |
Posted - 2006-04-05 : 20:28:05
|
| declare @userID intselect @userID = 0while @userID < (select max(userID) from tblUser)beginselect @userID = @userID + 1 insert tblUserFav (userID, colorID, shapeID)select @userID, (select top 1 colorID from tblColor order by newid()), (select top 1 shapeID from tblShape order by newid())end==========================================Cursors are useful if you don't know sql.DTS can be used in a similar way.Beer is not cold and it isn't fizzy. |
 |
|
|
ywb
Yak Posting Veteran
55 Posts |
Posted - 2006-04-06 : 13:49:38
|
Hi nr, it works great! Thanks!quote: Originally posted by nr declare @userID intselect @userID = 0while @userID < (select max(userID) from tblUser)beginselect @userID = @userID + 1 insert tblUserFav (userID, colorID, shapeID)select @userID, (select top 1 colorID from tblColor order by newid()), (select top 1 shapeID from tblShape order by newid())end==========================================Cursors are useful if you don't know sql.DTS can be used in a similar way.Beer is not cold and it isn't fizzy.
|
 |
|
|
ywb
Yak Posting Veteran
55 Posts |
Posted - 2006-04-06 : 16:15:59
|
| Hi nr,How do I get it to work if the userID in my tblUser table isn't sequential? For example, what if Peter, Paul & Mary had userID of 3, 97, 17 respectively?ywb. |
 |
|
|
nr
SQLTeam MVY
12543 Posts |
Posted - 2006-04-06 : 18:50:27
|
| declare @userID intselect @userID = 0while @userID < (select max(userID) from tblUser)beginselect @userID = min(userID) from tblUser where userID > @userID insert tblUserFav (userID, colorID, shapeID)select @userID, (select top 1 colorID from tblColor order by newid()), (select top 1 shapeID from tblShape order by newid())end==========================================Cursors are useful if you don't know sql.DTS can be used in a similar way.Beer is not cold and it isn't fizzy. |
 |
|
|
ywb
Yak Posting Veteran
55 Posts |
Posted - 2006-04-07 : 19:11:05
|
| Cool! Thanks! |
 |
|
|
|
|
|
|
|