SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Inserting Multiple Records Using While Loop


Inserting Multiple Records Using While Loop

Author
Message
cdub11532
cdub11532
Forum Newbie
Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)

Group: General Forum Members
Points: 3 Visits: 5
I'm trying to insert multiple records in while loop but I keep getting cannot insert duplicate into primary key error. I'm trying to insert same information into temp table except for linecd should be 4 or 5. Issue seems to be with while loop.

create table #TempSalesGLLink(
AHInsCostAcct varchar(10)
, AHInsCostDept varchar(10)
, AHInsRevenueAcct varchar(10)
, AHInsRevenueDept varchar(10)
, CashDownAcct varchar(10)
, CashDownDept varchar(3)
, CLInsCostAcct varchar(10)
, CLInsCostDept varchar(10)
, CLInsRevenueAcct varchar(10)
, CLInsRevenueDept varchar(10)
, CostGoodsAcct varchar(10)
, CostGoodsDept varchar(3)
, CostofSalesSubAcct varchar(10)
, CostofSalesSubDept varchar(10)
, DueFromFinAcct varchar(10)
, DueFromFinDept varchar(3)
, DueToCustAcct varchar(10)
, DueToCustDept varchar(3)
, InvSoldAcct varchar(10)
, InvSoldDept varchar(3)
, LineCd char(2)
, LoanDiscountAcct varchar(10)
, LoanDiscountDept varchar(3)
, LocId varchar(10)
, NSFFeeAcct varchar(10)
, NSFFeeDept varchar(3)
, NSFRecAcct varchar(10)
, NSFRecDept varchar(10)
, OtherIncomeAcct varchar(10)
, OtherIncomeDept varchar(3)
, OverAllowAcct varchar(10)
, OverAllowDept varchar(3)
, SalesGLLinkUniqueNum int
, SalesTypeCd varchar(5)
, StoreId varchar(10)
, TradeACVAcct varchar(10)
, TradeACVDept varchar(3)
, VehSaleAcct varchar(5)
, VehSaleDept varchar(3),
CONSTRAINT [PK_SalesGLLink] PRIMARY KEY
(
[StoreId] ASC,
[LocId] ASC,
[SalesGLLinkUniqueNum] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 80) ON [PRIMARY]
) ON [PRIMARY]




SET NOCOUNT ON


--Insert Into #TempSalesGLLink(AHInsCostAcct, AHInsCostDept, AHInsRevenueAcct, AHInsRevenueDept, CashDownAcct, CashDownDept, CLInsCostAcct, CLInsCostDept, CLInsRevenueAcct, CLInsRevenueDept, CostGoodsAcct,
--CostGoodsDept, CostofSalesSubAcct, CostofSalesSubDept, DueFromFinAcct, DueFromFinDept, DueToCustAcct, DueToCustDept, InvSoldAcct, InvSoldDept, LineCd, LoanDiscountAcct, LoanDiscountDept, LocId
--, NSFFeeAcct, NSFFeeDept, NSFRecAcct, NSFRecDept, OtherIncomeAcct, OtherIncomeDept, OverAllowAcct, OverAllowDept, SalesGLLinkUniqueNum , SalesTypeCd, StoreId
--, TradeACVAcct, TradeACVDept, VehSaleAcct, VehSaleDept
--)


--/* Gets the Product Description, MembershipNo, DateAdded, LastName and FirstName, and BranchName for New Members */
-- select AHInsCostAcct, AHInsCostDept, AHInsRevenueAcct, AHInsRevenueDept, CashDownAcct, CashDownDept, CLInsCostAcct, CLInsCostDept, CLInsRevenueAcct, CLInsRevenueDept, CostGoodsAcct,
-- CostGoodsDept, CostofSalesSubAcct, CostofSalesSubDept, DueFromFinAcct, DueFromFinDept, DueToCustAcct, DueToCustDept, InvSoldAcct, InvSoldDept, LineCd, LoanDiscountAcct, LoanDiscountDept, LocId,
-- NSFFeeAcct, NSFFeeDept, NSFRecAcct, NSFRecDept, OtherIncomeAcct, OtherIncomeDept, OverAllowAcct, OverAllowDept, SalesGLLinkUniqueNum , SalesTypeCd, StoreId,
-- TradeACVAcct, TradeACVDept, VehSaleAcct, VehSaleDept from SalesGLLink where salestypecd = 'r' and linecd = '3'


