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 2000 Forums
 Transact-SQL (2000)
 how to capture stored procedure output

Author  Topic 

mk_garg20
Constraint Violating Yak Guru

343 Posts

Posted - 2005-11-16 : 23:46:44
here is my stored proc


CREATE PROCEDURE sp_Insert_StockReceipts (
@ResourceId AS INTEGER, @SupplierId AS INTEGER,
@Description AS VARCHAR(150), @Quantity AS INTEGER,
@PurchaseOrder AS INTEGER, @StockCode AS VARCHAR(10),
@DateReceived AS VARCHAR(10), @DeliveryMethod AS VARCHAR(50),
@DeliveryCompany AS VARCHAR(50), @Comments AS VARCHAR(255),
@RequisitionNumber AS INTEGER, @OrderFulfilled AS BIT,
@OrderItemFulfilled AS BIT, @ReferenceCode AS VARCHAR(100),
@DeliveredTo AS INTEGER)
AS

DECLARE @ReceiptID AS INTEGER

INSERT StockReceipts (
TimeReceived,
ResourceId, SupplierId,
Description, Quantity,
PurchaseOrder, StockCode,
DateReceived, DeliveryMethod,
DeliveryCompany, Comments,
RequisitionNumber, OrderFulfilled,
OrderItemFulfilled, ReferenceCode,
DeliveredTo)
VALUES(
GETDATE(),
@ResourceId, @SupplierId,
@Description, @Quantity,
@PurchaseOrder, @StockCode,
CONVERT(DATETIME, @DateReceived, 103), @DeliveryMethod,
@DeliveryCompany, @Comments,
@RequisitionNumber, @OrderFulfilled,
@OrderItemFulfilled, @ReferenceCode,
@DeliveredTo)

SET @ReceiptID = @@identity

SELECT @ReceiptID AS ReceiptID

GO


i am calling it from another stored procedure proc1.

how i can capture value of ReceiptID in a variable in proc1

Thanks

mk_garg

derrickleggett
Pointy Haired Yak DBA

4184 Posts

Posted - 2005-11-17 : 00:05:38
There's a couple ways you can do this.

1. You can make the @ReceiptID an output parameter. Here's an example from Books Online and information regarding it.

quote:


Creating and Maintaining Databases


Returning Data Using OUTPUT Parameters
If you specify the OUTPUT keyword for a parameter in the procedure definition, the stored procedure can return the current value of the parameter to the calling program when the stored procedure exits. To save the value of the parameter in a variable that can be used in the calling program, the calling program must use the OUTPUT keyword when executing the stored procedure.

Examples
The following example shows a stored procedure with an input and an output parameter. The first parameter in the stored procedure @title receives the input value specified by the calling program, and the second parameter @ytd_sales is used to return the value to the calling program. The SELECT statement uses the @title parameter to obtain the correct ytd_sales value, and assigns the value to the @ytd_sales output parameter.

CREATE PROCEDURE get_sales_for_title
@title varchar(80), -- This is the input parameter.
@ytd_sales int OUTPUT -- This is the output parameter.
AS

-- Get the sales for the specified title and
-- assign it to the output parameter.
SELECT @ytd_sales = ytd_sales
FROM titles
WHERE title = @title

RETURN
GO

The following program executes the stored procedure with a value for the input parameter and saves the output value of the stored procedure in the @ytd_sales_for_title variable local to the calling program.

-- Declare the variable to receive the output value of the procedure.
DECLARE @ytd_sales_for_title int

-- Execute the procedure with a title_id value
-- and save the output value in a variable.

EXECUTE get_sales_for_title
"Sushi, Anyone?", @ytd_sales = @ytd_sales_for_title OUTPUT

-- Display the value returned by the procedure.
PRINT 'Sales for "Sushi, Anyone?": ' + convert(varchar(6),@ytd_sales_for_title)
GO

Sales for "Sushi, Anyone?": 4095

Input values can also be specified for OUTPUT parameters when the stored procedure is executed. This allows the stored procedure to receive a value from the calling program, change it or perform operations with it, then return the new value to the calling program. In the earlier example, the @ytd_sales_for_title variable can be assigned a value prior to executing the stored procedure. The @ytd_sales variable contains the value of the parameter in the body of the stored procedure, and the value of the @ytd_sales variable is returned to the calling program when the stored procedure exits. This is often referred to as "pass-by-reference capability."

If you specify OUTPUT for a parameter when you execute a stored procedure and the parameter is not defined using OUTPUT in the stored procedure, you get an error message. You can execute a stored procedure with OUTPUT parameters and not specify OUTPUT when executing the stored procedure. No error is returned, but you cannot use the output value in the calling program.


See Also

EXECUTE

Scope of Transact-SQL Cursor Names

©1988-2000 Microsoft Corporation. All Rights Reserved.



2. You can create a temp table with a ReceiptID column in proc1. This will allow you to INSERT #temp(ReceiptID) EXEC sp_Insert_StockReceipts

You've been on here quite awhile. You do know that you shouldn't prefix procs with "sp_" and you should probably use SCOPE_IDENTITY() instead of @@identity, right?

MeanOldDBA
derrickleggett@hotmail.com

When life gives you a lemon, fire the DBA.
Go to Top of Page

madhivanan
Premature Yak Congratulator

22864 Posts

Posted - 2005-11-17 : 00:24:06
Are you using Front End application?
If so, As you used this SELECT @ReceiptID AS ReceiptID, you will be able to get that value in Recordset

Madhivanan

Failing to plan is Planning to fail
Go to Top of Page

mk_garg20
Constraint Violating Yak Guru

343 Posts

Posted - 2005-11-17 : 00:26:04
thanks derick.

I understand stored procedure shpuld not start with "sp_".

This is very old sp written by someone else and shared by many application.



mk_garg
Go to Top of Page
   

- Advertisement -