ADODB Command (Stored Procedure)

Collapse
This topic is closed.
X
X
 
  • Time
  • Show
Clear All
new posts
  • Ben

    ADODB Command (Stored Procedure)

    Hi!

    I already sent this to the ACCESS newsgroup. But since I do not know really
    which side is really causing the problem, I have decided to send this
    inquiry
    to this newsgroup also, if I may.

    Below is the environment of the application:
    a. MS Access 2003 application running on Windows XP
    b. SQL Server 2000 - backend running MS Server 2003 OS

    Below is the code that is giving me an error:

    Dim com As ADODB.Command

    Set com = New ADODB.Command

    With com
    .ActiveConnecti on = "DSN=YES2;DATAB ASE=YES100SQLC; "
    .CommandText = "sp_Recalculate "
    .CommandType = adCmdStoredProc
    .Parameters.Ref resh
    .Parameters("@I temNumber") = ItemNum
    .Execute ' This is where it hangs up...

    TotalItems = .Parameters("@T otalInStock")
    TotalCost = .Parameters("@T otalCost")

    End With

    Set com = Nothing

    and the store procedure is:

    CREATE PROCEDURE DBO.sp_Recalcul ate
    @ItemNumber nvarchar(50),
    @TotalInStock int = 0,
    @TotalCost money = 0
    AS

    BEGIN
    SET @TotalInStock = (
    SELECT Sum([Quantity in Stock])
    FROM [Inventory Products]
    WHERE [Item Number] = @ItemNumber)

    SET @TotalCost = (
    SELECT Sum([Cost] * [Quantity in Stock])
    FROM [Inventory Products]
    WHERE [Item Number] = @ItemNumber)

    END


    When the process goes to the ".Execute" line, it hangs up for a long time
    then gives me an error message "Everflow". I have been trying to solve
    this issue but do not have an idea for now of the cause.

    Below is my finding:
    a. When I run the stored procedure in the SQL analyzer, it works just fine.
    I placed a SELECT statement to view the result of the stored procedure.
    It gives the correct values.

    Can anyone have ideas or similar problems?

    Thanks.


  • Erland Sommarskog

    #2
    Re: ADODB Command (Stored Procedure)

    Ben (pillars4@sbcgl obal.net) writes:
    .Execute ' This is where it hangs up...
    >
    TotalItems = .Parameters("@T otalInStock")
    TotalCost = .Parameters("@T otalCost")
    >
    End With
    >
    Set com = Nothing
    >
    and the store procedure is:
    >
    CREATE PROCEDURE DBO.sp_Recalcul ate
    Do not use the sp_ prefix in your procedures. This prefix is reserved
    for system procedures, and SQL Server will first look for these in master.
    I don't think this explains why your process hangs, but I nevertheless
    wanted to point it out.
    @ItemNumber nvarchar(50),
    @TotalInStock int = 0,
    @TotalCost money = 0
    AS
    Judging from the code, the parameters @TotalInStock and @TotalCost
    should be declared as OUTPUT. Right now your procedure is only a no-op.

    Also, I can't see in you code that you create these parameters when you
    call the procedure. You need to do that; you cannot just refer the
    parameters after the call.
    BEGIN
    SET @TotalInStock = (
    SELECT Sum([Quantity in Stock])
    FROM [Inventory Products]
    WHERE [Item Number] = @ItemNumber)
    >
    SET @TotalCost = (
    SELECT Sum([Cost] * [Quantity in Stock])
    FROM [Inventory Products]
    WHERE [Item Number] = @ItemNumber)
    >
    END
    Rewrite as

    SELECT @TotalInStock = Sum([Quantity in Stock]),
    @TotalCost = Sum([Cost] * [Quantity in Stock])
    FROM [Inventory Products]
    WHERE [Item Number] = @ItemNumber

    That will slash the execution time in half.
    When the process goes to the ".Execute" line, it hangs up for a long time
    then gives me an error message "Everflow". I have been trying to solve
    this issue but do not have an idea for now of the cause.
    I guess you mean "Overflow"? That sounds like VB message to me, which
    would indicate that you are using the wrong data type for TotalItems.
    (Check that you did not mistakenly declare it as Integer.) Then again,
    it does not seem that you would get anything back from the procedure
    at all. But maybe that is the problem? You get some unintialised junk?
    Below is my finding:
    a. When I run the stored procedure in the SQL analyzer, it works just
    fine.
    And it completes in how long time?




    --
    Erland Sommarskog, SQL Server MVP, esquel@sommarsk og.se

    Books Online for SQL Server 2005 at

    Books Online for SQL Server 2000 at

    Comment

    • Ben

      #3
      Re: ADODB Command (Stored Procedure)

      I timed the execution: 1 minute. Then it gives me the overflow error.

      I double checked the code especially the declarations, and they seem to
      okay. The "TotalItems " var in the calling method uses "long" as its data
      type. The "@TotalInSt ock" OUTPUT var in the stored procedure is declared as
      "int". They seem to be okay.

      Is there an issue between the number of open connections to the database?


      "Erland Sommarskog" <esquel@sommars kog.sewrote in message
      news:Xns9945EF2 273D83Yazorman@ 127.0.0.1...
      Ben (pillars4@sbcgl obal.net) writes:
      > .Execute ' This is where it hangs up...
      >>
      > TotalItems = .Parameters("@T otalInStock")
      > TotalCost = .Parameters("@T otalCost")
      >>
      > End With
      >>
      > Set com = Nothing
      >>
      >and the store procedure is:
      >>
      >CREATE PROCEDURE DBO.sp_Recalcul ate
      >
      Do not use the sp_ prefix in your procedures. This prefix is reserved
      for system procedures, and SQL Server will first look for these in master.
      I don't think this explains why your process hangs, but I nevertheless
      wanted to point it out.
      >
      > @ItemNumber nvarchar(50),
      > @TotalInStock int = 0,
      > @TotalCost money = 0
      >AS
      >
      Judging from the code, the parameters @TotalInStock and @TotalCost
      should be declared as OUTPUT. Right now your procedure is only a no-op.
      >
      Also, I can't see in you code that you create these parameters when you
      call the procedure. You need to do that; you cannot just refer the
      parameters after the call.
      >
      >BEGIN
      > SET @TotalInStock = (
      > SELECT Sum([Quantity in Stock])
      > FROM [Inventory Products]
      > WHERE [Item Number] = @ItemNumber)
      >>
      > SET @TotalCost = (
      > SELECT Sum([Cost] * [Quantity in Stock])
      > FROM [Inventory Products]
      > WHERE [Item Number] = @ItemNumber)
      >>
      >END
      >
      Rewrite as
      >
      SELECT @TotalInStock = Sum([Quantity in Stock]),
      @TotalCost = Sum([Cost] * [Quantity in Stock])
      FROM [Inventory Products]
      WHERE [Item Number] = @ItemNumber
      >
      That will slash the execution time in half.
      >
      >When the process goes to the ".Execute" line, it hangs up for a long time
      >then gives me an error message "Everflow". I have been trying to solve
      >this issue but do not have an idea for now of the cause.
      >
      I guess you mean "Overflow"? That sounds like VB message to me, which
      would indicate that you are using the wrong data type for TotalItems.
      (Check that you did not mistakenly declare it as Integer.) Then again,
      it does not seem that you would get anything back from the procedure
      at all. But maybe that is the problem? You get some unintialised junk?
      >
      >Below is my finding:
      >a. When I run the stored procedure in the SQL analyzer, it works just
      >fine.
      >
      And it completes in how long time?
      >
      >
      >
      >
      --
      Erland Sommarskog, SQL Server MVP, esquel@sommarsk og.se
      >
      Books Online for SQL Server 2005 at

      Books Online for SQL Server 2000 at
      http://www.microsoft.com/sql/prodinf...ons/books.mspx

      Comment

      • Erland Sommarskog

        #4
        Re: ADODB Command (Stored Procedure)

        Ben (pillars4@sbcgl obal.net) writes:
        I timed the execution: 1 minute. Then it gives me the overflow error.
        Does it run for one minute in QA as well?
        I double checked the code especially the declarations, and they seem to
        okay. The "TotalItems " var in the calling method uses "long" as its
        data type. The "@TotalInSt ock" OUTPUT var in the stored procedure is
        declared as "int". They seem to be okay.
        And the data type for TotalCost is?
        Is there an issue between the number of open connections to the database?
        No, that has nothing to do with it.

        There were a couple of more issues with your code that I pointed out,
        but you did not comment these. The code you posted will not work for
        reasons I've already detailed.

        It may be that you did not post the actual code, but just scribbled down a
        sketch and introduced a few errors along the way. But in that case, I don't
        know what you are doing, so I cannot say more than I've already said.


        --
        Erland Sommarskog, SQL Server MVP, esquel@sommarsk og.se

        Books Online for SQL Server 2005 at

        Books Online for SQL Server 2000 at

        Comment

        • Ben

          #5
          Re: ADODB Command (Stored Procedure)

          I made th necessary changes. Below are the current scripts for both the
          calling method and the
          store procedure. Variable "ItemNum" is being passed as a string parameter to
          the recalculate
          method.


          '************** ************** This is the script in the calling method
          *************** **********
          Dim TotalCost As Currency, TotalItems As Long, AvgCost As Currency
          Dim CurDB As Database, Inv As Recordset, InvP As Recordset, SQLStmt As
          String, SQLStmt2 As String

          Dim com As ADODB.Command

          Set com = New ADODB.Command

          With com
          .ActiveConnecti on = "DSN=YES2;DATAB ASE=YES100SQLC; "
          .CommandText = "sp_Recalculate "
          .CommandType = adCmdStoredProc
          .Parameters.Ref resh
          .Parameters("@I temNumber") = ItemNum
          .Execute

          TotalItems = .Parameters("@T otalInStock")
          TotalCost = .Parameters("@T otalCost")
          End With

          Set com = Nothing

          =============== =============== =============== =============== ====

          '************** ************* This is the current script in the stored
          procedure *************** ****
          CREATE PROCEDURE DBO.sp_Recalcul ate
          @ItemNumber nvarchar(50),
          @TotalInStock int = 0 OUTPUT,
          @TotalCost money = 0 OUTPUT
          AS
          SELECT @TotalInStock = Sum([Quantity in Stock]),
          @TotalCost = Sum([Cost] * [Quantity in Stock])
          FROM [Inventory Products]
          WHERE [Item Number] = @ItemNumber
          GO




          "Erland Sommarskog" <esquel@sommars kog.sewrote in message
          news:Xns994667A 846B71Yazorman@ 127.0.0.1...
          Ben (pillars4@sbcgl obal.net) writes:
          >I timed the execution: 1 minute. Then it gives me the overflow error.
          >
          Does it run for one minute in QA as well?
          >
          >I double checked the code especially the declarations, and they seem to
          >okay. The "TotalItems " var in the calling method uses "long" as its
          >data type. The "@TotalInSt ock" OUTPUT var in the stored procedure is
          >declared as "int". They seem to be okay.
          >
          And the data type for TotalCost is?
          >
          >Is there an issue between the number of open connections to the database?
          >
          No, that has nothing to do with it.
          >
          There were a couple of more issues with your code that I pointed out,
          but you did not comment these. The code you posted will not work for
          reasons I've already detailed.
          >
          It may be that you did not post the actual code, but just scribbled down a
          sketch and introduced a few errors along the way. But in that case, I
          don't
          know what you are doing, so I cannot say more than I've already said.
          >
          >
          --
          Erland Sommarskog, SQL Server MVP, esquel@sommarsk og.se
          >
          Books Online for SQL Server 2005 at

          Books Online for SQL Server 2000 at
          http://www.microsoft.com/sql/prodinf...ons/books.mspx

          Comment

          • Ben

            #6
            Re: ADODB Command (Stored Procedure)

            I also changed the stored procedure name to "procRecalculat e".


            "Erland Sommarskog" <esquel@sommars kog.sewrote in message
            news:Xns994667A 846B71Yazorman@ 127.0.0.1...
            Ben (pillars4@sbcgl obal.net) writes:
            >I timed the execution: 1 minute. Then it gives me the overflow error.
            >
            Does it run for one minute in QA as well?
            >
            >I double checked the code especially the declarations, and they seem to
            >okay. The "TotalItems " var in the calling method uses "long" as its
            >data type. The "@TotalInSt ock" OUTPUT var in the stored procedure is
            >declared as "int". They seem to be okay.
            >
            And the data type for TotalCost is?
            >
            >Is there an issue between the number of open connections to the database?
            >
            No, that has nothing to do with it.
            >
            There were a couple of more issues with your code that I pointed out,
            but you did not comment these. The code you posted will not work for
            reasons I've already detailed.
            >
            It may be that you did not post the actual code, but just scribbled down a
            sketch and introduced a few errors along the way. But in that case, I
            don't
            know what you are doing, so I cannot say more than I've already said.
            >
            >
            --
            Erland Sommarskog, SQL Server MVP, esquel@sommarsk og.se
            >
            Books Online for SQL Server 2005 at

            Books Online for SQL Server 2000 at
            http://www.microsoft.com/sql/prodinf...ons/books.mspx

            Comment

            • Erland Sommarskog

              #7
              Re: ADODB Command (Stored Procedure)

              Ben (pillars4@sbcgl obal.net) writes:
              I made th necessary changes. Below are the current scripts for both the
              calling method and the store procedure. Variable "ItemNum" is being
              passed as a string parameter to the recalculate method.
              Do you still get the overflow error, or does it work alright now?



              --
              Erland Sommarskog, SQL Server MVP, esquel@sommarsk og.se

              Books Online for SQL Server 2005 at

              Books Online for SQL Server 2000 at

              Comment

              • Ben

                #8
                Re: ADODB Command (Stored Procedure)

                This is the current scripts of the application:

                Dim com As ADODB.Command
                Dim MyItemNumber As String, MyTotalInStock As Long, MyTotalCost As
                Currency

                Set com = New ADODB.Command

                MyItemNumber = ItemNum
                MyTotalInStock = 0
                MyTotalCost = 0

                With com
                .ActiveConnecti on = "DSN=YES2;DATAB ASE=YES100SQLC; "
                .CommandText = "procRecalculat e"
                .CommandType = adCmdStoredProc

                .Parameters.App end .CreateParamete r("ItemNumber ", adVarChar,
                adParamInput, MyItemNumber)
                .Parameters.App end .CreateParamete r("TotalInStock ", adInteger,
                adParamOutput, MyTotalInStock)
                .Parameters.App end .CreateParamete r("TotalCost" , adCurrency,
                adParamOutput, MyTotalCost)
                .Execute

                End With

                Set com = Nothing

                If IsNull(MyTotalI nStock) Then MyTotalInStock = 0
                If IsNull(MyTotalC ost) Then MyTotalCost = 0

                TotalItems = MyTotalInStock
                TotalCost = MyTotalCost

                =============== =============== ===============
                CREATE PROCEDURE DBO.procRecalcu late
                @ItemNumber nvarchar(50),
                @TotalInStock int = 0 OUTPUT,
                @TotalCost money = 0 OUTPUT
                AS
                SET NOCOUNT ON

                SELECT @TotalInStock = Sum(Cast([Quantity in Stock] As int)),
                @TotalCost = Sum(Cast([Cost] * [Quantity in Stock] As money))
                FROM [Inventory Products]
                WHERE [Item Number] = @ItemNumber

                SET NOCOUNT OFF
                GO

                Unfortunately, I still get the same error. But this time, I get it in a
                second.




                "Erland Sommarskog" <esquel@sommars kog.sewrote in message
                news:Xns9946E6B 747AD9Yazorman@ 127.0.0.1...
                Ben (pillars4@sbcgl obal.net) writes:
                >I made th necessary changes. Below are the current scripts for both the
                >calling method and the store procedure. Variable "ItemNum" is being
                >passed as a string parameter to the recalculate method.
                >
                Do you still get the overflow error, or does it work alright now?
                >
                >
                >
                --
                Erland Sommarskog, SQL Server MVP, esquel@sommarsk og.se
                >
                Books Online for SQL Server 2005 at

                Books Online for SQL Server 2000 at
                http://www.microsoft.com/sql/prodinf...ons/books.mspx

                Comment

                • Erland Sommarskog

                  #9
                  Re: ADODB Command (Stored Procedure)

                  Ben (pillars4@sbcgl obal.net) writes:
                  This is the current scripts of the application:
                  >...
                  .Parameters.App end .CreateParamete r("ItemNumber ", adVarChar,
                  >adParamInput , MyItemNumber)
                  .Parameters.App end .CreateParamete r("TotalInStock ", adInteger,
                  adParamOutput, MyTotalInStock)
                  .Parameters.App end .CreateParamete r("TotalCost" , adCurrency,
                  adParamOutput, MyTotalCost)
                  Here is an error: .CreateParamete r takes five parameter of which the
                  fourth is the size, and the fifth is the value. Thus you need to insert
                  an extra comma after adParamInput, adParamOutput.
                  Unfortunately, I still get the same error. But this time, I get it in a
                  second.
                  Well, at least some progress. :-)
                  --
                  Erland Sommarskog, SQL Server MVP, esquel@sommarsk og.se

                  Books Online for SQL Server 2005 at

                  Books Online for SQL Server 2000 at

                  Comment

                  Working...