declare @rowCount int
select @rowCount = count(*) from SalesGLLink where salestypecd = 'r' and linecd = '3'
Print @rowCount
declare @counter int
select @counter = 0


[color=#FF4040]while @counter < @rowCount[/color]
begin


Insert Into #TempSalesGLLink(StoreId, LocId, SalesGLLinkUniqueNum, SalesTypeCd, LineCd, VehSaleAcct, VehSaleDept, TradeACVAcct, TradeACVDept, OverAllowAcct, OverAllowDept, LoanDiscountAcct, LoanDiscountDept,
DueFromFinAcct, DueFromFinDept, CashDownAcct, CashDownDept, CostGoodsAcct, CostGoodsDept, InvSoldDept, OtherIncomeAcct, OtherIncomeDept, DueToCustAcct, DueToCustDept, NSFFeeAcct, NSFFeeDept, NSFRecAcct,
NSFRecDept, CostofSalesSubAcct, CostofSalesSubDept, AHInsRevenueAcct, AHInsRevenueDept, AHInsCostAcct, AHInsCostDept, CLInsRevenueAcct, CLInsRevenueDept, CLInsCostAcct, CLInsCostDept)


select StoreId, LocId, SalesGLLinkUniqueNum, SalesTypeCd, '4' as LineCd, VehSaleAcct, VehSaleDept, TradeACVAcct, TradeACVDept, OverAllowAcct, OverAllowDept, LoanDiscountAcct, LoanDiscountDept,
DueFromFinAcct, DueFromFinDept, CashDownAcct, CashDownDept, CostGoodsAcct, CostGoodsDept, InvSoldDept, OtherIncomeAcct, OtherIncomeDept, DueToCustAcct, DueToCustDept, NSFFeeAcct, NSFFeeDept, NSFRecAcct,
NSFRecDept, CostofSalesSubAcct, CostofSalesSubDept, AHInsRevenueAcct, AHInsRevenueDept, AHInsCostAcct, AHInsCostDept, CLInsRevenueAcct, CLInsRevenueDept, CLInsCostAcct, CLInsCostDept from SalesGLLink where salestypecd = 'r' and linecd = '3'


Insert Into #TempSalesGLLink(StoreId, LocId, SalesGLLinkUniqueNum, SalesTypeCd, LineCd, VehSaleAcct, VehSaleDept, TradeACVAcct, TradeACVDept, OverAllowAcct, OverAllowDept, LoanDiscountAcct, LoanDiscountDept,
DueFromFinAcct, DueFromFinDept, CashDownAcct, CashDownDept, CostGoodsAcct, CostGoodsDept, InvSoldDept, OtherIncomeAcct, OtherIncomeDept, DueToCustAcct, DueToCustDept, NSFFeeAcct, NSFFeeDept, NSFRecAcct,
NSFRecDept, CostofSalesSubAcct, CostofSalesSubDept, AHInsRevenueAcct, AHInsRevenueDept, AHInsCostAcct, AHInsCostDept, CLInsRevenueAcct, CLInsRevenueDept, CLInsCostAcct, CLInsCostDept
)


select StoreId, LocId, SalesGLLinkUniqueNum, SalesTypeCd, '5' as LineCd, VehSaleAcct, VehSaleDept, TradeACVAcct, TradeACVDept, OverAllowAcct, OverAllowDept, LoanDiscountAcct, LoanDiscountDept,
DueFromFinAcct, DueFromFinDept, CashDownAcct, CashDownDept, CostGoodsAcct, CostGoodsDept, InvSoldDept, OtherIncomeAcct, OtherIncomeDept, DueToCustAcct, DueToCustDept, NSFFeeAcct, NSFFeeDept, NSFRecAcct,
NSFRecDept, CostofSalesSubAcct, CostofSalesSubDept, AHInsRevenueAcct, AHInsRevenueDept, AHInsCostAcct, AHInsCostDept, CLInsRevenueAcct, CLInsRevenueDept, CLInsCostAcct, CLInsCostDept from SalesGLLink where salestypecd = 'r' and linecd = '3'

