Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase

SQL Insert with Identity value AND incremental rollover column ? Expand / Collapse
Author
Message
Posted Wednesday, February 26, 2014 11:21 AM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Friday, March 7, 2014 9:52 AM
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

Post #1545516
Posted Wednesday, February 26, 2014 5:50 PM


Hall of Fame

Hall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of Fame

Group: General Forum Members
Last Login: Yesterday @ 7:58 PM
Points: 3,422, Visits: 5,366
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!
Post #1545648
Posted Wednesday, February 26, 2014 7:13 PM
Ten Centuries

Ten CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen Centuries

Group: General Forum Members
Last Login: 2 days ago @ 2:45 PM
Points: 1,080, Visits: 3,170
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
Post #1545663
Posted Wednesday, February 26, 2014 9:06 PM This worked for the OP Answer marked as solution


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Today @ 9:34 AM
Points: 35,532, Visits: 32,115
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."

(play on words) "Just because you CAN do something in T-SQL, doesn't mean you SHOULDN'T." --22 Aug 2013

Helpful Links:
How to post code problems
How to post performance problems
Post #1545685
Posted Friday, March 7, 2014 9:53 AM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Friday, March 7, 2014 9:52 AM
Points: 2, Visits: 16
I've never used a "computed column", but I tried it and it will solve my problem.
Thanks!
Post #1548797
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse