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


SQL Insert with Identity value AND incremental rollover column ?


SQL Insert with Identity value AND incremental rollover column ?

Author
Message
RobRud
RobRud
Forum Newbie
Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)

Group: General Forum Members
Points: 2 Visits: 16
Hi
I need to create an INSERT query that will create new rows with a normal identity column, and in another integer column: increment (and rollover) a three-digit number. I'm using MSSQL Server 2008 r2.

Similar to the (incorrect) code below, I have a table and I need an INSERT procedure that will increment the MBatch column from 1 to 999, then rollover back to 1 on the next row insert. For example: the last row (identity=1111) may have MBatch=999, so when I insert new row (1112) I need MBatch=1).

When I call the INSERT procedure, I will pass it the "@MStatus" value, and would like the proc to return the Identity column value and the MBatch value.

Any suggestions?
Thanks!


CREATE TABLE [dbo].[MTRANS]
([MTRANS_ID] int IDENTITY (1, 1) NOT NULL,
[MBatch] int NULL,
[MStatus] char(1) NULL
)


CREATE PROCEDURE [prMTRANS_INSERT]
(@MTRANS_ID int OUTPUT,
@MStatus char(1),
@MBatch int OUTPUT
)

As

BEGIN
Begin
select MAX([MTRANS_ID]), [MBatch] from [MTRANS]

-- this bit is not correct, but you get what I'm going for ...

SET @mbatch = [MBatch]
if @mbatch >= 999
begin
set @mbatch = 1
end
else
set @mbatch = @mbatch +1

INSERT INTO [MTRANS]([MStatus], [MBatch)
VALUES (@mstatus,@mbatch)
End

SELECT @@IDENTITY as TRANS_ID, @mbatch as BATCHNO

END


dwain.c
dwain.c
SSCertifiable
SSCertifiable (7.6K reputation)SSCertifiable (7.6K reputation)SSCertifiable (7.6K reputation)SSCertifiable (7.6K reputation)SSCertifiable (7.6K reputation)SSCertifiable (7.6K reputation)SSCertifiable (7.6K reputation)SSCertifiable (7.6K reputation)

Group: General Forum Members
Points: 7591 Visits: 6431
Something like this?


CREATE TABLE #MTRANS
([MTRANS_ID] int IDENTITY (1, 1) NOT NULL,
[MBatch] int NULL,
[MStatus] char(1) NULL
);

-- Create 10 rows
WITH Tally (n) AS
(
SELECT TOP 10 ROW_NUMBER() OVER (ORDER BY (SELECT NULL))
FROM sys.all_columns a CROSS JOIN sys.all_columns b
)
INSERT INTO #MTRANS (MBatch)
SELECT n
FROM Tally;

DECLARE @MBatch INT =(SELECT MAX(MBatch) FROM #MTRANS);

-- Create 999 rows with rollover at 300
WITH Tally (n) AS
(
SELECT TOP 999 ROW_NUMBER() OVER (ORDER BY (SELECT NULL))
FROM sys.all_columns a CROSS JOIN sys.all_columns b
)
INSERT INTO #MTRANS (MBatch)
SELECT 1+(@MBatch+ROW_NUMBER() OVER (ORDER BY n)-1)%300
FROM Tally;

SELECT *
FROM #MTRANS

GO
DROP TABLE #MTRANS;





My mantra: No loops! No CURSORs! No RBAR! Hoo-uh!

My thought question: Have you ever been told that your query runs too fast?

My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.


Need to UNPIVOT? Why not CROSS APPLY VALUES instead?
Since random numbers are too important to be left to chance, let's generate some!
Learn to understand recursive CTEs by example.
Splitting strings based on patterns can be fast!
My temporal SQL musings: Calendar Tables, an Easter SQL, Time Slots and Self-maintaining, Contiguous Effective Dates in Temporal Tables
mickyT
mickyT
SSCommitted
SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)

Group: General Forum Members
Points: 1612 Visits: 3317
The problem I see with your procedure is that the @mbatch variable is not set to the max.

If you alter your procedure to the following it should work.
CREATE PROCEDURE [prMTRANS_INSERT]
(@MTRANS_ID int OUTPUT,
@MStatus char(1),
@MBatch int OUTPUT
)

As

BEGIN
Begin
-- Changed your query here
SELECT TOP 1 @mbatch = [MBatch] FROM [MTRANS] ORDER BY [MTRANS_ID] DESC

--SET @mbatch = [MBatch] -- Remove this
if @mbatch >= 999
begin
set @mbatch = 1
end
else
set @mbatch = @mbatch +1

INSERT INTO [MTRANS]([MStatus], [MBatch])
VALUES (@mstatus,@mbatch)
End

SET @MTRANS_ID = SCOPE_IDENTITY()
-- SELECT @@IDENTITY as TRANS_ID, @mbatch as BATCHNO -- Not sure if you want to do this

END



Tested with
declare @oMID INT, @oBatch INT
exec prMTRANS_INSERT @MTRANS_ID = @oMID , @MStatus = 'B', @MBatch = @oBatch
GO 1500

SELECT * FROM [MTRANS]



Having said that, are all of your inserts one at a time and are they all through this procedure? You may run into issues if they aren't.
In 2012 you could use a sequence with cycling as the default value on the batch.

Edit: Fixed a syntax error and return values
Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (89K reputation)SSC Guru (89K reputation)SSC Guru (89K reputation)SSC Guru (89K reputation)SSC Guru (89K reputation)SSC Guru (89K reputation)SSC Guru (89K reputation)SSC Guru (89K reputation)

Group: General Forum Members
Points: 89577 Visits: 41144
Avoid the RBAR. Make a persisted computed column that uses a formula like MTRANS_ID%999+1. Yeah... it'll have gaps, now and again... just like the IDENTITY column

--Jeff Moden

RBAR is pronounced ree-bar and is a Modenism for Row-By-Agonizing-Row.
First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column.
If you think its expensive to hire a professional to do the job, wait until you hire an amateur. -- Red Adair

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
RobRud
RobRud
Forum Newbie
Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)

Group: General Forum Members
Points: 2 Visits: 16
I've never used a "computed column", but I tried it and it will solve my problem.
Thanks!
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