select @counter = @counter + 1
Print @Counter
end


select StoreId, LocId, SalesGLLinkUniqueNum, SalesTypeCd, LineCd, VehSaleAcct, VehSaleDept, TradeACVAcct, TradeACVDept, OverAllowAcct, OverAllowDept, LoanDiscountAcct, LoanDiscountDept,
DueFromFinAcct, DueFromFinDept, CashDownAcct, CashDownDept, CostGoodsAcct, CostGoodsDept, InvSoldDept, OtherIncomeAcct, OtherIncomeDept, DueToCustAcct, DueToCustDept, NSFFeeAcct, NSFFeeDept, NSFRecAcct,
NSFRecDept, CostofSalesSubAcct, CostofSalesSubDept, AHInsRevenueAcct, AHInsRevenueDept, AHInsCostAcct, AHInsCostDept, CLInsRevenueAcct, CLInsRevenueDept, CLInsCostAcct, CLInsCostDept from #TempSalesGLLink where LineCd = '4' or LineCd = '5'
--drop table #TempSalesGLLink
Tochi
Tochi
Forum Newbie
Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)

Group: General Forum Members
Points: 1 Visits: 44
Just like the error said...you have a primary key on the table and primary keys don't accept duplicates
cdub11532
cdub11532
Forum Newbie
Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)

Group: General Forum Members
Points: 3 Visits: 5
Thanks for the reply. I know what the error means. I'm trying to figure out why when performing the loop it keeps putting in the same records multiple times. That's why I added the primary key to the temp table.
Gazareth
Gazareth
SSCarpal Tunnel
SSCarpal Tunnel (4K reputation)SSCarpal Tunnel (4K reputation)SSCarpal Tunnel (4K reputation)SSCarpal Tunnel (4K reputation)SSCarpal Tunnel (4K reputation)SSCarpal Tunnel (4K reputation)SSCarpal Tunnel (4K reputation)SSCarpal Tunnel (4K reputation)

Group: General Forum Members
Points: 4040 Visits: 5843
On that PK violation - As far as I can tell, each loop just inserts the same data, so you will get the PK violation on the second iteration?
Gazareth
Gazareth
SSCarpal Tunnel
SSCarpal Tunnel (4K reputation)SSCarpal Tunnel (4K reputation)SSCarpal Tunnel (4K reputation)SSCarpal Tunnel (4K reputation)SSCarpal Tunnel (4K reputation)SSCarpal Tunnel (4K reputation)SSCarpal Tunnel (4K reputation)SSCarpal Tunnel (4K reputation)

Group: General Forum Members
Points: 4040 Visits: 5843
cdub11532 (1/17/2013)
Thanks for the reply. I know what the error means. I'm trying to figure out why when performing the loop it keeps putting in the same records multiple times. That's why I added the primary key to the temp table.


Because your select statement is the same in each loop :-)
cdub11532
cdub11532
Forum Newbie
Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)

