INTELLIGENT WORK FORUMS
FOR COMPUTER PROFESSIONALS

Log In

Come Join Us!

Are you a
Computer / IT professional?
Join Tek-Tips Forums!
  • Talk With Other Members
  • Be Notified Of Responses
    To Your Posts
  • Keyword Search
  • One-Click Access To Your
    Favorite Forums
  • Automated Signatures
    On Your Posts
  • Best Of All, It's Free!

*Tek-Tips's functionality depends on members receiving e-mail. By joining you are opting in to receive e-mail.

Posting Guidelines

Promoting, selling, recruiting, coursework and thesis posting is forbidden.

Jobs

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

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

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

(OP)
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

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

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
www.syssoft-int.com

FAQ219-2884: How Do I Get Great Answers To my Tek-Tips Questions?
FAQ181-2886: How can I maximize my chances of getting an answer?

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

(OP)
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

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

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
www.syssoft-int.com

FAQ219-2884: How Do I Get Great Answers To my Tek-Tips Questions?
FAQ181-2886: How can I maximize my chances of getting an answer?

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

(OP)
Thanks, looks great. I will try it out.

Auguy
Sylvania/Toledo Ohio

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

(OP)
Follow up, worked perfectly. Thanks again.

Auguy
Sylvania/Toledo Ohio

Red Flag This Post

Please let us know here why this post is inappropriate. Reasons such as off-topic, duplicates, flames, illegal, vulgar, or students posting their homework.

Red Flag Submitted

Thank you for helping keep Tek-Tips Forums free from inappropriate posts.
The Tek-Tips staff will check this out and take appropriate action.

Reply To This Thread

Posting in the Tek-Tips forums is a member-only feature.

Click Here to join Tek-Tips and talk with other members!

Resources

Close Box

Join Tek-Tips® Today!

Join your peers on the Internet's largest technical computer professional community.
It's easy to join and it's free.

Here's Why Members Love Tek-Tips Forums:

Register now while it's still free!

Already a member? Close this window and log in.

Join Us             Close