Tek-Tips is the largest IT community on the Internet today!

Members share and learn making Tek-Tips Forums the best source of peer-reviewed technical information on the Internet!

  • Congratulations strongm on being selected by the Tek-Tips community for having the most helpful posts in the forums last week. Way to Go!

Insert Depending On Aother Table's Column Value Not Part of the Insert Columns 1

Status
Not open for further replies.

Auguy

Programmer
May 1, 2004
1,206
US
I have stored proc that looks something like this (shortened for clarity)
Code:
	@IsPosted int
	,@CompanyMasterFK int
	,@GLperiod varchar(10)
	,@Amount decimal(12, 2)
	,@SourceID varchar(20)
	,@NewPK	int output
AS
BEGIN
	-- SET NOCOUNT ON added to prevent extra result sets from
	-- interfering with SELECT statements.
	SET NOCOUNT ON;

    -- Insert statements for procedure here
	INSERT INTO dbo.GLpost
 	(IsPosted
	,CompanyMasterFK
	,GLperiod
	,Amount
	,SourceID)

	SELECT
 	@IsPosted
	,@CompanyMasterFK
	,@GLperiod
	,@Amount
	,@SourceID

	FROM dbo.Numbers NBR

	-- Make sure GL period is valid
	WHERE NBR.Number = 1
		AND EXISTS (SELECT 1
			FROM dbo.CompanyCurrentGLinfo CGLI
			WHERE CGLI.CompanyMasterFK = @CompanyMasterFK 
                        AND @GLperiod >= 
			CASE
				WHEN @SourceID = 'AP' THEN CGLI.APcurrentPeriod
				WHEN @SourceID = 'AR' THEN CGLI.ARcurrentPeriod
				WHEN @SourceID = 'GL' THEN CGLI.GLcurrentPeriod
				ELSE '9999-99'
			END
			)

	SET @NewPK = Scope_Identity()

	RETURN @NewPK
END
This doesn't work, but if I change the Where clause to use a specific column (see below), it works. What am I missing?
Code:
	-- Make sure GL period is valid
	WHERE NBR.Number = 1
		AND EXISTS (SELECT 1
			FROM dbo.CompanyCurrentGLinfo CGLI
			WHERE CGLI.CompanyMasterFK = @CompanyMasterFK 
                        AND @GLperiod >= CGLI.ARcurrentPeriod)			)
What I am trying to achieve is to insert the record if the GL period is equal to or greater that the GL period in the CompanyCurrentGLinfo table depending on AP, AP, or GL.

Auguy
Sylvania/Toledo Ohio
 
what are the datatypes of the GCLI fields you comparing to on the case statement?

And can you give some data examples for each of them.

On another note for the particular code you have you do not need to access that numbers table.
a simple
if exists (select ... from CompanyCurrentGLinfo ...)
begin
insert into ... values ...
end
would do

Regards

Frederico Fonseca
SysSoft Integrated Ltd

FAQ219-2884
FAQ181-2886
 
These are all varchar(10). Examples
GLperiod = '2017-07'
CGLI.APcurrentPeriod = '2017-08'
CGLI.ARcurrentPeriod = '2017-07'
CGLI.GLcurrentPeriod = ' 2017-07'

I tried without the numbers table and was getting too many inserts (actually the number of records in the CGLI table).
Probably because the case statement isn't correct or even the the method to use.
I also tried to set up an inner join with no success.

Auguy
Sylvania/Toledo Ohio
 
ok.

this works with dummy data based on your examples.

Code:
create procedure x
     @IsPosted int
   , @CompanyMasterFK int
   , @GLperiod varchar(10)
   , @Amount decimal(12, 2)
   , @SourceID varchar(20)
   , @NewPK int output
as
begin
    -- SET NOCOUNT ON added to prevent extra result sets from
    -- interfering with SELECT statements.
    set nocount on;

    set @NewPK = null
    if exists
        (select 1
            from dbo.CompanyCurrentGLinfo CGLI
            where CGLI.CompanyMasterFK = @CompanyMasterFK
                and @GLperiod >=
                    case
                    when @SourceID = 'AP' then CGLI.APcurrentPeriod
                    when @SourceID = 'AR' then CGLI.ArcurrentPeriod
                    when @SourceID = 'GL' then CGLI.GLcurrentPeriod
                    else '9999-99'
                    end
        )
    begin
        insert into dbo.GLpost
                ( IsPosted
                , CompanyMasterFK
                , GLperiod
                , Amount
                , SourceID
                )
            values (@IsPosted, @CompanyMasterFK, @GLperiod, @Amount, @SourceID)
        set @NewPK = scope_identity()
    end
    return @NewPK
end

Regards

Frederico Fonseca
SysSoft Integrated Ltd

FAQ219-2884
FAQ181-2886
 
Thanks, looks great. I will try it out.

Auguy
Sylvania/Toledo Ohio
 
Follow up, worked perfectly. Thanks again.

Auguy
Sylvania/Toledo Ohio
 
Status
Not open for further replies.

Part and Inventory Search

Sponsor

Back
Top