Group: General Forum Members
Points: 3 Visits: 5
Thank you Gazareth. I looked again and realized I didn't even need the loop.
All I need is and really I don't even need the temp table just need to do the insert on the permanent table. I think my brain was on vacation yesterday.
create table #TempSalesGLLink(
AHInsCostAcct varchar(10)
, AHInsCostDept varchar(10)
, AHInsRevenueAcct varchar(10)
, AHInsRevenueDept varchar(10)
, CashDownAcct varchar(10)
, CashDownDept varchar(3)
, CLInsCostAcct varchar(10)
, CLInsCostDept varchar(10)
, CLInsRevenueAcct varchar(10)
, CLInsRevenueDept varchar(10)
, CostGoodsAcct varchar(10)
, CostGoodsDept varchar(3)
, CostofSalesSubAcct varchar(10)
, CostofSalesSubDept varchar(10)
, DueFromFinAcct varchar(10)
, DueFromFinDept varchar(3)
, DueToCustAcct varchar(10)
, DueToCustDept varchar(3)
, InvSoldAcct varchar(10)
, InvSoldDept varchar(3)
, LineCd char(2)
, LoanDiscountAcct varchar(10)
, LoanDiscountDept varchar(3)
, LocId varchar(10)
, NSFFeeAcct varchar(10)
, NSFFeeDept varchar(3)
, NSFRecAcct varchar(10)
, NSFRecDept varchar(10)
, OtherIncomeAcct varchar(10)
, OtherIncomeDept varchar(3)
, OverAllowAcct varchar(10)
, OverAllowDept varchar(3)
, SalesGLLinkUniqueNum int
, SalesTypeCd varchar(5)
, StoreId varchar(10)
, TradeACVAcct varchar(10)
, TradeACVDept varchar(3)
, VehSaleAcct varchar(5)
, VehSaleDept varchar(3)
)
--CONSTRAINT [PK_SalesGLLink] PRIMARY KEY
--(
-- [StoreId] ASC,
-- [LocId] ASC,
-- [SalesGLLinkUniqueNum] ASC
--)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 80) ON [PRIMARY]
--) ON [PRIMARY]


SET NOCOUNT ON

Insert Into #TempSalesGLLink(StoreId, LocId, SalesGLLinkUniqueNum, SalesTypeCd, LineCd, VehSaleAcct, VehSaleDept, TradeACVAcct, TradeACVDept, OverAllowAcct, OverAllowDept, LoanDiscountAcct, LoanDiscountDept,
DueFromFinAcct, DueFromFinDept, CashDownAcct, CashDownDept, CostGoodsAcct, CostGoodsDept, InvSoldDept, OtherIncomeAcct, OtherIncomeDept, DueToCustAcct, DueToCustDept, NSFFeeAcct, NSFFeeDept, NSFRecAcct,
NSFRecDept, CostofSalesSubAcct, CostofSalesSubDept, AHInsRevenueAcct, AHInsRevenueDept, AHInsCostAcct, AHInsCostDept, CLInsRevenueAcct, CLInsRevenueDept, CLInsCostAcct, CLInsCostDept)

select StoreId, LocId, 6, SalesTypeCd, '4' as LineCd, VehSaleAcct, VehSaleDept, TradeACVAcct, TradeACVDept, OverAllowAcct, OverAllowDept, LoanDiscountAcct, LoanDiscountDept,
DueFromFinAcct, DueFromFinDept, CashDownAcct, CashDownDept, CostGoodsAcct, CostGoodsDept, InvSoldDept, OtherIncomeAcct, OtherIncomeDept, DueToCustAcct, DueToCustDept, NSFFeeAcct, NSFFeeDept, NSFRecAcct,
NSFRecDept, CostofSalesSubAcct, CostofSalesSubDept, AHInsRevenueAcct, AHInsRevenueDept, AHInsCostAcct, AHInsCostDept, CLInsRevenueAcct, CLInsRevenueDept, CLInsCostAcct, CLInsCostDept from SalesGLLink where salestypecd = 'r' and linecd = '3'

Insert Into #TempSalesGLLink(StoreId, LocId, SalesGLLinkUniqueNum, SalesTypeCd, LineCd, VehSaleAcct, VehSaleDept, TradeACVAcct, TradeACVDept, OverAllowAcct, OverAllowDept, LoanDiscountAcct, LoanDiscountDept,
DueFromFinAcct, DueFromFinDept, CashDownAcct, CashDownDept, CostGoodsAcct, CostGoodsDept, InvSoldDept, OtherIncomeAcct, OtherIncomeDept, DueToCustAcct, DueToCustDept, NSFFeeAcct, NSFFeeDept, NSFRecAcct,
NSFRecDept, CostofSalesSubAcct, CostofSalesSubDept, AHInsRevenueAcct, AHInsRevenueDept, AHInsCostAcct, AHInsCostDept, CLInsRevenueAcct, CLInsRevenueDept, CLInsCostAcct, CLInsCostDept)

