web
You’re offline. This is a read only version of the page.
close
Skip to main content

Notifications

Announcements

No record found.

Community site session details

Community site session details

Session Id :
Microsoft Dynamics GP (Archived)

SOP Line Items Linked To Incorrect SOP Header

(0) ShareShare
ReportReport
Posted on by

We have been dealing with an odd situation at our company for years. It is impossible to duplicate using any set of criteria that I can come up with but still the issue occurrs several times a week. We have several people entering sales orders all day long. Every once in a while, the line items (SOP10200) from one order will end up associated with the order (SOP10100) that was entered by a different user. Have you ever seen this and if so, is there something I can do to stop this from happening?

Thanks,

Lonnie Nelson

*This post is locked for comments

I have the same question (0)
  • Rona Santos Profile Picture
    30 on at

    Hi Lonnie,

    I am experiencing the same problem.  I'm just wondering if you were able to find a fix for this.  We are currently running GP ver 8.0.

    Thanks,

    Rona Santos

  • L Vail Profile Picture
    65,271 on at

    Hi Lonnie,

    Strange indeed.

    Do the Master Numbers seem alright? Not out of sequence or duplicated?

    Leslie

  • Richard Wheeler Profile Picture
    75,848 Moderator on at

    How old is your GP installation? There was a problem many moons ago when occasionally when a user would start a new order, it did not properly get the next order number so the user would think they are entering lines on one order but GP was assigning a different order number. This happened very rarely and the code was corrected to fix that. It there any chance of upgrading your GP? We had actually gotten a patch for that. I may still have it lying around.

  • Community Member Profile Picture
    on at

    It's very rare with latest versions of GP. As Leslie Vail pointed out, you may want to check the Master Number not being duplicated. Also, check your SOP Next Number setup. It could possibly not working as it's suppose to be. One other point is to check whether you have any customization / addon running at the time of creating an SOP order. Even a simplest customization/addon can mess up the next number process, if not written properly.

  • Rona Santos Profile Picture
    30 on at

    Hi Richard,

    Appreciate if you could send me the patch if you still have it.  We also had a problem with the Master Number being duplicated prior to getting this new issu.

  • Suggested answer
    Richard Whaley Profile Picture
    25,195 on at

    We duplicated this once.

    Person 1 enters a new order.  After putting in several new lines, save the order but do not close the Sales Transaction Entry window or start working on another order.

    Person 2 enters a new order.  Lines get tied to the order created by Person 1.

    Try this at your firm to see if you can reproduce the problem.  Then tell people when they save an order to immediately open another one or close the STE screen

  • Richard Wheeler Profile Picture
    75,848 Moderator on at

    This script goes way back so please have a backup in place before running it. It basically tries to correct the next master number.

    /****** Object:  Stored Procedure dbo.sopGetMasterNumber    Script Date: 1/14/97 8:46:29 PM ******/

    if exists (select * from sysobjects where id = object_id('dbo.sopGetMasterNumber') and sysstat & 0xf = 4)

    drop procedure dbo.sopGetMasterNumber

    GO

    create procedure dbo.sopGetMasterNumber

           @O_iOUTMasterNumber                   int             = NULL  output,

           @O_iErrorState                        int             = NULL  output

    as      

    /*

    **********************************************************************************************************

    * (c) 1994 Great Plains Software, Inc.

    **********************************************************************************************************

    *

    * PROCEDURE NAME:      sopGetMasterNumber

    *

    * SANSCRIPT NAME:      Get_Master_Number of form SOP_Entry

    *

    * PARAMETERS:

    * @O_iOUTMasterNumber Retreived Master Number

    * @O_iErrorState contains any errors that occur in this procedure

    *

    * DESCRIPTION:

    *   Returns the next number field from the given SOP_SETP record and increments

    * the next number.

    *

    * Customization was made to look at SOP40500 to verify the NXTMSTNO is larger than existing values.

    *

    * TABLES:

    *              Table Name                      Access

    *              =========                       =====

    * SOP40100 Read/Write

    *

    * DATABASE:    

    *              Company

    *

    *

    * RETURN VALUE:

    *

    *      0 = Successful

    *     non-0 = Not successful

    *

    * REVISION HISTORY:

    *

    *      Date           Who             Comments

    *      ------------- --------        -------------------------------------------------

    * 24Jun98 msluke Initial Creation

    *****************************************************************************

    */

    declare @tTransaction           tinyint,

    @iError int,

    @MaxMSTRNUMB int

    /*

    * Initialize variables and Output Parameters.

    */

    select @O_iOUTMasterNumber = 0,

    @O_iErrorState  = 0

    /*

    * Start a transaction if the trancount is 0.

    */

    if @@trancount = 0

    begin

           select @tTransaction = 1

           begin transaction

    end

    /*

    * Read record from SOP_SETP table within an update statement so a lock is held

    * on the record until the number is updated. This will ensure that only a single

    * user is reading this record at any given time.

    */

    update

    SOP40100  WITH (TABLOCKX,HOLDLOCK)

    set

    @O_iOUTMasterNumber = NXTMSTNO,

    NXTMSTNO= NXTMSTNO + 1

    if ( @@rowcount <> 1)

    begin

    /* Failed writing to SOP40100. */

    select          @O_iErrorState                  = 21035 /* Failed writing to SOP40100 */

    end

    /*

    * Do an additional read from SOP40500 to attempt to recover from the situation where the NXTMSTNO

    * is less than or equal to the max value in SOP40500.  

    */

    select @MaxMSTRNUMB = max(MSTRNUMB) from SOP40500 (nolock)

    if (@MaxMSTRNUMB >= @O_iOUTMasterNumber)

    begin

    update

    SOP40100

    set

    @O_iOUTMasterNumber = @MaxMSTRNUMB + 1,

    NXTMSTNO= @MaxMSTRNUMB + 2

    if ( @@rowcount <> 1)

    begin

    /* Failed writing to SOP40100. */

    select          @O_iErrorState                  = 21035 /* Failed writing to SOP40100 */

    end

    end

    /*

    *  Reset next master number to 2, if master number has reached max value

    *  or it is zero.

    */

    if (( @O_iOUTMasterNumber = 99999999) or ( @O_iOUTMasterNumber = 0)) and @O_iErrorState = 0

    begin

    select   @O_iOUTMasterNumber = 1

    update

    SOP40100

    set

    NXTMSTNO = 2

    if ( @@rowcount <> 1)

    begin

    /* Failed writing to SOP40100. */

    select          @O_iErrorState                  = 21035 /* Failed writing to SOP40100 */

    end

    end

    /*

    * Determine if a rollback or commit should be executed.

    */

    if @O_iErrorState <> 0

    begin

           select           @O_iOUTMasterNumber    = 0

           /*

            * Rollback the transaction if this procedure started it.

            */

           if @tTransaction = 1

                   rollback transaction

    end

    else

    begin

           /*

            *  Commit the transaction if this procedure started it.

            */

            if @tTransaction = 1

                   commit transaction

    end

    return

    GO

    GRANT  EXECUTE  ON dbo.sopGetMasterNumber  TO DYNGRP

    GO

Under review

Thank you for your reply! To ensure a great experience for everyone, your content is awaiting approval by our Community Managers. Please check back later.

Helpful resources

Quick Links

Responsible AI policies

As AI tools become more common, we’re introducing a Responsible AI Use…

Neeraj Kumar – Community Spotlight

We are honored to recognize Neeraj Kumar as our Community Spotlight honoree for…

Leaderboard > 🔒一 Microsoft Dynamics GP (Archived)

#1
mtabor Profile Picture

mtabor 1

Last 30 days Overall leaderboard

Featured topics

Product updates

Dynamics 365 release plans