select StoreId, LocId, 7, SalesTypeCd, '5' as LineCd, VehSaleAcct, VehSaleDept, TradeACVAcct, TradeACVDept, OverAllowAcct, OverAllowDept, LoanDiscountAcct, LoanDiscountDept,
DueFromFinAcct, DueFromFinDept, CashDownAcct, CashDownDept, CostGoodsAcct, CostGoodsDept, InvSoldDept, OtherIncomeAcct, OtherIncomeDept, DueToCustAcct, DueToCustDept, NSFFeeAcct, NSFFeeDept, NSFRecAcct,
NSFRecDept, CostofSalesSubAcct, CostofSalesSubDept, AHInsRevenueAcct, AHInsRevenueDept, AHInsCostAcct, AHInsCostDept, CLInsRevenueAcct, CLInsRevenueDept, CLInsCostAcct, CLInsCostDept from SalesGLLink where salestypecd = 'r' and linecd = '3'
Gazareth
Gazareth
SSCarpal Tunnel
SSCarpal Tunnel (4K reputation)SSCarpal Tunnel (4K reputation)SSCarpal Tunnel (4K reputation)SSCarpal Tunnel (4K reputation)SSCarpal Tunnel (4K reputation)SSCarpal Tunnel (4K reputation)SSCarpal Tunnel (4K reputation)SSCarpal Tunnel (4K reputation)

Group: General Forum Members
Points: 4040 Visits: 5843
No problem!
ChrisM@Work
ChrisM@Work
SSCoach
SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)

Group: General Forum Members
Points: 16468 Visits: 19557
-- you only need to read the SalesGLLink table once:
INSERT INTO #TempSalesGLLink(
StoreId, LocId, SalesGLLinkUniqueNum, SalesTypeCd, LineCd,
VehSaleAcct, VehSaleDept, TradeACVAcct, TradeACVDept, OverAllowAcct, OverAllowDept, LoanDiscountAcct, LoanDiscountDept,
DueFromFinAcct, DueFromFinDept, CashDownAcct, CashDownDept, CostGoodsAcct, CostGoodsDept, InvSoldDept, OtherIncomeAcct, OtherIncomeDept, DueToCustAcct, DueToCustDept, NSFFeeAcct, NSFFeeDept, NSFRecAcct,
NSFRecDept, CostofSalesSubAcct, CostofSalesSubDept, AHInsRevenueAcct, AHInsRevenueDept, AHInsCostAcct, AHInsCostDept, CLInsRevenueAcct, CLInsRevenueDept, CLInsCostAcct, CLInsCostDept)

SELECT
StoreId, LocId, cj.SalesGLLinkUniqueNum, SalesTypeCd, cj.LineCd,
VehSaleAcct, VehSaleDept, TradeACVAcct, TradeACVDept, OverAllowAcct, OverAllowDept, LoanDiscountAcct, LoanDiscountDept,
DueFromFinAcct, DueFromFinDept, CashDownAcct, CashDownDept, CostGoodsAcct, CostGoodsDept, InvSoldDept, OtherIncomeAcct, OtherIncomeDept, DueToCustAcct, DueToCustDept, NSFFeeAcct, NSFFeeDept, NSFRecAcct,
NSFRecDept, CostofSalesSubAcct, CostofSalesSubDept, AHInsRevenueAcct, AHInsRevenueDept, AHInsCostAcct, AHInsCostDept, CLInsRevenueAcct, CLInsRevenueDept, CLInsCostAcct, CLInsCostDept
FROM SalesGLLink s
CROSS JOIN (SELECT SalesGLLinkUniqueNum = 6, LineCd = '4' UNION ALL SELECT 7, '5') cj
WHERE s.salestypecd = 'r' AND s.linecd = '3'



“Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
Exploring Recursive CTEs by Example Dwain Camps
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search