MYOB Exo Business Views & Stored Procedures
List of procedures
Procedure details
Procedure: ADD_EXTENDED_PROPERTY_TO_VIEW
NameADD_EXTENDED_PROPERTY_TO_VIEW
Note
Code/**
Properties for columns are returned in view VW_FACT_OBJ. Cube = a cube view e.g VW_FACT_SALES

SQL Property Name VW_FACT_OBJ Content Example for Cube column ACCNAME_BRANCH
MS_Description EDESCRIPTION Friendly Name DebtorAccountNameBranch
EXO_Class ECLASS Cube Class Lookup (other classes = Dimension & Measure)
EXO_Hive EHIVE Cube Class Hive (groups entities together by source level e.g. PLU)
EXO_LUobj ELUOBJ Lookup Table DR_ACCS
EXO_LUcol ELUCOL LU Match Column NAME
EXO_LUkey ELUKEY LU Return Column ACCNO
EXO_LUfact ELUFACT Cube Match Column ACCNO_BRANCH
(computed) ELUSQL Clause for WHERE ACCNO_BRANCH IN (SELECT ACCNO FROM DR_ACCS WHERE NAME LIKE '')

Lookups are used in interface to translate filters to primary key columns in form
   IN (SELECT FROM WHERE LIKE '')

**/

CREATE PROCEDURE [dbo].[ADD_EXTENDED_PROPERTY_TO_VIEW]
  (@SYSOBJECT VARCHAR(MAX), @SYSCOLUMN VARCHAR(MAX),
   @DESCRIPTION VARCHAR(256) = NULL, @EXOCLASS VARCHAR(256) = NULL, @EXOHIVE VARCHAR(256) = NULL,
   @LOOKUPOBJ VARCHAR(256) = NULL, @LOOKUPCOL VARCHAR(256) = NULL,
   @LOOKUPKEY VARCHAR(256) = NULL, @LOOKUPFACT VARCHAR(256) = NULL)
  AS
  BEGIN
  DECLARE @EXTCOUNT INT
  /** Stored procedure for adding properties to view **/

/** Primary properties **/

  -- Test valid input
  IF (LEN(ISNULL(@SYSOBJECT, ''))=0 OR LEN(ISNULL(@SYSCOLUMN, ''))=0)
      RETURN
  -- See if colum exists
  IF 0=(select count(*)
        from syscolumns sf
        left outer join sysobjects so on so.id = sf.id
        where sf.name = @SYSCOLUMN and so.name = @SYSOBJECT)
     RETURN;

-- MS_Description = Friendly Name
IF (@DESCRIPTION IS NOT NULL AND @DESCRIPTION <> '*')
BEGIN
  WITH
  CTE_EXTRAPROP
  AS
  (SELECT major_id, minor_id, t.name AS ViewName, c.name AS ColumnName,
          ep.name as ExtendedProperty, ep.value AS ExtendedValue
   FROM sys.extended_properties AS ep
   INNER JOIN sys.views AS t ON ep.major_id = t.object_id
   INNER JOIN sys.columns AS c ON ep.major_id = c.object_id AND ep.minor_id = c.column_id
   WHERE class = 1
  ) SELECT @EXTCOUNT= COUNT(major_id)
    FROM CTE_EXTRAPROP
    WHERE ViewName =@SYSOBJECT AND ColumnName = @SYSCOLUMN AND ExtendedProperty = 'MS_Description'
  IF @EXTCOUNT =0
    EXEC sp_addextendedproperty @name = N'MS_Description',
         @level0type = N'Schema', @level0name = 'dbo', @level1type = N'View', @level2type = N'Column',
        @level1name = @SYSOBJECT, @level2name = @SYSCOLUMN, @value = @DESCRIPTION;
  ELSE
    EXEC sp_updateextendedproperty @name = N'MS_Description',
         @level0type = N'Schema', @level0name = 'dbo', @level1type = N'View', @level2type = N'Column',
         @level1name = @SYSOBJECT, @level2name = @SYSCOLUMN, @value = @DESCRIPTION;
END

-- EXO_Class = Cube Class Lookup (other classes = Dimension & Measure)
IF (@EXOCLASS IS NOT NULL AND @EXOCLASS <> '*')
BEGIN
  WITH
  CTE_EXTRAPROP
  AS
  (SELECT major_id, minor_id, t.name AS ViewName, c.name AS ColumnName,
          ep.name as ExtendedProperty, ep.value AS ExtendedValue
   FROM sys.extended_properties AS ep
   INNER JOIN sys.views AS t ON ep.major_id = t.object_id
   INNER JOIN sys.columns AS c ON ep.major_id = c.object_id AND ep.minor_id = c.column_id
   WHERE class = 1
  ) SELECT @EXTCOUNT= COUNT(major_id)
    FROM CTE_EXTRAPROP
    WHERE ViewName =@SYSOBJECT AND ColumnName = @SYSCOLUMN AND ExtendedProperty = 'EXO_Class'
  IF @EXTCOUNT =0
    EXEC sp_addextendedproperty @name = N'EXO_Class',
         @level0type = N'Schema', @level0name = 'dbo', @level1type = N'View', @level2type = N'Column',
        @level1name = @SYSOBJECT, @level2name = @SYSCOLUMN, @value = @EXOCLASS;
  ELSE
    EXEC sp_updateextendedproperty @name = N'EXO_Class',
         @level0type = N'Schema', @level0name = 'dbo', @level1type = N'View', @level2type = N'Column',
         @level1name = @SYSOBJECT, @level2name = @SYSCOLUMN, @value = @EXOCLASS;
END

-- EXO_Hive = Cube Hive (groups entities together by source level e.g. PLU)
IF @EXOCLASS = 'Lookup' AND (@EXOHIVE IS NULL OR @EXOHIVE ='*') SET @EXOHIVE = @LOOKUPFACT;
IF (@EXOHIVE IS NOT NULL AND @EXOHIVE <> '*')
BEGIN
IF @EXOHIVE = '!' SET @EXOHIVE = @SYSCOLUMN;
  WITH
  CTE_EXTRAPROP
  AS
  (SELECT major_id, minor_id, t.name AS ViewName, c.name AS ColumnName,
          ep.name as ExtendedProperty, ep.value AS ExtendedValue
   FROM sys.extended_properties AS ep
   INNER JOIN sys.views AS t ON ep.major_id = t.object_id
   INNER JOIN sys.columns AS c ON ep.major_id = c.object_id AND ep.minor_id = c.column_id
   WHERE class = 1
  ) SELECT @EXTCOUNT= COUNT(major_id)
    FROM CTE_EXTRAPROP
    WHERE ViewName =@SYSOBJECT AND ColumnName = @SYSCOLUMN AND ExtendedProperty = 'EXO_Hive'
  IF @EXTCOUNT =0
    EXEC sp_addextendedproperty @name = N'EXO_Hive',
         @level0type = N'Schema', @level0name = 'dbo', @level1type = N'View', @level2type = N'Column',
         @level1name = @SYSOBJECT, @level2name = @SYSCOLUMN, @value = @EXOHIVE;
  ELSE
    EXEC sp_updateextendedproperty @name = N'EXO_Hive',
         @level0type = N'Schema', @level0name = 'dbo', @level1type = N'View', @level2type = N'Column',
         @level1name = @SYSOBJECT, @level2name = @SYSCOLUMN, @value = @EXOHIVE;
END

/** Lookup properties **/

  -- Test valid input
  IF (LEN(ISNULL(@LOOKUPOBJ, ''))=0 OR LEN(ISNULL(@LOOKUPCOL, ''))=0
      OR LEN(ISNULL(@LOOKUPKEY, ''))=0 OR LEN(ISNULL(@LOOKUPFACT, ''))=0)
      RETURN

  -- See if lookup table/view exists
  IF 0=(select count(*) from sysobjects so
        where so.name = @LOOKUPOBJ)
     RETURN;
  -- See if lookup match colum exists
  IF 0=(select count(*)
        from syscolumns sf
        left outer join sysobjects so on so.id = sf.id
        where sf.name = @LOOKUPCOL and so.name = @LOOKUPOBJ)
     RETURN;
  -- See if lookup return colum exists
  IF 0=(select count(*)
        from syscolumns sf
        left outer join sysobjects so on so.id = sf.id
        where sf.name = @LOOKUPKEY and so.name = @LOOKUPOBJ)
     RETURN;
  -- See if cube view colum exists
  IF 0=(select count(*)
        from syscolumns sf
        left outer join sysobjects so on so.id = sf.id
        where sf.name = @LOOKUPFACT and so.name = @SYSOBJECT)
     RETURN;

-- EXO_LUobj = Lookup Table or View **/
  WITH
  CTE_EXTRAPROP
  AS
  (SELECT major_id, minor_id, t.name AS ViewName, c.name AS ColumnName,
          ep.name as ExtendedProperty, ep.value AS ExtendedValue
   FROM sys.extended_properties AS ep
   INNER JOIN sys.views AS t ON ep.major_id = t.object_id
   INNER JOIN sys.columns AS c ON ep.major_id = c.object_id AND ep.minor_id = c.column_id
   WHERE class = 1
  ) SELECT @EXTCOUNT= COUNT(major_id)
    FROM CTE_EXTRAPROP
    WHERE ViewName =@SYSOBJECT AND ColumnName = @SYSCOLUMN AND ExtendedProperty = 'EXO_LUobj'
  IF @EXTCOUNT =0
    EXEC sp_addextendedproperty @name = N'EXO_LUobj',
         @level0type = N'Schema', @level0name = 'dbo', @level1type = N'View', @level2type = N'Column',
        @level1name = @SYSOBJECT, @level2name = @SYSCOLUMN, @value = @LOOKUPOBJ;
  ELSE
    EXEC sp_updateextendedproperty @name = N'EXO_LUobj',
         @level0type = N'Schema', @level0name = 'dbo', @level1type = N'View', @level2type = N'Column',
         @level1name = @SYSOBJECT, @level2name = @SYSCOLUMN, @value = @LOOKUPOBJ;
-- EXO_LUcol = Lookup Match Column **/
  WITH
  CTE_EXTRAPROP
  AS
  (SELECT major_id, minor_id, t.name AS ViewName, c.name AS ColumnName,
          ep.name as ExtendedProperty, ep.value AS ExtendedValue
   FROM sys.extended_properties AS ep
   INNER JOIN sys.views AS t ON ep.major_id = t.object_id
   INNER JOIN sys.columns AS c ON ep.major_id = c.object_id AND ep.minor_id = c.column_id
   WHERE class = 1
  ) SELECT @EXTCOUNT= COUNT(major_id)
    FROM CTE_EXTRAPROP
    WHERE ViewName =@SYSOBJECT AND ColumnName = @SYSCOLUMN AND ExtendedProperty = 'EXO_LUcol'
  IF @EXTCOUNT =0
    EXEC sp_addextendedproperty @name = N'EXO_LUcol',
         @level0type = N'Schema', @level0name = 'dbo', @level1type = N'View', @level2type = N'Column',
        @level1name = @SYSOBJECT, @level2name = @SYSCOLUMN, @value = @LOOKUPCOL;
  ELSE
    EXEC sp_updateextendedproperty @name = N'EXO_LUcol',
         @level0type = N'Schema', @level0name = 'dbo', @level1type = N'View', @level2type = N'Column',
         @level1name = @SYSOBJECT, @level2name = @SYSCOLUMN, @value = @LOOKUPCOL;
-- EXO_LUkey =Lookup Return Column
  WITH
  CTE_EXTRAPROP
  AS
  (SELECT major_id, minor_id, t.name AS ViewName, c.name AS ColumnName,
          ep.name as ExtendedProperty, ep.value AS ExtendedValue
   FROM sys.extended_properties AS ep
   INNER JOIN sys.views AS t ON ep.major_id = t.object_id
   INNER JOIN sys.columns AS c ON ep.major_id = c.object_id AND ep.minor_id = c.column_id
   WHERE class = 1
  ) SELECT @EXTCOUNT= COUNT(major_id)
    FROM CTE_EXTRAPROP
    WHERE ViewName =@SYSOBJECT AND ColumnName = @SYSCOLUMN AND ExtendedProperty = 'EXO_LUkey'
  IF @EXTCOUNT =0
    EXEC sp_addextendedproperty @name = N'EXO_LUkey',
         @level0type = N'Schema', @level0name = 'dbo', @level1type = N'View', @level2type = N'Column',
        @level1name = @SYSOBJECT, @level2name = @SYSCOLUMN, @value = @LOOKUPKEY;
  ELSE
    EXEC sp_updateextendedproperty @name = N'EXO_LUkey',
         @level0type = N'Schema', @level0name = 'dbo', @level1type = N'View', @level2type = N'Column',
         @level1name = @SYSOBJECT, @level2name = @SYSCOLUMN, @value = @LOOKUPKEY;
-- EXO_LUfact = Cube Match Column **/
  WITH
  CTE_EXTRAPROP
  AS
  (SELECT major_id, minor_id, t.name AS ViewName, c.name AS ColumnName,
          ep.name as ExtendedProperty, ep.value AS ExtendedValue
   FROM sys.extended_properties AS ep
   INNER JOIN sys.views AS t ON ep.major_id = t.object_id
   INNER JOIN sys.columns AS c ON ep.major_id = c.object_id AND ep.minor_id = c.column_id
   WHERE class = 1
  ) SELECT @EXTCOUNT= COUNT(major_id)
    FROM CTE_EXTRAPROP
    WHERE ViewName =@SYSOBJECT AND ColumnName = @SYSCOLUMN AND ExtendedProperty = 'EXO_LUfact'
  IF @EXTCOUNT =0
    EXEC sp_addextendedproperty @name = N'EXO_LUfact',
         @level0type = N'Schema', @level0name = 'dbo', @level1type = N'View', @level2type = N'Column',
        @level1name = @SYSOBJECT, @level2name = @SYSCOLUMN, @value = @LOOKUPFACT;
  ELSE
    EXEC sp_updateextendedproperty @name = N'EXO_LUfact',
         @level0type = N'Schema', @level0name = 'dbo', @level1type = N'View', @level2type = N'Column',
         @level1name = @SYSOBJECT, @level2name = @SYSCOLUMN, @value = @LOOKUPFACT;



END


Procedure: ALLOC_DR_TO_OLDEST
NameALLOC_DR_TO_OLDEST
Note
CodeCREATE PROCEDURE [dbo].[ALLOC_DR_TO_OLDEST]
  @ACCNO INTEGER
AS
  DECLARE @NEG_SEQNO INTEGER
  DECLARE @NEG_TOALLOC FLOAT
BEGIN
  SET NOCOUNT ON

  /* ALLOCATE DEBTOR'S UNALLOCATED NEGATIVE TRANSACTIONS (ALLOW ZEROES) TO OLDEST POSITIVE TRANSACTIONS */
  DECLARE DR_TRANS_CURSOR CURSOR LOCAL
    FOR SELECT SEQNO, AMOUNT-ALLOCATEDBAL
    FROM DR_TRANS
    WHERE ACCNO=@ACCNO AND ALLOCATED='0' AND AMOUNT<=0
    AND (PAY_STATUS<>1 OR PAY_STATUS IS NULL)
    ORDER BY TRANSDATE, SEQNO
  OPEN DR_TRANS_CURSOR
  FETCH NEXT FROM DR_TRANS_CURSOR
    INTO @NEG_SEQNO, @NEG_TOALLOC

  WHILE @@FETCH_STATUS=0
  BEGIN
    EXECUTE ALLOC_DR_TRANS_TO_OLDEST @ACCNO, @NEG_SEQNO, @NEG_TOALLOC

    FETCH NEXT FROM DR_TRANS_CURSOR
      INTO @NEG_SEQNO, @NEG_TOALLOC
  END
  CLOSE DR_TRANS_CURSOR
  DEALLOCATE DR_TRANS_CURSOR

  SET NOCOUNT OFF
END


Procedure: ALLOC_DR_TRANS_TO_OLDEST
NameALLOC_DR_TRANS_TO_OLDEST
Note
CodeCREATE PROCEDURE [dbo].[ALLOC_DR_TRANS_TO_OLDEST]
  @ACCNO INTEGER,
  @NEG_SEQNO INTEGER,
  @NEG_TOALLOC FLOAT
AS
  DECLARE @ALLOCNO INTEGER
  DECLARE @ALLOCSEQ INTEGER
  DECLARE @CURRENCYNO INTEGER
  DECLARE @NEG_OUT FLOAT
  DECLARE @NEG_OUT_ISZERO CHAR(1)
  DECLARE @NEG_TOALLOC_ISZERO CHAR(1)
  DECLARE @NEG_ALLOC FLOAT
  DECLARE @REMAINING_TOALLOC FLOAT
  DECLARE @REMAINING_TOALLOC_ISZERO CHAR(1)
  DECLARE @POS_DATE DATETIME
  DECLARE @POS_SEQNO INTEGER
  DECLARE @POS_OUT FLOAT
  DECLARE @POS_OUT_ISZERO CHAR(1)
  DECLARE @POS_ALLOC FLOAT
  DECLARE @PERIOD_SEQNO INT
BEGIN
  SET NOCOUNT ON

  /* ALLOCATE SPECIFIED NEGATIVE TRANSACTION (PAYMENT) AMOUNT TO OLDEST POSITIVE TRANSACTIONS (INVOICES) */

  /* INITIALISE VARIABLES*/
  SET @ALLOCNO=0
  SET @ALLOCSEQ=0
  SET @CURRENCYNO=0
  SET @NEG_ALLOC=0
  SELECT @PERIOD_SEQNO = SEQNO FROM PERIOD_STATUS WHERE AGE = 0 AND LEDGER = 'D'

  /* VALIDATE NEGATIVE TRANSACTION */
  /* GET OUTSTANDING AMOUNT */
  SELECT @NEG_OUT=AMOUNT-ALLOCATEDBAL
    FROM DR_TRANS
    WHERE SEQNO=@NEG_SEQNO

  /* IF NO AMOUNT OUTSTANDING, SET TO FULLY ALLOCATED AND EXIT */
  EXECUTE ISZERO_FLOAT @NEG_OUT, 'Y', @NEG_OUT_ISZERO OUTPUT
  IF (@NEG_OUT_ISZERO='Y')
  BEGIN
    UPDATE DR_TRANS
      SET ALLOCATED='1'
      WHERE SEQNO=@NEG_SEQNO
    RETURN
  END
  /* EXIT IF AMOUNT OUTSTANDING IS POSITIVE */
  ELSE IF (@NEG_OUT>0)
    RETURN

  /* EXIT IF TRYING TO ALLOCATE A POSITIVE/ZERO AMOUNT (WHEN KNOW THERE IS A NEGATIVE OUTSTANDING AMOUNT) */
  EXECUTE ISZERO_FLOAT @NEG_TOALLOC, 'Y', @NEG_TOALLOC_ISZERO OUTPUT
  IF (@NEG_TOALLOC_ISZERO='Y')
    RETURN
  ELSE IF (@NEG_TOALLOC>0)
    RETURN
  /* IF TRYING TO ALLOCATE MORE THAN AMOUNT OUTSTANDING, SET AMOUNT TO ALLOCATE EQUAL TO AMOUNT OUTSTANDING */
  ELSE IF (@NEG_TOALLOC<@NEG_OUT)
    SET @NEG_TOALLOC=@NEG_OUT

  /* LOOP WHILE THERE IS STILL AN AMOUNT TO ALLOCATE AGAINST A POSITIVE TRANSACTION */
  WHILE (@NEG_TOALLOC_ISZERO<>'Y')
  BEGIN
    /* FIND THE OLDEST POSITIVE TRANSACTION AND IT'S AMOUNT OUTSTANDING */
    SELECT @POS_DATE=MIN(TRANSDATE)
      FROM DR_TRANS
      WHERE ACCNO=@ACCNO AND ALLOCATED='0' AND AMOUNT>=0
      AND (PAY_STATUS<>1 OR PAY_STATUS IS NULL)

    SELECT @POS_SEQNO=MIN(SEQNO)
      FROM DR_TRANS
      WHERE ACCNO=@ACCNO AND ALLOCATED='0' AND AMOUNT>=0
      AND (PAY_STATUS<>1 OR PAY_STATUS IS NULL)
      AND TRANSDATE=@POS_DATE

    /* GET OUTSTANDING AMOUNT */
    SELECT @POS_OUT=AMOUNT-ALLOCATEDBAL
      FROM DR_TRANS
      WHERE SEQNO=@POS_SEQNO

    /* LOOK AT ALLOCATING AGAINST THE POSITIVE TRANSACTION FOUND */
    IF (@POS_SEQNO IS NOT NULL)
    BEGIN
      /* FULLY ALLOCATE POSITIVE TRANSACTION DUE AMOUNT WITH (MORE THAN) SUFFICIENT AMOUNT TO ALLOCATE */
      SET @REMAINING_TOALLOC=@NEG_TOALLOC+@POS_OUT
      EXECUTE ISZERO_FLOAT @REMAINING_TOALLOC, 'Y', @REMAINING_TOALLOC_ISZERO OUTPUT
      IF ((@REMAINING_TOALLOC<0) OR (@REMAINING_TOALLOC_ISZERO='Y'))
        SET @POS_ALLOC=@POS_OUT
      /* PART ALLOCATE POSITIVE TRANSACTION DUE AMOUNT WITH REMAINING AMOUNT TO ALLOCATE */
      ELSE
        SET @POS_ALLOC=-@NEG_TOALLOC
      SET @NEG_ALLOC=@NEG_ALLOC-@POS_ALLOC
      SET @NEG_TOALLOC=@NEG_TOALLOC+@POS_ALLOC
      EXECUTE ISZERO_FLOAT @NEG_TOALLOC, 'Y', @NEG_TOALLOC_ISZERO OUTPUT

      /* UPDATE POSITIVE TRANSACTION'S ALLOCATION INFORMATION */
      /* UPDATE ALLOCATEDBAL AMOUNT */
      UPDATE DR_TRANS
        SET ALLOCATEDBAL=ALLOCATEDBAL+@POS_ALLOC
        WHERE SEQNO=@POS_SEQNO

      /* GET OUTSTANDING AMOUNT */
      SELECT @POS_OUT=AMOUNT-ALLOCATEDBAL
        FROM DR_TRANS
        WHERE SEQNO=@POS_SEQNO

      /* IF NO AMOUNT OUTSTANDING, SET TO FULLY ALLOCATED */
      EXECUTE ISZERO_FLOAT @POS_OUT, 'Y', @POS_OUT_ISZERO OUTPUT
      IF (@POS_OUT_ISZERO='Y')
        UPDATE DR_TRANS
          SET ALLOCATED='1'
          WHERE SEQNO=@POS_SEQNO

      /* INSERT ALLOCATION RECORD */
      IF (@ALLOCNO=0)
      BEGIN
        EXECUTE GEN_ID 'DR_ALLOCATIONS', 'ALLOCNO', 'Y', @ALLOCNO OUTPUT
        SELECT @CURRENCYNO=CURRENCYNO FROM DR_ACCS WHERE ACCNO=@ACCNO
      END
      SET @ALLOCSEQ=@ALLOCSEQ+1
      INSERT INTO DR_ALLOCATIONS (SEQNO, ALLOCNO, TRANS_SEQNO, AMOUNT, CURRENCY, TAKENUP, ALLOCTIME
    , PERIOD_SEQNO
)
        VALUES (@ALLOCSEQ, @ALLOCNO, @POS_SEQNO, @POS_ALLOC, @CURRENCYNO, 'N', GETDATE()
    , @PERIOD_SEQNO
)
    END
    /* FORCE EXIT OF LOOP IF NO MORE POSITIVE TRANSACTIONS FOUND TO ALLOCATE AGAINST */
    ELSE
    BEGIN
      SET @NEG_TOALLOC=0
      SET @NEG_TOALLOC_ISZERO='Y'
    END
  END

  /* UPDATE NEGATIVE TRANSACTION'S ALLOCATION INFORMATION, IF ANY ALLOCATION MADE AGAINST IT */
  IF (@ALLOCNO>0)
  BEGIN
    /* UPDATE ALLOCATEDBAL AMOUNT */
    UPDATE DR_TRANS
      SET ALLOCATEDBAL=ALLOCATEDBAL+@NEG_ALLOC
      WHERE SEQNO=@NEG_SEQNO

    /* GET OUTSTANDING AMOUNT */
    SELECT @NEG_OUT=AMOUNT-ALLOCATEDBAL
      FROM DR_TRANS
      WHERE SEQNO=@NEG_SEQNO

    /* IF NO AMOUNT OUTSTANDING, SET TO FULLY ALLOCATED */
    EXECUTE ISZERO_FLOAT @NEG_OUT, 'Y', @NEG_OUT_ISZERO OUTPUT
    IF (@NEG_OUT_ISZERO='Y')
      UPDATE DR_TRANS
        SET ALLOCATED='1'
        WHERE SEQNO=@NEG_SEQNO

    /* INSERT ALLOCATION RECORD */
    SET @ALLOCSEQ=@ALLOCSEQ+1
    INSERT INTO DR_ALLOCATIONS (SEQNO, ALLOCNO, TRANS_SEQNO, AMOUNT, CURRENCY, TAKENUP, ALLOCTIME
    , PERIOD_SEQNO
)
      VALUES (@ALLOCSEQ, @ALLOCNO, @NEG_SEQNO, @NEG_ALLOC, @CURRENCYNO, 'N', GETDATE()
    , @PERIOD_SEQNO
)
  END

  SET NOCOUNT OFF
END


Procedure: AVG_DEBTOR_DAYS_TO_PAY_METRIC
NameAVG_DEBTOR_DAYS_TO_PAY_METRIC
Note
CodeCREATE PROCEDURE [dbo].[AVG_DEBTOR_DAYS_TO_PAY_METRIC]
  @METRIC_RESULT DECIMAL OUT
AS
BEGIN
  SELECT @METRIC_RESULT = AVG(
    CASE
WHEN (T.ALLOCATED = 0 AND PAY_STATUS <> 1) OR A.SEQNO IS NULL THEN
DATEDIFF(DD, T.TRANSDATE, GETDATE())
ELSE
        DATEDIFF(DD, T.TRANSDATE, A.ALLOCTIME)
  END)
  FROM DR_TRANS T
LEFT OUTER JOIN DR_ALLOCATIONS A ON T.SEQNO = A.TRANS_SEQNO
  WHERE T.TRANSTYPE = 1 AND DATEDIFF(M, T.TRANSDATE, GETDATE()) <= 12 -- Last 12 months --

  RETURN 1
END


Procedure: base64_encode
Namebase64_encode
Note
CodeCREATE FUNCTION [dbo].[base64_encode]
(
    @value varchar(max)
)
RETURNS varchar(max)
AS
BEGIN
    DECLARE @source varbinary(max) = convert(varbinary(max), @value)
    RETURN cast('' as xml).value('xs:base64Binary(sql:variable("@source"))', 'varchar(max)')
END


Procedure: BEST_PRICE
NameBEST_PRICE
Note
CodeCREATE PROCEDURE [dbo].[BEST_PRICE]
  @STOCKCODE VARCHAR(23),
  @ACCNO INTEGER,
  @QTY FLOAT,
  @TRANSDATE DATETIME,
  @BEST_FLAG CHAR(1),
  @JOBNO INT=-1,
  @MASTER_JOBNO INT=-1,
  @BEST_INT1 INT=-1,
  @BEST_INT2 INT=-1,
  @BEST_VAR1 VARCHAR(50)='',
  @BEST_PRICE FLOAT=NULL OUTPUT,
  @DISCOUNT_AMOUNT FLOAT=NULL OUTPUT,
  @IS_SPECIAL_PRICE CHAR(1)=NULL OUTPUT,
  @POLICY_HDR INTEGER=NULL OUTPUT,
  @FREIGHT_FREE CHAR(1)=NULL OUTPUT,
  @FIXEDPOLICY CHAR(1)='N' OUTPUT
AS
  DECLARE @STANDARDPRICE FLOAT
  DECLARE @SPECIALPRICE FLOAT
  DECLARE @ACCGROUP INTEGER
  DECLARE @PRICEGROUP INTEGER
  DECLARE @PRICENO INTEGER
  DECLARE @STOCKGROUP INTEGER
  DECLARE @BEST_PRICE_STOCK_GROUP INTEGER
  DECLARE @LOCATION INTEGER
  DECLARE @COMPUTERPROFILEID INTEGER
  DECLARE @IS_DISCOUNTABLE CHAR(1)
  DECLARE @QUERY NVARCHAR(500)
  DECLARE @ParmDefinition NVARCHAR(500)
BEGIN
  SELECT
    @PRICEGROUP=STOCKPRICEGROUP, @STOCKGROUP=STOCKGROUP, @IS_DISCOUNTABLE=IS_DISCOUNTABLE
  FROM STOCK_ITEMS
  WHERE STOCKCODE=@STOCKCODE

  SELECT @ACCGROUP=PRICEGROUP, @PRICENO=PRICENO, @FREIGHT_FREE=FREIGHT_FREE
  FROM DR_ACCS
  WHERE ACCNO=@ACCNO

  --Dr_prices.Stockpricegroup stores stockgroup/pricegroup based on profile
  EXECUTE GET_PROFILE_VALUE_INT 'BEST_PRICE_STOCK_GROUP', @BEST_PRICE_STOCK_GROUP OUTPUT
  IF (@BEST_PRICE_STOCK_GROUP = 0)
   SET @PRICEGROUP = @STOCKGROUP

SELECT @PRICENO = ISNULL(
(SELECT MAX(SELL_PRICE_BANDNO)
  FROM DR_PRICES D
  LEFT JOIN DR_PRICE_POLICY P ON D.POLICY_HDR = P.POLICY_HDR
  LEFT JOIN DR_PRICE_POLICY_ACC DA ON D.POLICY_HDR = DA.POLICY_HDR
  WHERE (
(SELL_PRICE_BANDNO <> -1) AND
(STARTDATE <= @TRANSDATE AND STOPDATE >= @TRANSDATE) AND
(MINQTY = 0 OR MINQTY <= @QTY) AND
(ISNULL(P.IS_ACTIVE, 'Y') = 'Y')
) AND
(
(((@ACCNO = DA.ACCNO OR @ACCGROUP = DA.ACCGROUP) AND (@STOCKCODE = STOCKCODE OR @PRICEGROUP = STOCKPRICEGROUP )) AND D.POLICY_HDR IS NOT NULL)
  OR
((@ACCNO = D.ACCNO AND (@STOCKCODE = STOCKCODE OR @PRICEGROUP = STOCKPRICEGROUP )) AND D.POLICY_HDR IS NULL))
)
, @PRICENO)
  SET @QUERY = N'SELECT @STANDARDPRICEOUT = SELLPRICE' + CONVERT(VARCHAR, @PRICENO) +
  ' FROM STOCK_ITEMS WHERE STOCKCODE = ' + CHAR(39) + @STOCKCODE + CHAR(39)
  SET @PARMDEFINITION = N'@LEVEL INT, @STANDARDPRICEOUT FLOAT OUTPUT'
  EXECUTE SP_EXECUTESQL @QUERY, @PARMDEFINITION, @LEVEL = @PRICENO, @STANDARDPRICEOUT=@STANDARDPRICE OUTPUT
  SET @IS_SPECIAL_PRICE = 'N'
  SET @BEST_PRICE = @STANDARDPRICE
  IF (@BEST_FLAG = 'Y') OR (@BEST_FLAG = 'S')
  BEGIN
    IF (@PRICEGROUP IS NULL)
      SET @PRICEGROUP = -1
    EXECUTE SPECIAL_PRICE @ACCNO, @ACCGROUP, @STOCKCODE, @PRICEGROUP, @QTY, @TRANSDATE, @STANDARDPRICE, @IS_DISCOUNTABLE,
      @JOBNO, @MASTER_JOBNO, @BEST_INT1, @BEST_INT2, @BEST_VAR1,
      @BEST_PRICE OUTPUT, @DISCOUNT_AMOUNT OUTPUT, @POLICY_HDR OUTPUT, @FREIGHT_FREE OUTPUT, @FIXEDPOLICY OUTPUT
    IF @BEST_PRICE IS NULL OR ((ISNULL(@BEST_PRICE, 0) > @STANDARDPRICE) AND (ISNULL(@FIXEDPOLICY, 'N') = 'N'))
      SET @BEST_PRICE = @STANDARDPRICE
    IF (@DISCOUNT_AMOUNT IS NOT NULL) AND (@IS_DISCOUNTABLE='Y')
      SET @BEST_PRICE = @STANDARDPRICE
    ELSE
      SET @IS_SPECIAL_PRICE = 'Y'
  END
  IF (@BEST_FLAG <> 'S')
  BEGIN
  SELECT
    @BEST_PRICE BEST_PRICE,
    @DISCOUNT_AMOUNT DISCOUNT_AMOUNT,
    @IS_SPECIAL_PRICE IS_SPECIAL_PRICE,
    @POLICY_HDR POLICY_HDR,
    @FREIGHT_FREE FREIGHT_FREE,
    @FIXEDPOLICY FIXEDPOLICY
  END
END


Procedure: CalculateAssetDepreciation
NameCalculateAssetDepreciation
Note
CodeCREATE PROCEDURE [dbo].[CalculateAssetDepreciation]
@AssetNo int,
@DepreciationDate datetime
AS
BEGIN
SET NOCOUNT ON

declare @OldBookDate datetime
declare @OldBookVal Float;
--// Most recent value in database. Use for display and diminishing value calculation
declare @StartBookVal Float;
-- Starting value for straight line dpreciation. Either the purchase price or if revalued the reval_value
declare @OldTaxDate datetime;
declare @OldTaxVal Float;
declare @StartTaxVal Float;
-- Starting value for straight line dpreciation. Either the purchase price or if revalued the reval_value
declare @NewBookVal Float;
declare @NewTaxVal Float;
declare @CurrBookVal Float;
declare @CurrTaxVal Float;
declare @DEPAMT Float, @NEWVAL float, @DEPTAXAMT float

declare @START_DATE datetime,
@START_VALUE float,
@COM_DATE datetime,
@DEP_DATE datetime,
@DEPRATETAX float,
@DEPVALUE float,
@DEPRATEACC float,
@DEPTYPE int,
@TAXDEPTYPE int,
@YR1_BOOKVAL float,
@YR1_TAXVAL float,
@DEPTAXVALUE float,
@REVAL_VALUE float,
@REVAL_DATE datetime,
@CURRENT_YR_DEP_START_BOOK datetime,
@CURRENT_YR_DEP_START_TAX datetime

--- GetStartVals

declare ASSET_REG_CURSOR cursor for
SELECT
START_VALUE,
COM_DATE,
START_DATE,
DEP_DATE,
DEPRATETAX,
DEPVALUE,
DEPRATEACC,
DEPTYPE,
TAXDEPTYPE,
YR1_BOOKVAL,
YR1_TAXVAL,
DEPTAXVALUE,
REVAL_VALUE,
REVAL_DATE,
CURRENT_YR_DEP_START_BOOK,
CURRENT_YR_DEP_START_TAX
from ASSET_REG
where Assetno = @AssetNo

OPEN ASSET_REG_CURSOR

fetch next from ASSET_REG_CURSOR into
@START_VALUE,
@COM_DATE,
@START_DATE,
@DEP_DATE,
@DEPRATETAX,
@DEPVALUE,
@DEPRATEACC,
@DEPTYPE,
@TAXDEPTYPE,
@YR1_BOOKVAL,
@YR1_TAXVAL,
@DEPTAXVALUE,
@REVAL_VALUE,
@REVAL_DATE,
@CURRENT_YR_DEP_START_BOOK,
@CURRENT_YR_DEP_START_TAX

IF @@FETCH_STATUS = 0
BEGIN
SELECT
@OldBookDate = @COM_DATE,
@OldBookVal = @START_VALUE,
@OldTaxDate = @COM_DATE,
@OldTaxVal = @START_VALUE,
@StartTaxVal = @START_VALUE

IF not ((@REVAL_VALUE IS NULL) or (@REVAL_VALUE = 0))
SET @StartBookVal = @REVAL_VALUE
ELSE
SET @StartBookVal = @START_VALUE


IF @CURRENT_YR_DEP_START_BOOK >= @OldBookDate
BEGIN
SELECT
@OldBookDate = @CURRENT_YR_DEP_START_BOOK,
@OldBookVal = @YR1_BOOKVAL
END

IF @CURRENT_YR_DEP_START_TAX >= @OldTaxDate
BEGIN
SELECT
@OldTaxDate = @CURRENT_YR_DEP_START_TAX,
@OldTaxVal = @YR1_TAXVAL
END

-- EDD believe that when a revalue happens on the same day as end of year or commsion value
-- that revalue value takes priority.
-- if revalue then end of year should be 0 dep so oldbookvalue = revalue = year end value
-- if year end then revalue then oldbookval = revalue

IF @REVAL_DATE >= @OldBookDate
BEGIN
SELECT
@OldBookDate = @REVAL_DATE,
@OldBookVal = @REVAL_VALUE
END
SET @CurrBookVal = @OldBookVal;
SET @CurrTaxVal = @OldTaxVal;

-- EDD
-- if dep date = reval date then depvalue = revalue ok
-- if dep date = year end date then depvalue = year end value ok
-- if dep date = com date then depvalue <> com date so should use depvalue ok
IF @DEP_DATE >= @OldBookDate
SET @CurrBookVal = @DEPVALUE

IF @DEP_DATE >= @OldTaxDate
SET @CurrTaxVal = @DEPTAXVALUE

-- decrease book and tax start date as the commision date is taken from the start of the day and includes that day
IF @OldBookDate = @COM_DATE
BEGIN
-- only if taken from commision date
SET @OldBookDate = DATEADD(dd, -1, @OldBookDate)
SET @OldTaxDate = DATEADD(dd, -1, @OldTaxDate);
END;

--- Calculate Depreciation

IF @DEPTYPE = 1 -- Diminishing val
SET @NewBookVal = ROUND(@OldBookVal - ((@OldBookVal * @DEPRATEACC / 100 / 365) * DateDiff(dd, @OldBookDate, @DepreciationDate)), 2)
ELSE
SET @NewBookVal = ROUND(@OldBookVal - ((@StartBookVal * @DEPRATEACC / 100 / 365) * DateDiff(dd, @OldBookDate, @DepreciationDate)), 2)

IF (@TAXDEPTYPE = 1) -- Diminishing val
SET @NewTaxVal = ROUND(@OldTaxVal - ((@OldTaxVal * @DEPRATETAX / 100 / 365) * DateDiff(dd, @OldTaxDate, @DepreciationDate)), 2)
ELSE
SET @NewTaxVal = ROUND(@OldTaxVal - ((@StartTaxVal * @DEPRATETAX / 100 / 365) * DateDiff(dd, @OldTaxDate, @DepreciationDate)), 2)

if not (@NewBookVal > 0)
begin
SET @NEWVAL = 0;
SET @DEPAMT = @CurrBookVal;
end
else
begin
if @NewBookVal > @OldBookVal
SET @NewBookVal = @OldBookVal;
-- This can happen if asset bought more recently than DepDate

SET @NEWVAL = @NewBookVal;
SET @DEPAMT = @CurrBookVal - @NewBookVal;
SET @DEPVALUE = @CurrBookVal;
end;

if not (@NewTaxVal > 0)
begin
SELECT
@NEWTAXVAL = 0,
@DEPTAXAMT = @CurrTaxVal,
@DEPTAXVALUE = @CurrTaxVal
end
else
begin
if @NewTaxVal > @OldTaxVal
SET @NewTaxVal = @OldTaxVal;

SET @NEWTAXVAL = @NewTaxVal;
SET @DEPTAXAMT = @CurrTaxVal - @NewTaxVal;
end;
SET @DEP_DATE = @DepreciationDate

END
CLOSE ASSET_REG_CURSOR
DEALLOCATE ASSET_REG_CURSOR

SELECT
@NewVal NewVal,
@NewTaxVal NewTaxVal,
@DEPAMT DepAmt,
@DEPTAXAMT DepTaxAmt
END


Procedure: CALCULATE_AVERAGE_COST
NameCALCULATE_AVERAGE_COST
Note
Code-- =============================================
-- Description: Stored procedure to calculate wighted average cost.
-- Input Parameters: @STOCKCODE, @BEFORE_DATE, @UPDATE_PREVIOUS_COST
-- Output Parameters: @TOTAL_STOCK, @NEW_AVG_COST
-- =============================================
CREATE PROCEDURE [dbo].[CALCULATE_AVERAGE_COST]
      -- Add the parameters for the stored procedure here
      @STOCKCODE VARCHAR(50),
      @BEFORE_DATE DATETIME,
      @UPDATE_PREVIOUS_COST CHAR(1),
      @TOTAL_STOCK FLOAT = 0 OUTPUT,
      @NEW_AVG_COST FLOAT = 0 OUTPUT
AS
BEGIN
      -- SET NOCOUNT ON added to prevent extra result sets from
      -- interfering with SELECT statements.
      SET NOCOUNT ON;

  DECLARE
      @PREVQTY FLOAT,
      @PREVAVECOST FLOAT,
      @SEQNO INTEGER,
      @QUANTITY FLOAT,
      @UNITPRICE FLOAT,
      @TRANSTYPE INTEGER,
      @AVECOSTINCLUDESCREDIT CHAR(1),
      @AVECOSTINCLUDESZERO CHAR(1),
      @FROM_WIP_LOC CHAR(1),
      @TO_WIP_LOC CHAR(1),
      @TOLOCATION INTEGER

  SET @TOTAL_STOCK = 0
  SET @NEW_AVG_COST = 0

  EXECUTE GET_PROFILE_VALUE 'AVECOSTINCLUDESCREDIT', @AVECOSTINCLUDESCREDIT OUTPUT
  EXECUTE GET_PROFILE_VALUE 'AVECOSTINCLUDESZERO', @AVECOSTINCLUDESZERO OUTPUT

  DECLARE STK_TRANS CURSOR
  FOR
  SELECT T.SEQNO, T.STOCKCODE, T.QUANTITY, T.UNITPRICE, T.TRANSTYPE, L.IS_WIPLOCATION FROM_WIP_LOC,
    ISNULL(L1.IS_WIPLOCATION, 'N') TO_WIP_LOC, T.TOLOCATION
  FROM STOCK_TRANS T
  JOIN STOCK_LOCATIONS L ON T.LOCATION = L.LOCNO
  LEFT JOIN STOCK_LOCATIONS L1 ON T.TOLOCATION = L1.LOCNO
  WHERE STOCKCODE = @STOCKCODE
    AND TRANSDATE < @BEFORE_DATE

  OPEN STK_TRANS

  FETCH NEXT FROM STK_TRANS
  INTO @SEQNO, @STOCKCODE, @QUANTITY, @UNITPRICE, @TRANSTYPE, @FROM_WIP_LOC, @TO_WIP_LOC, @TOLOCATION

  WHILE @@FETCH_STATUS = 0
  BEGIN

    SET @PREVQTY = @TOTAL_STOCK;
    SET @PREVAVECOST = @NEW_AVG_COST;
   IF @TRANSTYPE = 1
    BEGIN
      SET @NEW_AVG_COST =
        CASE
          WHEN (@AVECOSTINCLUDESCREDIT = 'N') AND (@QUANTITY < 0) THEN @NEW_AVG_COST
          WHEN (@AVECOSTINCLUDESZERO = 'N') AND (@UNITPRICE < 0) THEN @NEW_AVG_COST
          WHEN (@TOTAL_STOCK + @QUANTITY <= 0) OR (@TOTAL_STOCK <= 0) THEN @UNITPRICE
          WHEN (@TOTAL_STOCK > 0) AND (@FROM_WIP_LOC = 'Y') THEN @NEW_AVG_COST
          ELSE ((@NEW_AVG_COST * (@TOTAL_STOCK)) + (@QUANTITY * @UNITPRICE)) / (@TOTAL_STOCK + @QUANTITY)
        END
    END

    IF ((@TRANSTYPE <> 2) AND (@FROM_WIP_LOC = 'N')) OR
       ((@TRANSTYPE = 2) AND ((@TO_WIP_LOC = 'Y') AND @FROM_WIP_LOC = 'N') AND @TOLOCATION <> 0)
      SET @TOTAL_STOCK = @TOTAL_STOCK + @QUANTITY;

    IF ((@TRANSTYPE = 2) AND ((@TO_WIP_LOC = 'N') AND @FROM_WIP_LOC = 'Y') AND @TOLOCATION <> 0)
      SET @TOTAL_STOCK = @TOTAL_STOCK - @QUANTITY;

    -- Update previous cost
    IF @UPDATE_PREVIOUS_COST = 'Y'
    BEGIN
      UPDATE STOCK_TRANS
      SET PREV_AVECOST = @NEW_AVG_COST,
          PREV_QUANTITY = @PREVQTY,
          NEW_AVECOST = @NEW_AVG_COST
      WHERE SEQNO = @SEQNO
    END

    FETCH NEXT FROM STK_TRANS
    INTO @SEQNO, @STOCKCODE, @QUANTITY, @UNITPRICE, @TRANSTYPE, @FROM_WIP_LOC, @TO_WIP_LOC, @TOLOCATION
  END

  CLOSE STK_TRANS
  DEALLOCATE STK_TRANS

  -- Update Average cost on stock_items table
  UPDATE STOCK_ITEMS
  SET AVECOST = @NEW_AVG_COST
  WHERE STOCKCODE = @STOCKCODE

  -- Update latestCost and AveCost for linked stockcodes
  UPDATE SI
  SET LATESTCOST = S.LATESTCOST * SI.UPDATEITEM_QTY,
      AVECOST = S.AVECOST * SI.UPDATEITEM_QTY
  FROM STOCK_ITEMS SI
  JOIN STOCK_ITEMS S ON SI.UPDATEITEM_CODE = S.STOCKCODE
  WHERE S.STOCKCODE = @STOCKCODE

      SELECT @TOTAL_STOCK TOTAL_STOCK, @NEW_AVG_COST NEW_AVG_COST
END


Procedure: CALCULATE_GLMOVEMENTS
NameCALCULATE_GLMOVEMENTS
Note
CodeCREATE PROCEDURE [dbo].[CALCULATE_GLMOVEMENTS]
  @IN_ACCNO INT,
  @IN_SUBACCNO INT,
  @IN_BRANCHNO INT,
  @IN_COMPANYNO INT,
  @IN_PERIOD_SEQNO INT
AS
  DECLARE @ACCNO INT
  DECLARE @SUBACCNO INT
  DECLARE @BRANCHNO INT
  DECLARE @COMPANYNO INT
  DECLARE @PERIOD_SEQNO INT
  DECLARE @AMOUNT FLOAT
  DECLARE @FCAMOUNT FLOAT
  DECLARE @SEQNO INT
  DECLARE @ISNEW CHAR(1)
BEGIN
  /* Exonet created procedure from DBUpdate version [6.180] */

  SET NOCOUNT ON

  DECLARE GLTRANS_CURSOR CURSOR LOCAL FOR
    SELECT ACCNO, SUBACCNO, BRANCHNO, COMPANYNO, PERIOD_SEQNO,
    SUM(AMOUNT), SUM(FCAMOUNT) FROM GLTRANS
    WHERE ((@IN_ACCNO IS NULL) OR (ACCNO=@IN_ACCNO)) AND (ACCNO IS NOT NULL)
    AND ((@IN_SUBACCNO IS NULL) OR (SUBACCNO=@IN_SUBACCNO)) AND (SUBACCNO IS NOT NULL)
    AND ((@IN_BRANCHNO IS NULL) OR (BRANCHNO=@IN_BRANCHNO)) AND (BRANCHNO IS NOT NULL)
    AND ((@IN_COMPANYNO IS NULL) OR (COMPANYNO=@IN_COMPANYNO)) AND (COMPANYNO IS NOT NULL)
    AND ((@IN_PERIOD_SEQNO IS NULL) OR (PERIOD_SEQNO=@IN_PERIOD_SEQNO)) AND (PERIOD_SEQNO IS NOT NULL)
    GROUP BY ACCNO, SUBACCNO, BRANCHNO, COMPANYNO, PERIOD_SEQNO
    ORDER BY ACCNO, SUBACCNO, BRANCHNO, COMPANYNO, PERIOD_SEQNO
  OPEN GLTRANS_CURSOR
  FETCH NEXT FROM GLTRANS_CURSOR
    INTO @ACCNO, @SUBACCNO, @BRANCHNO, @COMPANYNO, @PERIOD_SEQNO, @AMOUNT, @FCAMOUNT
  WHILE @@FETCH_STATUS=0
  BEGIN
    EXEC GET_GLMOVEMENTS_RECORD @ACCNO, @SUBACCNO, @BRANCHNO,
      @COMPANYNO, @PERIOD_SEQNO, 'N', @SEQNO OUTPUT, @ISNEW OUTPUT
    UPDATE GLMOVEMENTS SET AMOUNT=@AMOUNT, AMOUNT_FC=@FCAMOUNT WHERE SEQNO=@SEQNO
    FETCH NEXT FROM GLTRANS_CURSOR
      INTO @ACCNO, @SUBACCNO, @BRANCHNO, @COMPANYNO, @PERIOD_SEQNO, @AMOUNT, @FCAMOUNT
  END
  CLOSE GLTRANS_CURSOR
  DEALLOCATE GLTRANS_CURSOR

  SET NOCOUNT OFF
END


Procedure: CALC_STKREQUIREMENT
NameCALC_STKREQUIREMENT
Note
CodeCREATE PROCEDURE [dbo].[CALC_STKREQUIREMENT] (@SUPPLIERNO INTEGER)
AS
BEGIN
DECLARE
@MAXFWDDAYS INT,
@USEWORKSORDS CHAR(1),
@PO_MAXFWDDAYS INT,
@WO_MAXFWDDAYS INT

  --DEAL WITH USER PROFILES
  EXECUTE GET_PROFILE_VALUE_INT 'ORDER_MAX_FWD_DAYS', @MAXFWDDAYS OUTPUT
  EXECUTE GET_PROFILE_VALUE_INT 'PO_ORDER_MAX_FWD_DAYS', @PO_MAXFWDDAYS OUTPUT
  EXECUTE GET_PROFILE_VALUE_INT 'WO_ORDER_MAX_FWD_DAYS', @WO_MAXFWDDAYS OUTPUT
  EXECUTE GET_PROFILE_VALUE 'USEWORKSORDERS', @USEWORKSORDS OUTPUT
  IF (@USEWORKSORDS IS NULL) SET @USEWORKSORDS='N'
  IF ((@MAXFWDDAYS IS NULL) OR (@MAXFWDDAYS=0)) SET @MAXFWDDAYS=90
  IF ((@PO_MAXFWDDAYS IS NULL) OR (@PO_MAXFWDDAYS=0)) SET @PO_MAXFWDDAYS=90
  IF ((@WO_MAXFWDDAYS IS NULL) OR (@WO_MAXFWDDAYS=0)) SET @WO_MAXFWDDAYS=90

  --CLEAN THE STOCKREQUIREMENT TABLE FOR SPECIFIC/ALL SUPPLIERS
  IF @SUPPLIERNO=-1
DELETE FROM STOCKREQUIREMENT;
  ELSE
DELETE FROM STOCKREQUIREMENT WHERE ACCNO =@SUPPLIERNO;

  INSERT INTO STOCKREQUIREMENT
  (STOCKCODE, LOCNO, [DESCRIPTION], ACCNO, STOCKGROUP, MINSTOCK, MAXSTOCK,
INSTOCKQTY, PURCHORDQTY, SALESORDQTY, VIRTSTOCK,
CALCREORD, ACTUALREORD, SALES0, SALES1, SALES2, SALES3, SALES4, SALES5,
    SALES6, SALES7, SALES8, SALES9, SALES10, SALES11, SALES12)
  SELECT
  STOCKCODE, LOCNO, [DESCRIPTION], ACCNO, STOCKGROUP, MINSTOCK, MAXSTOCK,
  ISINLOC, ISINCOMING, ISCOMMITTED, ISFREE,
  CALCREORD, ACTUALREORD, M0_SALES, M1_SALES , M2_SALES , M3_SALES , M4_SALES , M5_SALES ,
  M6_SALES , M7_SALES , M8_SALES , M9_SALES , M10_SALES , M11_SALES , M12_SALES
  FROM FN_STOCK_REQUIREMENT(@SUPPLIERNO, @MAXFWDDAYS, @PO_MAXFWDDAYS, @WO_MAXFWDDAYS, @USEWORKSORDS)

  UPDATE GENERAL_INFO SET STOCKCAL_LASTRUN = GETDATE()
END


Procedure: CHECK_END_OF_YEAR_ROLLED
NameCHECK_END_OF_YEAR_ROLLED
Note
CodeCREATE PROCEDURE [dbo].[CHECK_END_OF_YEAR_ROLLED]
AS
BEGIN
  DECLARE @LEDGER_SEQNO INT
  DECLARE @LEDGER_PERIOD INT
  DECLARE @LEDGER_STOPDATE DATETIME
  DECLARE @YEAR_STARTDATE DATETIME
  DECLARE @RESULT INT

  SET @RESULT = 0

  DECLARE LedgerPeriods CURSOR FOR (SELECT SEQNO, PERIOD_SEQNO FROM LEDGER_PERIODS)

  OPEN LedgerPeriods

  BEGIN TRY
FETCH NEXT FROM LedgerPeriods INTO @LEDGER_SEQNO, @LEDGER_PERIOD

SELECT @YEAR_STARTDATE = STARTDATE FROM PERIODS_DEFN WHERE SEQNO = 1

WHILE @@FETCH_STATUS = 0
BEGIN
IF (@LEDGER_SEQNO = 1)
SELECT @LEDGER_STOPDATE = MAX(STOPDATE) FROM PERIOD_STATUS WHERE LEDGER = 'D' AND PERIOD_SEQNO = @LEDGER_PERIOD
ELSE IF (@LEDGER_SEQNO = 2)
SELECT @LEDGER_STOPDATE = MAX(STOPDATE) FROM PERIOD_STATUS WHERE LEDGER = 'C' AND PERIOD_SEQNO = @LEDGER_PERIOD
ELSE IF (@LEDGER_SEQNO = 3)
SELECT @LEDGER_STOPDATE = MAX(STOPDATE) FROM PERIOD_STATUS WHERE LEDGER = 'S' AND PERIOD_SEQNO = @LEDGER_PERIOD
ELSE
SELECT @LEDGER_STOPDATE = MAX(STOPDATE) FROM PERIOD_STATUS WHERE LEDGER = 'G' AND PERIOD_SEQNO = @LEDGER_PERIOD

IF @LEDGER_STOPDATE < @YEAR_STARTDATE
SET @RESULT = 1

FETCH NEXT FROM LedgerPeriods INTO @LEDGER_SEQNO, @LEDGER_PERIOD
END
  END TRY
  BEGIN CATCH
CLOSE LedgerPeriods
DEALLOCATE LedgerPeriods

RETURN 0
  END CATCH

  CLOSE LedgerPeriods
  DEALLOCATE LedgerPeriods

  RETURN @RESULT
END


Procedure: CleanupObjectLocks
NameCleanupObjectLocks
Note
CodeCREATE PROCEDURE [dbo].[CleanupObjectLocks]
AS
BEGIN
    SET NOCOUNT ON;
    DELETE OL
    FROM OBJECT_LOCK OL
    LEFT JOIN MASTER..SYSPROCESSES SP
      ON OL.SESSIONID = SUBSTRING(RTRIM(CONVERT(VARCHAR(128), CONTEXT_INFO)), CHARINDEX('|', RTRIM(CONVERT(VARCHAR(128), CONTEXT_INFO)), CHARINDEX('|', RTRIM(CONVERT(VARCHAR(128), CONTEXT_INFO)) ) + 1) + 1, 38)
AND DBID = DB_ID() AND CONTEXT_INFO <> 0x0
        WHERE SP.spid IS NULL
        AND SESSIONID IS NOT NULL
END


Procedure: CL_DRUNALLOCTRANSCHECK
NameCL_DRUNALLOCTRANSCHECK
Note
Code--[dbo].[CL_DRUNALLOCTRANSCHECK]--
CREATE PROCEDURE [CL_DRUNALLOCTRANSCHECK]
/*
This procedure checks whether there are unallocated or partly allocated debtor transactions.
If none are found then the Debtor Aged Balances node is marked complete.
*/
@NODESTATUS INT = -1 OUTPUT,
@CONTEXTID INT = -1
AS
BEGIN
 SET NOCOUNT ON

   IF EXISTS (SELECT * FROM DR_TRANS WHERE ALLOCATED < 1 AND PERIOD_SEQNO <= @CONTEXTID) --Check for unallocated transactions

   BEGIN
SET @NODESTATUS=-1 --Unallocated transactions exist so do nothing.
END
ELSE
BEGIN
SET @NODESTATUS=2 --No unallocated transactions exist mark node completed.
END

    SELECT @NODESTATUS NODESTATUS

 SET NOCOUNT OFF
END


Procedure: CL_ENDOFYEARCHECK
NameCL_ENDOFYEARCHECK
Note
Code-- [dbo].[CL_ENDOFYEARCHECK] --
CREATE PROCEDURE [CL_ENDOFYEARCHECK]
/*
This procedure checks whether the selected context is the last period in the financial year and hides nodes accordingly.
*/
@NODESTATUS INT = -1 OUTPUT,
@CONTEXTID INT = -1
AS
DECLARE @FIELDVALUE CHAR(1)

BEGIN
 SET NOCOUNT ON

SELECT @FIELDVALUE=CASE WHEN PERIOD_SEQNO = (SELECT MAX(SEQNO) FROM PERIODS_DEFN) THEN 'Y' ELSE 'N' END
FROM PERIOD_STATUS JOIN PERIODS_DEFN ON PERIODS_DEFN.SEQNO = PERIOD_STATUS.PERIOD_SEQNO AND
PERIOD_STATUS.SEQNO = @CONTEXTID -- Check to see if @CONTEXTID is last period of year

IF ISNULL(@FIELDVALUE, 'N') = 'Y' -- If last period of the year
   BEGIN
SET @NODESTATUS=4 -- Hide the node
END
ELSE
BEGIN
SET @NODESTATUS=-1 -- Otherwise do nothing
END

    SELECT @NODESTATUS NODESTATUS

 SET NOCOUNT OFF
END


Procedure: CL_NOT_ENDOFYEARCHECK
NameCL_NOT_ENDOFYEARCHECK
Note
CodeCREATE PROCEDURE [dbo].[CL_NOT_ENDOFYEARCHECK]
/*
This procedure checks whether the selected context is the last period in the financial year.
  Hide the node if it is NOT the end of financial year.
*/
@NODESTATUS INT = -1 OUTPUT,
@CONTEXTID INT = -1
AS
DECLARE @FIELDVALUE CHAR(1)

BEGIN
 SET NOCOUNT ON

SELECT @FIELDVALUE=CASE WHEN PERIOD_SEQNO = (SELECT MAX(SEQNO) FROM PERIODS_DEFN) THEN 'Y' ELSE 'N' END
FROM PERIOD_STATUS JOIN PERIODS_DEFN ON PERIODS_DEFN.SEQNO = PERIOD_STATUS.PERIOD_SEQNO AND
PERIOD_STATUS.SEQNO = @CONTEXTID -- Check to see if @CONTEXTID is last period of year

IF ISNULL(@FIELDVALUE, 'N') = 'N' -- If NOT last period of the year
  BEGIN
    SET @NODESTATUS=4 --hide
  END
  ELSE
  BEGIN
    SET @NODESTATUS=-1 --do nothing
  END

  SELECT @NODESTATUS NODESTATUS

 SET NOCOUNT OFF
END


Procedure: CL_PERIODICSTOCKCHECK
NameCL_PERIODICSTOCKCHECK
Note
Code-- [dbo].[CL_PERIODICSTOCKCHECK] --
CREATE PROCEDURE [CL_PERIODICSTOCKCHECK]
/*
This procedure checks whether the system is set to periodic or perpetual stock and sets node status accordingly.
*/
@NODESTATUS INT = -1 OUTPUT,
@CONTEXTID INT = -1
AS
DECLARE @FIELDVALUE CHAR(1)

BEGIN
 SET NOCOUNT ON

EXEC GET_PROFILE_VALUE'LIVESTOCKTOGL', @FIELDVALUE OUTPUT -- Check stock method

IF ISNULL(@FIELDVALUE, 'N') = 'N'
   BEGIN
SET @NODESTATUS=-1 -- If periodic then do nothing
END
ELSE
BEGIN
SET @NODESTATUS=4 -- If perpetual then hide the node
END

    SELECT @NODESTATUS NODESTATUS

 SET NOCOUNT OFF
END


Procedure: CL_TAX_AUCHECK
NameCL_TAX_AUCHECK
Note
Code--[dbo].[CL_TAX_AUCHECK]--
CREATE PROCEDURE [CL_TAX_AUCHECK]
/*
This procedure checks whether the localisation is AUS and whether GST is set to payment or invoice basis.
*/
@NODESTATUS INT = -1 OUTPUT,
@CONTEXTID INT = -1
AS
DECLARE @FIELDVALUE CHAR(1),
@COUNTRY VARCHAR(3)

BEGIN
 SET NOCOUNT ON

  EXEC GET_PROFILE_VALUE'PAYMENTBASEDGST', @FIELDVALUE OUTPUT -- Check GST method
  SELECT @COUNTRY=COUNTRY FROM GENERAL_INFO -- Check country set up in company details

  IF @COUNTRY = 'AUS' -- If Australia localisation then run method checks
  BEGIN
    IF ISNULL(@FIELDVALUE, 'N') = 'Y' -- Payment basis
    BEGIN
      SET @NODESTATUS=4 -- Payment basis so hide node
    END
    ELSE
    BEGIN
      IF @NODESTATUS=4 -- If invoice basis and node already hidden
      BEGIN
        SET @NODESTATUS = 0 -- Reset node to not processed
      END
      ELSE
      BEGIN
        SET @NODESTATUS = -1 -- Otherwise do nothing
      END
    END
  END
  ELSE -- hide the node
  BEGIN
    SET @NODESTATUS = 4
  END

  SELECT @NODESTATUS NODESTATUS

 SET NOCOUNT OFF
END


Procedure: CL_TAX_METHODCHECK
NameCL_TAX_METHODCHECK
Note
Code--[dbo].[CL_TAX_METHODCHECK]--
CREATE PROCEDURE [CL_TAX_METHODCHECK]
/*
This procedure checks whether GST is set to payment or invoice basis.
*/
@NODESTATUS INT = -1 OUTPUT,
@CONTEXTID INT = -1
AS
DECLARE @FIELDVALUE CHAR(1),
@COUNTRY VARCHAR(3)

BEGIN
 SET NOCOUNT ON

  EXEC GET_PROFILE_VALUE'PAYMENTBASEDGST', @FIELDVALUE OUTPUT -- Check GST method

IF ISNULL(@FIELDVALUE, 'N') = 'Y' -- Payment basis
   BEGIN
SET @NODESTATUS=4 -- Payment basis so hide node
END
ELSE
BEGIN
IF @NODESTATUS=4 -- If invoice basis and node already hidden
BEGIN
SET @NODESTATUS = 0 -- Reset node to not processed
END
ELSE
BEGIN
SET @NODESTATUS = -1 -- Otherwise do nothing
END
END

  SELECT @NODESTATUS NODESTATUS

 SET NOCOUNT OFF
END


Procedure: CL_TAX_NZCHECK
NameCL_TAX_NZCHECK
Note
Code--[dbo].[CL_TAX_NZCHECK]--
CREATE PROCEDURE [CL_TAX_NZCHECK]
/*
This procedure checks whether the localisation is NZ and whether GST is set to payment or invoice basis.
*/
@NODESTATUS INT = -1 OUTPUT,
@CONTEXTID INT = -1
AS
DECLARE @FIELDVALUE CHAR(1),
@COUNTRY VARCHAR(3)

BEGIN
 SET NOCOUNT ON

  EXEC GET_PROFILE_VALUE'PAYMENTBASEDGST', @FIELDVALUE OUTPUT -- Check GST method
  SELECT @COUNTRY=COUNTRY FROM GENERAL_INFO -- Check country set up in company details

  IF @COUNTRY = 'NZL' -- If New Zealand localisation then run method checks
  BEGIN
    IF ISNULL(@FIELDVALUE, 'N') = 'Y' -- Payment basis
    BEGIN
      SET @NODESTATUS=4 -- Payment basis so hide node
    END
    ELSE
    BEGIN
      IF @NODESTATUS=4 -- If invoice basis and node already hidden
      BEGIN
        SET @NODESTATUS = 0 -- Reset node to not processed
      END
      ELSE
      BEGIN
        SET @NODESTATUS = -1 -- Otherwise do nothing
      END
    END
  END
  ELSE -- hide the node
  BEGIN
    SET @NODESTATUS = 4
  END

  SELECT @NODESTATUS NODESTATUS

 SET NOCOUNT OFF
END


Procedure: CL_USEFX
NameCL_USEFX
Note
CodeCREATE PROCEDURE [dbo].[CL_USEFX]
/*
This procedure checks whether 'Operate in multiple currencies' is enabled and hides the relevant checklist nodes.
*/
@NODESTATUS INT = -1 OUTPUT,
@CONTEXTID INT = -1
AS
DECLARE @FIELDVALUE CHAR(1)

BEGIN
 SET NOCOUNT ON

EXEC GET_PROFILE_VALUE'MULTICURRENCY', @FIELDVALUE OUTPUT -- Check if enabled

IF ISNULL(@FIELDVALUE, 'N') = 'N'
   BEGIN
SET @NODESTATUS=4 -- If not enabled then hide the node
END
ELSE
BEGIN
SET @NODESTATUS=-1 -- If enabled then do nothing
END

    SELECT @NODESTATUS NODESTATUS

 SET NOCOUNT OFF
END


Procedure: COPY_POLICY
NameCOPY_POLICY
Note
CodeCREATE PROCEDURE [dbo].[COPY_POLICY]
  @FROM_POLICY_HDR INTEGER,
  @TO_POLICY_HDR INTEGER
AS
BEGIN
  SELECT @FROM_POLICY_HDR FROM DR_PRICE_POLICY WHERE POLICY_HDR = @FROM_POLICY_HDR
  IF @FROM_POLICY_HDR IS NOT NULL
  BEGIN
    DECLARE @POLICY_EXISTS INTEGER
    SELECT @POLICY_EXISTS=COUNT(*) FROM DR_PRICE_POLICY WHERE POLICY_HDR = @TO_POLICY_HDR
    IF @POLICY_EXISTS <> 0
    BEGIN
      DELETE FROM DR_PRICE_POLICY WHERE POLICY_HDR = @TO_POLICY_HDR
      SET IDENTITY_INSERT DR_PRICE_POLICY ON
      INSERT INTO DR_PRICE_POLICY (
        POLICY_HDR, CUSTOMER_REF, POLICY_REF, START_DATE, END_DATE, PRICE_MODE, IS_ACTIVE, NOTES, FREIGHT_FREE, FIXED)
        SELECT @TO_POLICY_HDR, CUSTOMER_REF, POLICY_REF, START_DATE, END_DATE, PRICE_MODE, IS_ACTIVE, NOTES, FREIGHT_FREE, FIXED
        FROM DR_PRICE_POLICY WHERE POLICY_HDR = @FROM_POLICY_HDR
    END
    ELSE
    BEGIN
      DECLARE @COPY_OF VARCHAR(30)
      SET @COPY_OF = 'Copy of ' + CAST(@FROM_POLICY_HDR AS VARCHAR(20))
      SET IDENTITY_INSERT DR_PRICE_POLICY OFF
      INSERT INTO DR_PRICE_POLICY (
        CUSTOMER_REF, POLICY_REF, START_DATE, END_DATE, PRICE_MODE, IS_ACTIVE, NOTES, FREIGHT_FREE, FIXED)
        SELECT @COPY_OF, @COPY_OF, START_DATE, END_DATE, PRICE_MODE, IS_ACTIVE, NOTES, FREIGHT_FREE, FIXED
        FROM DR_PRICE_POLICY WHERE POLICY_HDR = @FROM_POLICY_HDR
      SELECT @TO_POLICY_HDR=IDENT_CURRENT('DR_PRICE_POLICY')
    END
    INSERT INTO DR_PRICES (
      ACCNO, STOCKCODE, PRICE, STARTDATE, STOPDATE, MINQTY, STOCKPRICEGROUP, POLICY_HDR, DISCOUNT, FREIGHT_FREE)
    SELECT ACCNO, STOCKCODE, PRICE, STARTDATE, STOPDATE, MINQTY, STOCKPRICEGROUP, @TO_POLICY_HDR, DISCOUNT, FREIGHT_FREE
      FROM DR_PRICES WHERE POLICY_HDR = @FROM_POLICY_HDR

    INSERT INTO DR_PRICE_POLICY_ACC (POLICY_HDR, ACCNO, ACCGROUP)
      SELECT @TO_POLICY_HDR, ACCNO, ACCGROUP FROM DR_PRICE_POLICY_ACC WHERE POLICY_HDR=@FROM_POLICY_HDR
  END
END


Procedure: CR_ACCS_BALFWD_BAL_DELTAS
NameCR_ACCS_BALFWD_BAL_DELTAS
Note
CodeCREATE PROCEDURE [dbo].[CR_ACCS_BALFWD_BAL_DELTAS]
  @ACCNO INTEGER, @TOAGEDBAL INTEGER, @AMOUNT FLOAT, @AGEDBAL0 FLOAT OUTPUT,
  @AGEDBAL1 FLOAT OUTPUT, @AGEDBAL2 FLOAT OUTPUT, @AGEDBAL3 FLOAT OUTPUT,
  @PRIOR_AGEDBAL0 FLOAT OUTPUT, @PRIOR_AGEDBAL1 FLOAT OUTPUT, @PRIOR_AGEDBAL2 FLOAT OUTPUT
AS
  DECLARE @ACC_AGEDBAL1 FLOAT
  DECLARE @ACC_AGEDBAL2 FLOAT
  DECLARE @ACC_AGEDBAL3 FLOAT
  DECLARE @ALLOC FLOAT
  DECLARE @AGE INTEGER
  DECLARE @AGEDBAL FLOAT
  DECLARE @AGEDBAL_DELTA FLOAT
BEGIN
  SET @AGEDBAL0 = 0
  SET @AGEDBAL1 = 0
  SET @AGEDBAL2 = 0
  SET @AGEDBAL3 = 0
  SET @PRIOR_AGEDBAL0 = 0
  SET @PRIOR_AGEDBAL1 = 0
  SET @PRIOR_AGEDBAL2 = 0

  IF (@TOAGEDBAL = 0)
    SET @AGEDBAL0 = @AMOUNT
  ELSE IF (@TOAGEDBAL = 1)
  BEGIN
    SET @AGEDBAL1 = @AMOUNT
    SET @PRIOR_AGEDBAL0 = @AGEDBAL1
  END
  ELSE IF (@TOAGEDBAL = 2)
  BEGIN
    SET @AGEDBAL2 = @AMOUNT
    SET @PRIOR_AGEDBAL1 = @AGEDBAL2
  END
  ELSE IF (@TOAGEDBAL = 3)
  BEGIN
    SET @AGEDBAL3 = @AMOUNT
    SET @PRIOR_AGEDBAL2 = @AGEDBAL3
  END
  ELSE /* From Oldest */
  BEGIN
    SELECT @ACC_AGEDBAL1 = AGEDBAL1, @ACC_AGEDBAL2 = AGEDBAL2, @ACC_AGEDBAL3 = AGEDBAL3
      FROM CR_ACCS WHERE ACCNO = @ACCNO

    SET @ALLOC = @AMOUNT
    SET @AGE = 3
    WHILE ((@ALLOC <> 0) AND (@AGE > 0))
    BEGIN
      SET @AGEDBAL = 0
      SET @AGEDBAL_DELTA = 0
      IF (@AGE = 1)
        SET @AGEDBAL = @ACC_AGEDBAL1
      ELSE IF (@AGE = 2)
        SET @AGEDBAL = @ACC_AGEDBAL2
      ELSE IF (@AGE = 3)
        SET @AGEDBAL = @ACC_AGEDBAL3

      IF (((@AGEDBAL < 0) AND (@ALLOC > 0)) OR ((@AGEDBAL > 0) AND (@ALLOC < 0)))
      BEGIN
        IF (((@ALLOC > 0) AND (@ALLOC > -@AGEDBAL)) OR ((@ALLOC < 0) AND (-@ALLOC > @AGEDBAL)))
        BEGIN
          SET @AGEDBAL_DELTA = -@AGEDBAL
          SET @ALLOC = @ALLOC + @AGEDBAL
        END
        ELSE
        BEGIN
          SET @AGEDBAL_DELTA = @ALLOC
          SET @ALLOC = 0
        END
      END

      IF (@AGE = 1)
      BEGIN
        SET @AGEDBAL1 = @AGEDBAL_DELTA
        SET @PRIOR_AGEDBAL0 = @AGEDBAL1
      END
      ELSE IF (@AGE = 2)
      BEGIN
        SET @AGEDBAL2 = @AGEDBAL_DELTA
        SET @PRIOR_AGEDBAL1 = @AGEDBAL2
      END
      ELSE IF (@AGE = 3)
      BEGIN
        SET @AGEDBAL3 = @AGEDBAL_DELTA
        SET @PRIOR_AGEDBAL2 = @AGEDBAL3
      END

      SET @AGE = @AGE - 1
    END

    IF (@ALLOC <> 0)
      SET @AGEDBAL0 = @ALLOC
  END
END


Procedure: DATA_VERIFICATION_ANALYSISCODE
NameDATA_VERIFICATION_ANALYSISCODE
Note
CodeCREATE PROCEDURE [dbo].[DATA_VERIFICATION_ANALYSISCODE]
    @CONFIG CHAR(10) = 'DCGIAMS$',
    @HDR_SEQNO INT = -1,
    @STANDALONE CHAR(1)= 'Y'
AS
BEGIN

  SET NOCOUNT ON

  DECLARE @OUTPUT VARCHAR(512)
  DECLARE @MCOUNT INT
  DECLARE @STARTTIME DATETIME
  DECLARE @ENDTIME DATETIME

  SET @STARTTIME = GETDATE()

  IF @CONFIG = 'Y'
  BEGIN
SET @CONFIG = 'YDCGIAMS$'
  END

  IF @CONFIG = 'N'
  BEGIN
SET @CONFIG = 'NDCGIAMS$'
  END

  IF @STANDALONE = 'Y'
  BEGIN
INSERT INTO VERIFICATION_HDR (CONFIG_FLAG, CREATED_BY, CREATEDATE )
SELECT @CONFIG, [dbo].FN_GET_STAFF_NO() , GETDATE()

SELECT @HDR_SEQNO = (SELECT MAX(SEQNO) FROM VERIFICATION_HDR)

--DATA VERIFICATION BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'MYOB EXO Business DATA VERIFICATION ' + CONVERT(VARCHAR, GETDATE()), 'TEXT'

SELECT @OUTPUT = USERNAME FROM GENERAL_INFO
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'Company Name: ' + @OUTPUT, 'TEXT'

SELECT @OUTPUT = SOFTWARE_VERSION FROM GENERAL_INFO
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'MYOB EXO Business Database Version: ' + @OUTPUT, 'TEXT'

IF CHARINDEX('L', @CONFIG) = 0
BEGIN
SELECT @OUTPUT = 'MYOB EXO Business Database configured for ' + COUNTRY_NAME FROM GENERAL_INFO G
JOIN COUNTRY C ON G.COUNTRY = C.COUNTRY_CODE
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, @OUTPUT, 'TEXT'
END

IF CHARINDEX('Y', @CONFIG) <> 0
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'Fix Imbalance is ''ON''', 'TEXT'
END
ELSE
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'Fix Imbalance is ''OFF''', 'TEXT'
END

IF CHARINDEX('N', @CONFIG) <> 0
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'MYOB VERIFICATION ''ON''', 'TEXT'
END

  END

  IF CHARINDEX('$', @CONFIG) <> 0
  BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'Checking AnalysisCodes links...', 'TEXT'

INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS, SOURCE_SEQ, LINETYPE)
SELECT @HDR_SEQNO, orphans.Reason + ' '
+ ISNULL(acs.[name], '')
+ ':' + ISNULL(ac.code, '')
+ ' --> ' + CASE
WHEN orphans.tran_type = 'D' THEN 'DR_INVLINES'
WHEN orphans.tran_type = ')' THEN 'DR_TRANS'
WHEN orphans.tran_type = 'C' THEN 'CR_INVLINES'
WHEN orphans.tran_type = '(' THEN 'CR_TRANS'
WHEN orphans.tran_type = 'S' THEN 'STOCK_TRANS'
WHEN orphans.tran_type = 'G' THEN 'GLTRANS[_ARCHIVE]'
WHEN orphans.tran_type = '7' THEN 'GL_SJLINES'
WHEN orphans.tran_type = 'P' THEN 'PURCHORD_LINES[_ARCHIVE]'
WHEN orphans.tran_type = 'L' THEN 'SALESORD_LINES[_ARCHIVE]'
WHEN orphans.tran_type = 'I' THEN 'INWARDS_GOODS_LINES'
WHEN orphans.tran_type = '$' THEN 'CASHBOOKLINE'
WHEN orphans.tran_type = 'W' THEN 'WORKSORD_LINES'
WHEN orphans.tran_type = 'u' THEN 'STAFF(users default codes)'
ELSE ''
END + ':' + CONVERT(VARCHAR, orphans.tran_seqno),
'A0001', orphans.TRAN_SEQNO, 'ERROR'
FROM (
-- Find all the link lines that have no matching lineItem:
select 'No Matching DR_INVLINES LineItem:' as Reason, * from analysis_matrix A where tran_type = 'D' and not exists (
select seqno from DR_INVLINES X where X.seqno = A.tran_seqno
) UNION (
select 'No Matching DR_TRANS Payment LineItem:' as Reason, * from analysis_matrix A where tran_type = ')' and not exists (
select seqno from DR_TRANS X where X.seqno = A.tran_seqno and X.transtype = 4
)) UNION (
select 'TransType Mismatched (NonPayment) DR_TRANS Payment LineItem:' as Reason, A.* from analysis_matrix A, DR_TRANS X
where tran_type = ')' and X.seqno = A.tran_seqno and X.transtype <> 4
) UNION (
select 'No Matching CR_INVLINES LineItem:' as Reason, * from analysis_matrix A where tran_type = 'C' and not exists (
select seqno from CR_INVLINES X where X.seqno = A.tran_seqno
)) UNION (
select 'No Matching CR_TRANS Payment LineItem:' as Reason, * from analysis_matrix A where tran_type = '(' and not exists (
select seqno from CR_TRANS X where X.seqno = A.tran_seqno and X.transtype = 4
)) UNION (
select 'TransType Mismatched (NonPayment) CR_TRANS Payment LineItem:' as Reason, A.* from analysis_matrix A, CR_TRANS X
where tran_type = '(' and X.seqno = A.tran_seqno and X.transtype <> 4
) UNION (
select 'No Matching STOCK_TRANS LineItem:' as Reason, * from analysis_matrix A where tran_type = 'S' and not exists (
select seqno from STOCK_TRANS X where X.seqno = A.tran_seqno
)) UNION (
select 'No Matching GLTRANS[_ARCHIVE] LineItem:' as Reason, * from analysis_matrix A where tran_type = 'G' and not exists (
select seqno from GLTRANS X where X.seqno = A.tran_seqno
UNION (select seqno from GLTRANS_ARCHIVE Y where Y.seqno = A.tran_seqno)
)) UNION (
select 'No Matching GL_SJLINES LineItem:' as Reason, * from analysis_matrix A where tran_type = '7' and not exists (
select seqno from GL_SJLINES X where X.seqno = A.tran_seqno
)) UNION (
select 'No Matching PURCHORD_LINES[_ARCHIVE] LineItem:' as Reason, * from analysis_matrix A where tran_type = 'P' and not exists (
select seqno from PURCHORD_LINES X where X.seqno = A.tran_seqno
UNION (select seqno from PURCHORD_LINES_ARCHIVE Y where Y.seqno = A.tran_seqno)
)) UNION (
select 'No Matching SALESORD_LINES[_ARCHIVE] LineItem:' as Reason, * from analysis_matrix A where tran_type = 'L' and not exists (
select seqno from SALESORD_LINES X where X.seqno = A.tran_seqno
UNION (select seqno from SALESORD_LINES_ARCHIVE Y where Y.seqno = A.tran_seqno)
)) UNION (
select 'No Matching INWARDS_GOODS_LINES LineItem:' as Reason, * from analysis_matrix A where tran_type = 'I' and not exists (
select seqno from INWARDS_GOODS_LINES X where X.seqno = A.tran_seqno
)) UNION (
select 'No Matching CASHBOOKLINE LineItem:' as Reason, * from analysis_matrix A where tran_type = '$' and not exists (
select seqno from CASHBOOKLINE X where X.seqno = A.tran_seqno
)) UNION (
select 'No Matching WORKSORD_LINES LineItem:' as Reason, * from analysis_matrix A where tran_type = 'W' and not exists (
select seqno from WORKSORD_LINES X where X.seqno = A.tran_seqno
)) UNION (
select 'No Matching STAFF LineItem:' as Reason, * from analysis_matrix A where tran_type = 'u' and not exists (
select staffno from STAFF X where X.staffno = A.tran_seqno
)) UNION (

-- Find all the link lines that have no matching CodeSet:
select 'No Matching CodeSet:' as Reason, * from analysis_matrix A where not exists (
select seqno from ANALYSIS X where X.seqno = A.Code_Set_seqno
and X.Code_Set_SEQNO is null
)) UNION (

-- Find all the link lines that have no matching Code:
select 'No Matching Code:' as Reason, * from analysis_matrix A where not exists (
select seqno from ANALYSIS X where X.seqno = A.Code_seqno
and X.Code_Set_SEQNO is not null
))
) orphans
LEFT JOIN ANALYSIS ac ON ac.seqno = orphans.Code_seqno AND ac.Code_Set_SEQNO is not null
LEFT JOIN ANALYSIS acs ON acs.seqno = orphans.Code_Set_seqno AND acs.Code_Set_SEQNO is null

SET @MCOUNT = @@ROWCOUNT

IF EXISTS(
SELECT [NAME] FROM SYSOBJECTS WHERE NAME = 'JOB_TRANSACTIONS'
)
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS, SOURCE_SEQ, LINETYPE)
SELECT @HDR_SEQNO, orphans.Reason + ' '
+ ISNULL(acs.[name], '')
+ ':' + ISNULL(ac.code, '')
+ ' --> ' + CASE
WHEN orphans.tran_type = 'Q' THEN 'JOBCOST_LINES'
WHEN orphans.tran_type = 'J' THEN 'JOB_TRANSACTIONS'
ELSE ''
END + ':' + CONVERT(VARCHAR, orphans.tran_seqno),
'A0001', orphans.TRAN_SEQNO, 'ERROR'
FROM (
-- Find all the link lines that have no matching lineItem:
select 'No Matching JOBCOST_LINES LineItem:' as Reason, * from analysis_matrix A where tran_type = 'Q' and not exists (
select seqno from JOBCOST_LINES X where X.seqno = A.tran_seqno
) UNION (
select 'No Matching JOB_TRANSACTIONS LineItem:' as Reason, * from analysis_matrix A where tran_type = 'J' and not exists (
select seqno from JOB_TRANSACTIONS X where X.seqno = A.tran_seqno
))
) orphans
LEFT JOIN ANALYSIS ac ON ac.seqno = orphans.Code_seqno AND ac.Code_Set_SEQNO is not null
LEFT JOIN ANALYSIS acs ON acs.seqno = orphans.Code_Set_seqno AND acs.Code_Set_SEQNO is null

SET @MCOUNT = @MCOUNT + @@ROWCOUNT
END

IF CHARINDEX('L', @CONFIG) = 0 AND @MCOUNT = 0
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'No invalid AnalysisCode links found', 'TEXT'
END
  END

  IF @STANDALONE = 'Y'
  BEGIN
    INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
    SELECT @HDR_SEQNO, 'Verification Completed '
      + LEFT(CONVERT(VARCHAR, GETDATE(), 109), 50) + ' '
      + CONVERT(VARCHAR(5), DATEDIFF(SECOND, (SELECT CREATEDATE FROM VERIFICATION_HDR WHERE SEQNO = @HDR_SEQNO), GETDATE())) + ' Seconds', 'TEXT'

SELECT MESSAGE FROM VERIFICATION_LINES WHERE HDR_SEQNO = @HDR_SEQNO
  END
  ELSE
  BEGIN
    SET @ENDTIME = GETDATE()
    INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
    SELECT @HDR_SEQNO, 'Duration for analysis codes verification: '
      + CONVERT(VARCHAR(5), DATEDIFF(SECOND, @STARTTIME, @ENDTIME)) + ' Seconds', 'TEXT'
  END

END


Procedure: DATA_VERIFICATION_CR
NameDATA_VERIFICATION_CR
Note
CodeCREATE PROCEDURE [dbo].[DATA_VERIFICATION_CR]
    @CONFIG CHAR(10) = 'DCGIAMS$',
    @HDR_SEQNO INT = -1,
    @STANDALONE CHAR(1)= 'Y',
    @STARTPERIOD INT = 0,
    @ENDPERIOD INT = 0
AS
BEGIN

  SET NOCOUNT ON

  DECLARE @OUTPUT VARCHAR(512)
  DECLARE @STARTTIME DATETIME
  DECLARE @ENDTIME DATETIME

  SET @STARTTIME = GETDATE()

  IF @CONFIG = 'Y'
  BEGIN
SET @CONFIG = 'YDCGIAMS$'
  END

  IF @CONFIG = 'N'
  BEGIN
SET @CONFIG = 'NDCGIAMS$'
  END

  IF @STANDALONE = 'Y'
  BEGIN
INSERT INTO VERIFICATION_HDR (CONFIG_FLAG, CREATED_BY, CREATEDATE )
SELECT @CONFIG, [dbo].FN_GET_STAFF_NO() , GETDATE()

SELECT @HDR_SEQNO = (SELECT MAX(SEQNO) FROM VERIFICATION_HDR)

--DATA VERIFICATION BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'MYOB EXO Business DATA VERIFICATION ' + CONVERT(VARCHAR, GETDATE()), 'TEXT'

SELECT @OUTPUT = USERNAME FROM GENERAL_INFO
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'Company Name: ' + @OUTPUT, 'TEXT'

SELECT @OUTPUT = SOFTWARE_VERSION FROM GENERAL_INFO
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'MYOB EXO Business Database Version: ' + @OUTPUT, 'TEXT'

IF CHARINDEX('L', @CONFIG) = 0
BEGIN
SELECT @OUTPUT = 'MYOB EXO Business Database configured for ' + COUNTRY_NAME FROM GENERAL_INFO G
JOIN COUNTRY C ON G.COUNTRY = C.COUNTRY_CODE
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, @OUTPUT, 'TEXT'
END

IF CHARINDEX('Y', @CONFIG) <> 0
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'Fix Imbalance is ''ON''', 'TEXT'
END
ELSE
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'Fix Imbalance is ''OFF''', 'TEXT'
END

IF CHARINDEX('N', @CONFIG) <> 0
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'MYOB VERIFICATION ''ON''', 'TEXT'
END
  END

  IF CHARINDEX('C', @CONFIG) <> 0
  BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'Verify Tax Rates on Creditors', 'TEXT'

IF EXISTS (
SELECT A.ACCNO FROM CR_ACCS A
LEFT JOIN TAX_RATES R ON A.TAXSTATUS = R.SEQNO
LEFT JOIN TAX_KEY_POINT K ON K.COUNTRY = (SELECT COUNTRY FROM GENERAL_INFO) AND R.KEY_POINT = K.KEY_POINT
AND K.CR_LEDGER = 'Y'
WHERE A.TAXSTATUS <> -1 AND K.SEQNO IS NULL
)
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS, SOURCE_SEQ, LINETYPE)
SELECT @HDR_SEQNO, 'Creditor Account No. ' + CONVERT(VARCHAR, A.ACCNO) + ' Named: ' + A.[NAME] + ' has a Tax Status of ' + CONVERT(VARCHAR, A.TAXSTATUS)
+ ' which does not have a matching ''Creditor'' Key Point
This is an ' + CASE
WHEN A.ISACTIVE = 'Y' THEN 'ACTIVE Creditor'
ELSE 'INACTIVE Creditor'
END AS MESSAGE,
CASE
                      WHEN A.ISACTIVE = 'Y' THEN 'C0001'
                      ELSE 'C0002'
                  END AS V_CLASS, A.ACCNO, 'ERROR'
FROM CR_ACCS A
LEFT JOIN TAX_RATES R ON A.TAXSTATUS = R.SEQNO
LEFT JOIN TAX_KEY_POINT K ON K.COUNTRY = (SELECT COUNTRY FROM GENERAL_INFO) AND R.KEY_POINT = K.KEY_POINT
AND K.CR_LEDGER = 'Y'
WHERE A.TAXSTATUS <> -1 AND K.SEQNO IS NULL
ORDER BY A.ACCNO

--MYOB MIGRATION ADDED FUNCTIONALITY
IF CHARINDEX('N', @CONFIG) <> 0 AND (SELECT COUNT(NAME) FROM SYSOBJECTS WHERE NAME = 'MYOB_IMPORT_EXCEPTIONS') = 1
BEGIN
--ADD ROWS TO MYOB_IMPORT_EXCEPTIONS FOR CREDITOR ACCOUNTS WITH INCORRECT TAX RATES WITH MISSING CREDITOR KEY POINT VALUES
INSERT INTO MYOB_IMPORT_EXCEPTIONS (EXONET_TABLE_NAME, SOURCE_TYPE, DESTINATION_REF_NO, PROBLEM_COLUMN,
PROBLEM_DESCRIPTION, PROBLEM_RESOLUTION)
SELECT 'CR_ACCS', 'MYGRATE', A.ACCNO, A.[NAME], 'MISSING CREDITOR KEY POINT ON TAX RATE', 'Verify the Purchase Tax rate on the Creditor
listed'
FROM CR_ACCS A
LEFT JOIN TAX_RATES R ON A.TAXSTATUS = R.SEQNO
LEFT JOIN TAX_KEY_POINT K ON K.COUNTRY = (SELECT COUNTRY FROM GENERAL_INFO) AND R.KEY_POINT = K.KEY_POINT
AND K.CR_LEDGER = 'Y'
WHERE A.TAXSTATUS <> -1 AND K.SEQNO IS NULL
ORDER BY A.ACCNO
END
END
ELSE
BEGIN
IF CHARINDEX('L', @CONFIG) = 0
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'Creditor tax rates are VALID', 'TEXT'
END
END

--VERIFY CREDITOR PRIOR AGED BALANCE - ONLY VERIFYING IT- NOT FIXING IT
SET NOCOUNT ON

INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'Checking Creditor Prior Aged Balances', 'TEXT'
IF EXISTS(
SELECT C.NAME
FROM CR_ACCS C
LEFT JOIN (
SELECT A.ACCNO, PS.AGE, SUM(PREV_PERIOD_CLOSE) SUMPRIORAGEBAL
FROM CR_ACCS A
LEFT JOIN CR_TRANS T ON A.ACCNO = T.ACCNO
JOIN PERIOD_STATUS PS ON T.PERIOD_SEQNO=PS.SEQNO
WHERE PS.AGE = 1
GROUP BY A.ACCNO, PS.AGE
) PRIOR0 ON C.ACCNO = PRIOR0.ACCNO
LEFT JOIN (
SELECT A.ACCNO, PS.AGE, SUM(PREV_PERIOD_CLOSE) SUMPRIORAGEBAL
FROM CR_ACCS A
LEFT JOIN CR_TRANS T ON A.ACCNO = T.ACCNO
JOIN PERIOD_STATUS PS ON T.PERIOD_SEQNO=PS.SEQNO
WHERE PS.AGE = 2
GROUP BY A.ACCNO, PS.AGE
) PRIOR1 ON C.ACCNO = PRIOR1.ACCNO
LEFT JOIN (
SELECT A.ACCNO, PS.AGE, SUM(PREV_PERIOD_CLOSE) SUMPRIORAGEBAL
FROM CR_ACCS A
LEFT JOIN CR_TRANS T ON A.ACCNO = T.ACCNO
JOIN PERIOD_STATUS PS ON T.PERIOD_SEQNO=PS.SEQNO
WHERE PS.AGE = 3
GROUP BY A.ACCNO, PS.AGE
) PRIOR2 ON C.ACCNO = PRIOR2.ACCNO
LEFT JOIN (
SELECT A.ACCNO, SUM(PREV_PERIOD_CLOSE) SUMPRIORAGEBAL
FROM CR_ACCS A
LEFT JOIN CR_TRANS T ON A.ACCNO = T.ACCNO
JOIN PERIOD_STATUS PS ON T.PERIOD_SEQNO=PS.SEQNO
WHERE PS.AGE > 3
GROUP BY A.ACCNO
) PRIOR3 ON C.ACCNO = PRIOR3.ACCNO
WHERE
(ABS(ISNULL(PRIOR0.SUMPRIORAGEBAL, 0)- ISNULL(C.PRIOR_AGEDBAL0, 0))>0.009)
OR (ABS(ISNULL(PRIOR1.SUMPRIORAGEBAL, 0)- ISNULL(C.PRIOR_AGEDBAL1, 0))>0.009)
OR (ABS(ISNULL(PRIOR2.SUMPRIORAGEBAL, 0)- ISNULL(C.PRIOR_AGEDBAL2, 0))>0.009)
OR (ABS(ISNULL(PRIOR3.SUMPRIORAGEBAL, 0)- ISNULL(C.PRIOR_AGEDBAL3, 0))>0.009)
)
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS, SOURCE_SEQ, LINETYPE)
SELECT @HDR_SEQNO, MESSAGE =
'Invalid Prior Aged Bals for Creditor a/c ''' + C.NAME + ''': '
+ ' Bal0= ' + convert(varchar, convert(money, isnull(C.PRIOR_AGEDBAL0, 0))) + ' Calc0= ' + convert(varchar, convert(money, isnull(PRIOR0.SUMPRIORAGEBAL, 0)))
+ '; Bal1= ' + convert(varchar, convert(money, isnull(C.PRIOR_AGEDBAL1, 0))) + ' Calc1= ' + convert(varchar, convert(money, isnull(PRIOR1.SUMPRIORAGEBAL, 0)))
+ '; Bal2= ' + convert(varchar, convert(money, isnull(C.PRIOR_AGEDBAL2, 0))) + ' Calc2= ' + convert(varchar, convert(money, isnull(PRIOR2.SUMPRIORAGEBAL, 0)))
+ '; Bal3= ' + convert(varchar, convert(money, isnull(C.PRIOR_AGEDBAL3, 0))) + ' Calc3= ' + convert(varchar, convert(money, isnull(PRIOR3.SUMPRIORAGEBAL, 0))),
'C0003', C.ACCNO, 'ERROR'
FROM CR_ACCS C
LEFT JOIN (
SELECT A.ACCNO, PS.AGE, SUM(PREV_PERIOD_CLOSE) SUMPRIORAGEBAL
FROM CR_ACCS A
LEFT JOIN CR_TRANS T ON A.ACCNO = T.ACCNO
JOIN PERIOD_STATUS PS ON T.PERIOD_SEQNO=PS.SEQNO
WHERE PS.AGE = 1
GROUP BY A.ACCNO, PS.AGE
) PRIOR0 ON C.ACCNO = PRIOR0.ACCNO
LEFT JOIN (
SELECT A.ACCNO, PS.AGE, SUM(PREV_PERIOD_CLOSE) SUMPRIORAGEBAL
FROM CR_ACCS A
LEFT JOIN CR_TRANS T ON A.ACCNO = T.ACCNO
JOIN PERIOD_STATUS PS ON T.PERIOD_SEQNO=PS.SEQNO
WHERE PS.AGE = 2
GROUP BY A.ACCNO, PS.AGE
) PRIOR1 ON C.ACCNO = PRIOR1.ACCNO
LEFT JOIN (
SELECT A.ACCNO, PS.AGE, SUM(PREV_PERIOD_CLOSE) SUMPRIORAGEBAL
FROM CR_ACCS A
LEFT JOIN CR_TRANS T ON A.ACCNO = T.ACCNO
JOIN PERIOD_STATUS PS ON T.PERIOD_SEQNO=PS.SEQNO
WHERE PS.AGE = 3
GROUP BY A.ACCNO, PS.AGE
) PRIOR2 ON C.ACCNO = PRIOR2.ACCNO
LEFT JOIN (
SELECT A.ACCNO, SUM(PREV_PERIOD_CLOSE) SUMPRIORAGEBAL
FROM CR_ACCS A
LEFT JOIN CR_TRANS T ON A.ACCNO = T.ACCNO
JOIN PERIOD_STATUS PS ON T.PERIOD_SEQNO=PS.SEQNO
WHERE PS.AGE > 3
GROUP BY A.ACCNO
) PRIOR3 ON C.ACCNO = PRIOR3.ACCNO
WHERE
(ABS(ISNULL(PRIOR0.SUMPRIORAGEBAL, 0)- ISNULL(C.PRIOR_AGEDBAL0, 0))>0.009)
OR (ABS(ISNULL(PRIOR1.SUMPRIORAGEBAL, 0)- ISNULL(C.PRIOR_AGEDBAL1, 0))>0.009)
OR (ABS(ISNULL(PRIOR2.SUMPRIORAGEBAL, 0)- ISNULL(C.PRIOR_AGEDBAL2, 0))>0.009)
OR (ABS(ISNULL(PRIOR3.SUMPRIORAGEBAL, 0)- ISNULL(C.PRIOR_AGEDBAL3, 0))>0.009)
END
ELSE
BEGIN
IF CHARINDEX('L', @CONFIG) = 0
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'CREDITOR PRIOR BALANCES CORRECT', 'TEXT'
END
END

--VERIFY BALANCE IS CORRECT ON CR_ACCS BASED ON TRANSACTIONAL DATA
SET NOCOUNT ON
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'Checking Creditor Aged Balances', 'TEXT'
IF EXISTS(
SELECT C.NAME
FROM CR_ACCS C
LEFT JOIN (
SELECT A.ACCNO, PS.AGE, SUM(T.AMOUNT - T.ALLOCATEDBAL) SUMAGEBAL
FROM CR_ACCS A
LEFT JOIN CR_TRANS T ON A.ACCNO = T.ACCNO AND T.ALLOCATED = '0'
JOIN PERIOD_STATUS PS ON T.PERIOD_SEQNO=PS.SEQNO
WHERE PS.AGE = 0
GROUP BY A.ACCNO, PS.AGE
) AGE0 ON C.ACCNO = AGE0.ACCNO
LEFT JOIN (
SELECT A.ACCNO, PS.AGE, SUM(T.AMOUNT - T.ALLOCATEDBAL) SUMAGEBAL
FROM CR_ACCS A
LEFT JOIN CR_TRANS T ON A.ACCNO = T.ACCNO AND T.ALLOCATED = '0'
JOIN PERIOD_STATUS PS ON T.PERIOD_SEQNO=PS.SEQNO
WHERE PS.AGE = 1
GROUP BY A.ACCNO, PS.AGE
) AGE1 ON C.ACCNO = AGE1.ACCNO
LEFT JOIN (
SELECT A.ACCNO, PS.AGE, SUM(T.AMOUNT - T.ALLOCATEDBAL) SUMAGEBAL
FROM CR_ACCS A
LEFT JOIN CR_TRANS T ON A.ACCNO = T.ACCNO AND T.ALLOCATED = '0'
JOIN PERIOD_STATUS PS ON T.PERIOD_SEQNO=PS.SEQNO
WHERE PS.AGE = 2
GROUP BY A.ACCNO, PS.AGE
) AGE2 ON C.ACCNO = AGE2.ACCNO
LEFT JOIN (
SELECT A.ACCNO, SUM(T.AMOUNT - T.ALLOCATEDBAL) SUMAGEBAL
FROM CR_ACCS A
LEFT JOIN CR_TRANS T ON A.ACCNO = T.ACCNO AND T.ALLOCATED = '0'
JOIN PERIOD_STATUS PS ON T.PERIOD_SEQNO=PS.SEQNO
WHERE PS.AGE >= 3
GROUP BY A.ACCNO
) AGE3 ON C.ACCNO = AGE3.ACCNO
WHERE
(ABS(ISNULL(AGE0.SUMAGEBAL, 0)- ISNULL(C.AGEDBAL0, 0))>0.009)
OR (ABS(ISNULL(AGE1.SUMAGEBAL, 0)- ISNULL(C.AGEDBAL1, 0))>0.009)
OR (ABS(ISNULL(AGE2.SUMAGEBAL, 0)- ISNULL(C.AGEDBAL2, 0))>0.009)
OR (ABS(ISNULL(AGE3.SUMAGEBAL, 0)- ISNULL(C.AGEDBAL3, 0))>0.009)
)
BEGIN
      INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS, SOURCE_SEQ, LINETYPE)
SELECT @HDR_SEQNO, MESSAGE =
'Invalid Aged Bals for Creditor a/c ''' + C.NAME + ''': '
+ ' Bal0= ' + convert(varchar, convert(money, isnull(C.AGEDBAL0, 0))) + ' Calc0= ' + convert(varchar, convert(money, isnull(AGE0.SUMAGEBAL, 0)))
+ '; Bal1= ' + convert(varchar, convert(money, isnull(C.AGEDBAL1, 0))) + ' Calc1= ' + convert(varchar, convert(money, isnull(AGE1.SUMAGEBAL, 0)))
+ '; Bal2= ' + convert(varchar, convert(money, isnull(C.AGEDBAL2, 0))) + ' Calc2= ' + convert(varchar, convert(money, isnull(AGE2.SUMAGEBAL, 0)))
+ '; Bal3= ' + convert(varchar, convert(money, isnull(C.AGEDBAL3, 0))) + ' Calc3= '+ convert(varchar, convert(money, isnull(AGE3.SUMAGEBAL, 0))) ,
'C0004', C.ACCNO, 'ERROR'
FROM CR_ACCS C
LEFT JOIN (
SELECT A.ACCNO, PS.AGE, SUM(T.AMOUNT - T.ALLOCATEDBAL) SUMAGEBAL
FROM CR_ACCS A
LEFT JOIN CR_TRANS T ON A.ACCNO = T.ACCNO AND T.ALLOCATED = '0'
JOIN PERIOD_STATUS PS ON T.PERIOD_SEQNO=PS.SEQNO
WHERE PS.AGE = 0
GROUP BY A.ACCNO, PS.AGE
) AGE0 ON C.ACCNO = AGE0.ACCNO
LEFT JOIN (
SELECT A.ACCNO, PS.AGE, SUM(T.AMOUNT - T.ALLOCATEDBAL) SUMAGEBAL
FROM CR_ACCS A
LEFT JOIN CR_TRANS T ON A.ACCNO = T.ACCNO AND T.ALLOCATED = '0'
JOIN PERIOD_STATUS PS ON T.PERIOD_SEQNO=PS.SEQNO
WHERE PS.AGE = 1
GROUP BY A.ACCNO, PS.AGE
) AGE1 ON C.ACCNO = AGE1.ACCNO
LEFT JOIN (
SELECT A.ACCNO, PS.AGE, SUM(T.AMOUNT - T.ALLOCATEDBAL) SUMAGEBAL
FROM CR_ACCS A
LEFT JOIN CR_TRANS T ON A.ACCNO = T.ACCNO AND T.ALLOCATED = '0'
JOIN PERIOD_STATUS PS ON T.PERIOD_SEQNO=PS.SEQNO
WHERE PS.AGE = 2
GROUP BY A.ACCNO, PS.AGE
) AGE2 ON C.ACCNO = AGE2.ACCNO
LEFT JOIN (
SELECT A.ACCNO, SUM(T.AMOUNT - T.ALLOCATEDBAL) SUMAGEBAL
FROM CR_ACCS A
LEFT JOIN CR_TRANS T ON A.ACCNO = T.ACCNO AND T.ALLOCATED = '0'
JOIN PERIOD_STATUS PS ON T.PERIOD_SEQNO=PS.SEQNO
WHERE PS.AGE >= 3
GROUP BY A.ACCNO
) AGE3 ON C.ACCNO = AGE3.ACCNO
WHERE
(ABS(ISNULL(AGE0.SUMAGEBAL, 0)- ISNULL(C.AGEDBAL0, 0))>0.009)
OR (ABS(ISNULL(AGE1.SUMAGEBAL, 0)- ISNULL(C.AGEDBAL1, 0))>0.009)
OR (ABS(ISNULL(AGE2.SUMAGEBAL, 0)- ISNULL(C.AGEDBAL2, 0))>0.009)
OR (ABS(ISNULL(AGE3.SUMAGEBAL, 0)- ISNULL(C.AGEDBAL3, 0))>0.009)

IF CHARINDEX('Y', @CONFIG) <> 0
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'Fixing Creditors Aged Balances', 'TEXT'

UPDATE C
SET AGEDBAL0 = ISNULL(AGE0.SUMAGEBAL, 0),
AGEDBAL1 = ISNULL(AGE1.SUMAGEBAL, 0),
AGEDBAL2 = ISNULL(AGE2.SUMAGEBAL, 0),
AGEDBAL3 = ISNULL(AGE3.SUMAGEBAL, 0)
FROM CR_ACCS C
LEFT JOIN (
SELECT A.ACCNO, PS.AGE, SUM(T.AMOUNT - T.ALLOCATEDBAL) SUMAGEBAL
FROM CR_ACCS A
LEFT JOIN CR_TRANS T ON A.ACCNO = T.ACCNO AND T.ALLOCATED = '0'
JOIN PERIOD_STATUS PS ON T.PERIOD_SEQNO=PS.SEQNO
WHERE PS.AGE = 0
GROUP BY A.ACCNO, PS.AGE
) AGE0 ON C.ACCNO = AGE0.ACCNO
LEFT JOIN (
SELECT A.ACCNO, PS.AGE, SUM(T.AMOUNT - T.ALLOCATEDBAL) SUMAGEBAL
FROM CR_ACCS A
LEFT JOIN CR_TRANS T ON A.ACCNO = T.ACCNO AND T.ALLOCATED = '0'
JOIN PERIOD_STATUS PS ON T.PERIOD_SEQNO=PS.SEQNO
WHERE PS.AGE = 1
GROUP BY A.ACCNO, PS.AGE
) AGE1 ON C.ACCNO = AGE1.ACCNO
LEFT JOIN (
SELECT A.ACCNO, PS.AGE, SUM(T.AMOUNT - T.ALLOCATEDBAL) SUMAGEBAL
FROM CR_ACCS A
LEFT JOIN CR_TRANS T ON A.ACCNO = T.ACCNO AND T.ALLOCATED = '0'
JOIN PERIOD_STATUS PS ON T.PERIOD_SEQNO=PS.SEQNO
WHERE PS.AGE = 2
GROUP BY A.ACCNO, PS.AGE
) AGE2 ON C.ACCNO = AGE2.ACCNO
LEFT JOIN (
SELECT A.ACCNO, SUM(T.AMOUNT - T.ALLOCATEDBAL) SUMAGEBAL
FROM CR_ACCS A
LEFT JOIN CR_TRANS T ON A.ACCNO = T.ACCNO AND T.ALLOCATED = '0'
JOIN PERIOD_STATUS PS ON T.PERIOD_SEQNO=PS.SEQNO
WHERE PS.AGE >= 3
GROUP BY A.ACCNO
) AGE3 ON C.ACCNO = AGE3.ACCNO

INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'DONE', 'TEXT'
END
END
ELSE
BEGIN
IF CHARINDEX('L', @CONFIG) = 0
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'CREDITORS CORRECT', 'TEXT'
END
END

    -- CHECK ORPHAN INVOICE LINES
    INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
    SELECT @HDR_SEQNO, 'Verify Orphan Creditor Invoice Lines', 'TEXT'

    IF EXISTS (
SELECT I.INVNO
        FROM CR_INVLINES I
LEFT JOIN CR_TRANS T ON T.SEQNO = I.HDR_SEQNO
WHERE T.SEQNO IS NULL)
    BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS, SOURCE_SEQ, LINETYPE)
SELECT @HDR_SEQNO, MESSAGE =
'Invalid invoice lines for Creditor a/c ' + I.INVNO + '',
'C0005', I.SEQNO, 'ERROR'
FROM CR_INVLINES I
LEFT JOIN CR_TRANS T ON T.SEQNO = I.HDR_SEQNO
WHERE T.SEQNO IS NULL

INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, ' ', 'TEXT'
END
ELSE
BEGIN
IF CHARINDEX('L', @CONFIG) = 0
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'INVOICE LINE ON CREDITOR CORRECT', 'TEXT'
END
END

    -- CHECK FOR INVALID STOCKCODES TYPE 'S'
    INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
    SELECT @HDR_SEQNO, 'Verify Stockcodes MODE STOCK on Creditor', 'TEXT'

    IF EXISTS (
SELECT CI.STOCKCODE, CI.DESCRIPTION
FROM CR_INVLINES CI
LEFT JOIN STOCK_ITEMS SI ON SI.STOCKCODE = CI.STOCKCODE
LEFT JOIN CR_TRANS T ON CI.HDR_SEQNO = T.SEQNO
JOIN PERIOD_STATUS PS ON T.PERIOD_SEQNO=PS.SEQNO
WHERE CI.CODETYPE = 'S'
AND SI.STOCKCODE IS NULL
AND PS.AGE <= @STARTPERIOD AND PS.AGE >= @ENDPERIOD)
    BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS, SOURCE_SEQ, LINETYPE)
          SELECT @HDR_SEQNO, ' Inv# ' + CI.INVNO
+ ' - ERROR!
Account = ' + CONVERT(VARCHAR, CI.ACCNO) + '
Invalid STOCKCODES: ' + CI.STOCKCODE + '
Description : ' + CI.DESCRIPTION + ' ',
'C0006', CI.SEQNO, 'ERROR'
FROM CR_INVLINES CI
LEFT JOIN STOCK_ITEMS SI ON SI.STOCKCODE = CI.STOCKCODE
LEFT JOIN CR_TRANS T ON CI.HDR_SEQNO = T.SEQNO
JOIN PERIOD_STATUS PS ON T.PERIOD_SEQNO=PS.SEQNO
WHERE CI.CODETYPE = 'S'
AND SI.STOCKCODE IS NULL
AND PS.AGE <= @STARTPERIOD AND PS.AGE >= @ENDPERIOD
END
ELSE
BEGIN
IF CHARINDEX('L', @CONFIG) = 0
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'STOCKCODES MODE STOCK ON CREDITOR CORRECT', 'TEXT'
END
END

    -- CHECK FOR INVALID STOCKCODES TYPE 'G'
    INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
    SELECT @HDR_SEQNO, 'Verify Stockcodes MODE GL on Creditor', 'TEXT'

DECLARE @GLACCNOSIZE INT
DECLARE @GLBRANCHSIZE INT
DECLARE @GLSUBACCSIZE INT

SELECT @GLACCNOSIZE = FIELDVALUE FROM profile_values WHERE fieldname = 'GLACCNOSIZE'
SELECT @GLBRANCHSIZE = FIELDVALUE FROM profile_values WHERE fieldname = 'GLBRANCHSIZE'
SELECT @GLSUBACCSIZE = FIELDVALUE FROM profile_values WHERE fieldname = 'GLSUBACCSIZE'

    IF EXISTS (
SELECT STOCKCODE
FROM CR_INVLINES
LEFT JOIN
(
SELECT SEQNO, LEFT(STOCKCODE, @GLBRANCHSIZE) AS BRANCH, RIGHT(STOCKCODE, @GLSUBACCSIZE) AS SUBACC,
REPLACE(substring(STOCKCODE, @GLBRANCHSIZE +2, @GLACCNOSIZE), '-', '') AS GLACCNO
FROM CR_INVLINES
WHERE CODETYPE = 'G'
) CI ON CI.SEQNO = CR_INVLINES.SEQNO
LEFT JOIN GLACCS A ON CI.GLACCNO = A.ACCNO
LEFT JOIN CR_TRANS T ON CR_INVLINES.HDR_SEQNO = T.SEQNO
JOIN PERIOD_STATUS PS ON T.PERIOD_SEQNO=PS.SEQNO
WHERE CODETYPE = 'G'
AND A.ACCNO IS NULL
        AND PS.AGE <= @STARTPERIOD AND PS.AGE >= @ENDPERIOD)
    BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS, SOURCE_SEQ, LINETYPE)
      SELECT @HDR_SEQNO, ' Inv# ' + CR_INVLINES.INVNO
+ ' - ERROR!
Invalid STOCKCODES: ' + CR_INVLINES.STOCKCODE + '
Description : ' + CR_INVLINES .DESCRIPTION + ' ',
'C0007', CR_INVLINES.SEQNO, 'ERROR'
FROM CR_INVLINES
LEFT JOIN
(
SELECT SEQNO, LEFT(STOCKCODE, @GLBRANCHSIZE) AS BRANCH, RIGHT(STOCKCODE, @GLSUBACCSIZE) AS SUBACC,
REPLACE(substring(STOCKCODE, @GLBRANCHSIZE +2, @GLACCNOSIZE), '-', '') AS GLACCNO
FROM CR_INVLINES
WHERE CODETYPE = 'G'
) CI ON CI.SEQNO = CR_INVLINES.SEQNO
LEFT JOIN GLACCS A ON CI.GLACCNO = A.ACCNO
LEFT JOIN CR_TRANS T ON CR_INVLINES.HDR_SEQNO = T.SEQNO
JOIN PERIOD_STATUS PS ON T.PERIOD_SEQNO=PS.SEQNO
WHERE CODETYPE = 'G'
AND A.ACCNO IS NULL
          AND PS.AGE <= @STARTPERIOD AND PS.AGE >= @ENDPERIOD

END
ELSE
BEGIN
IF CHARINDEX('L', @CONFIG) = 0
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'STOCKCODES ON CREDITOR CORRECT', 'TEXT'
END
END

    -- CHECK FOR INVALID GLCODES
    INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
    SELECT @HDR_SEQNO, 'Verify Analysis GL CODE on Creditor', 'TEXT'

    IF EXISTS (
        SELECT I.ANALYSIS, A.ACCNO
        FROM CR_INVLINES I
        LEFT JOIN GLACCS A ON I.ANALYSIS = A.ACCNO
        LEFT JOIN CR_TRANS T ON I.HDR_SEQNO = T.SEQNO
JOIN PERIOD_STATUS PS ON T.PERIOD_SEQNO=PS.SEQNO
        WHERE (I.ANALYSIS <> 0 AND A.ACCNO IS NULL )
        AND PS.AGE <= @STARTPERIOD AND PS.AGE >= @ENDPERIOD)
    BEGIN
      INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS, SOURCE_SEQ, LINETYPE)
      SELECT @HDR_SEQNO, MESSAGE = ' Inv# ' + I.INVNO +
        + ' - ERROR!
        Stock Code = ' + CONVERT(VARCHAR, I.STOCKCODE) + '
        Batch = ' + CONVERT(VARCHAR, I.BATCHCODE) + '
        CR Analysis GL Code = ' + CONVERT(VARCHAR, I.ANALYSIS) + ' ',
        'C0008', I.SEQNO, 'ERROR'
      FROM CR_INVLINES I
      LEFT JOIN GLACCS A ON I.ANALYSIS = A.ACCNO
      LEFT JOIN CR_TRANS T ON I.HDR_SEQNO = T.SEQNO
JOIN PERIOD_STATUS PS ON T.PERIOD_SEQNO=PS.SEQNO
      WHERE (I.ANALYSIS <> 0 AND A.ACCNO IS NULL )
        AND PS.AGE <= @STARTPERIOD AND PS.AGE >= @ENDPERIOD

      INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE)
      SELECT @HDR_SEQNO, ' '
    END
    ELSE
    BEGIN
      IF CHARINDEX('L', @CONFIG) = 0
      BEGIN
        INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
        SELECT @HDR_SEQNO, 'ANALYSIS GL CODE ON CREDITOR CORRECT', 'TEXT'
      END
    END

    -- CHECK FOR INVALID BRANCH
    INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
    SELECT @HDR_SEQNO, 'Verify Branch on Creditor', 'TEXT'

    IF EXISTS (
SELECT CREDITOR.BRANCHNO, CREDITOR.INVNO
FROM (
SELECT I.BRANCHNO, I.INVNO FROM CR_INVLINES I
            LEFT JOIN CR_TRANS T ON I.HDR_SEQNO = T.SEQNO
JOIN PERIOD_STATUS PS ON T.PERIOD_SEQNO=PS.SEQNO
            WHERE PS.AGE <= @STARTPERIOD AND PS.AGE >= @ENDPERIOD
UNION
SELECT T.BRANCHNO, T.INVNO FROM CR_TRANS T
JOIN PERIOD_STATUS PS ON T.PERIOD_SEQNO=PS.SEQNO
WHERE PS.AGE <= @STARTPERIOD AND PS.AGE >= @ENDPERIOD
) AS CREDITOR
LEFT JOIN BRANCHES B ON CREDITOR.BRANCHNO = B.BRANCHNO
WHERE (B.BRANCHNO IS NULL))
    BEGIN
      INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS, SOURCE_SEQ, LINETYPE)
      SELECT @HDR_SEQNO, MESSAGE = ' Inv# ' + CREDITOR.INVNO +
        + ' - ERROR!
        Branch No = ' + CONVERT(VARCHAR, CREDITOR.BRANCHNO) + ' ',
        'C0009', CREDITOR.SEQNO, 'ERROR'
      FROM (
SELECT I.BRANCHNO, I.INVNO, T.SEQNO FROM CR_INVLINES I
        LEFT JOIN CR_TRANS T ON I.HDR_SEQNO = T.SEQNO
JOIN PERIOD_STATUS PS ON T.PERIOD_SEQNO=PS.SEQNO
        WHERE PS.AGE <= @STARTPERIOD AND PS.AGE >= @ENDPERIOD
UNION
SELECT T.BRANCHNO, T.INVNO, T.SEQNO FROM CR_TRANS T
JOIN PERIOD_STATUS PS ON T.PERIOD_SEQNO=PS.SEQNO
WHERE PS.AGE <= @STARTPERIOD AND PS.AGE >= @ENDPERIOD
) AS CREDITOR
LEFT JOIN BRANCHES B ON CREDITOR.BRANCHNO = B.BRANCHNO
WHERE (B.BRANCHNO IS NULL)

      INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
      SELECT @HDR_SEQNO, ' ', 'TEXT'
    END
    ELSE
    BEGIN
IF CHARINDEX('L', @CONFIG) = 0
      BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
        SELECT @HDR_SEQNO, 'BRANCH ON CREDITOR CORRECT', 'TEXT'
      END
    END

    -- CHECK FOR MULTIPLE GL POSTING
    SET NOCOUNT ON
    INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
    SELECT @HDR_SEQNO, 'Verify GL Posting on Creditor Transaction', 'TEXT'

    IF EXISTS (
      SELECT T.SEQNO, T.INVNO, T.TRANSDATE, T.ACCNO, T.AGE, T.AMOUNT, GL.GLPOSTING
      FROM CR_TRANS T
      LEFT JOIN (
        SELECT G.SOURCE_SEQ, COUNT(SOURCE_SEQ) AS GLPOSTING
        FROM GLTRANS G
        INNER JOIN CR_TRANS D ON D.SEQNO = G.SOURCE_SEQ AND G.SOURCE = 'c' AND G.SOURCE_INVLINEID = -1 AND CONVERT(MONEY, G.FCAMOUNT) = CONVERT(MONEY, -D.AMOUNT)
        GROUP BY G.SOURCE_SEQ
      ) GL ON T.SEQNO = GL.SOURCE_SEQ
JOIN PERIOD_STATUS PS ON T.PERIOD_SEQNO=PS.SEQNO
      WHERE GL.GLPOSTING > 1
        AND PS.AGE <= @STARTPERIOD AND PS.AGE >= @ENDPERIOD)
    BEGIN
      INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS, SOURCE_SEQ, LINETYPE)
      SELECT @HDR_SEQNO , MESSAGE = ' Inv# ' + T.INVNO + ' Dated: ' + CONVERT(VARCHAR, T.TRANSDATE, 3)
        + ' - ERROR!
Account = ' + CONVERT(VARCHAR, T.ACCNO) + '
Age = ' + CONVERT(VARCHAR, T.AGE) + '
Amount = ' + CONVERT(VARCHAR, CONVERT(MONEY, T.AMOUNT )) + '
        GL Posting times = ' + CONVERT(VARCHAR, GL.GLPOSTING) + ' ',
        'C0010', T.SEQNO, 'ERROR'
      FROM CR_TRANS T
      LEFT JOIN (
        SELECT G.SOURCE_SEQ, COUNT(SOURCE_SEQ) AS GLPOSTING
        FROM GLTRANS G
        INNER JOIN CR_TRANS D ON D.SEQNO = G.SOURCE_SEQ AND G.SOURCE = 'c' AND G.SOURCE_INVLINEID = -1 AND CONVERT(MONEY, G.FCAMOUNT) = CONVERT(MONEY, -D.AMOUNT)
        GROUP BY G.SOURCE_SEQ
      ) GL ON T.SEQNO = GL.SOURCE_SEQ
JOIN PERIOD_STATUS PS ON T.PERIOD_SEQNO=PS.SEQNO
      WHERE GL.GLPOSTING > 1
      AND PS.AGE <= @STARTPERIOD AND PS.AGE >= @ENDPERIOD

      INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
      SELECT @HDR_SEQNO, ' ', 'TEXT'
    END
    ELSE
    BEGIN
      IF CHARINDEX('L', @CONFIG) = 0
      BEGIN
        INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
        SELECT @HDR_SEQNO, 'GL POSTING ON CREDITOR TRANSACTION CORRECT', 'TEXT'
      END
    END
  END

  IF CHARINDEX('I', @CONFIG) <> 0 AND CHARINDEX('C', @CONFIG) <> 0
  BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'Verify CR_TRAN header balance matches line totals', 'TEXT'
IF EXISTS(
SELECT CT.ACCNO FROM CR_TRANS CT
LEFT JOIN (
SELECT HDR_SEQNO, SUM(CONVERT(MONEY, ISNULL(LINETOTAL, 0))) AS LINETOTAL
FROM CR_INVLINES
GROUP BY HDR_SEQNO
) CL ON CT.SEQNO = CL.HDR_SEQNO
JOIN PERIOD_STATUS PS ON CT.PERIOD_SEQNO=PS.SEQNO
WHERE CT.TRANSTYPE = 1 AND ABS(SUBTOTAL - LINETOTAL) > 0.009
          AND PS.AGE <= @STARTPERIOD AND PS.AGE >= @ENDPERIOD
)
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS, SOURCE_SEQ, LINETYPE)
SELECT @HDR_SEQNO, 'A/c ' + CONVERT(VARCHAR, CT.ACCNO) + ' Inv# ' + CT.INVNO + ' Dated: ' + CONVERT(VARCHAR, CT.TRANSDATE, 3)
+ ' - ERROR!
Header Sequence = ' + CONVERT(VARCHAR, CT.SEQNO) + '
Header Subtotal = ' + CONVERT(VARCHAR, CONVERT(MONEY, SUBTOTAL)) + '
Inv Lines Total = ' + CONVERT(VARCHAR, CONVERT(MONEY, LINETOTAL)) + '
Inv Imbalance = ' + CONVERT(VARCHAR, CONVERT(MONEY, SUBTOTAL - LINETOTAL)) + ' ',
'C0011', CT.SEQNO, 'ERROR'
FROM CR_TRANS CT
LEFT JOIN (
SELECT HDR_SEQNO, SUM(CONVERT(MONEY, ISNULL(LINETOTAL, 0))) AS LINETOTAL
FROM CR_INVLINES
GROUP BY HDR_SEQNO
) CL ON CT.SEQNO = CL.HDR_SEQNO
JOIN PERIOD_STATUS PS ON CT.PERIOD_SEQNO=PS.SEQNO
WHERE CT.TRANSTYPE = 1 AND ABS(SUBTOTAL - LINETOTAL) > 0.009
          AND PS.AGE <= @STARTPERIOD AND PS.AGE >= @ENDPERIOD
ORDER BY CT.INVNO

INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, CONVERT(VARCHAR, @@ROWCOUNT) + ' Invoice Errors', 'TEXT'
END
ELSE
BEGIN
IF CHARINDEX('L', @CONFIG) = 0
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'No Creditor Invoice Errors found', 'TEXT'
END
END
  END

  --VERIFY CR_TRANS HEADER ALLOCATED BALANCE MATCHES ALLOCATION TOTALS
  IF CHARINDEX('A', @CONFIG) <> 0 AND CHARINDEX('C', @CONFIG) <> 0
  BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'Verify CR_TRANS header Allocated Balance matches Allocation totals' , 'TEXT'
IF EXISTS(
SELECT CT.ACCNO FROM CR_TRANS CT
LEFT JOIN (
SELECT TRANS_SEQNO, SUM(CONVERT(MONEY, ISNULL(AMOUNT, 0))) AS ALLOCTOTAL
FROM CR_ALLOCATIONS
GROUP BY TRANS_SEQNO
) CA ON CT.SEQNO = CA.TRANS_SEQNO
JOIN PERIOD_STATUS PS ON CT.PERIOD_SEQNO=PS.SEQNO
          WHERE ABS(CT.ALLOCATEDBAL) - ABS(CA.ALLOCTOTAL) > 0.009
          AND PS.AGE <= @STARTPERIOD AND PS.AGE >= @ENDPERIOD
)
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS, SOURCE_SEQ, LINETYPE)
SELECT @HDR_SEQNO, 'A/c ' + CONVERT(VARCHAR, CT.ACCNO) + ' Transaction Dated: ' + CONVERT(VARCHAR, CT.TRANSDATE, 3)
+ ' - ERROR!
Header Sequence = ' + CONVERT(VARCHAR, CT.SEQNO) + '
Header AllocatedBal = ' + CONVERT(VARCHAR, CONVERT(MONEY, ALLOCATEDBAL)) + '
Allocation Lines Total = ' + CONVERT(VARCHAR, CONVERT(MONEY, ALLOCTOTAL)) + '
Allocation Imbalance = ' + CONVERT(VARCHAR, CONVERT(MONEY, ALLOCATEDBAL - ALLOCTOTAL)) + ' ',
'C0012', CT.SEQNO, 'ERROR'
FROM CR_TRANS CT
LEFT JOIN (
SELECT TRANS_SEQNO, SUM(CONVERT(MONEY, ISNULL(AMOUNT, 0))) AS ALLOCTOTAL
FROM CR_ALLOCATIONS
GROUP BY TRANS_SEQNO
) CA ON CT.SEQNO = CA.TRANS_SEQNO
JOIN PERIOD_STATUS PS ON CT.PERIOD_SEQNO=PS.SEQNO
WHERE ABS(CT.ALLOCATEDBAL) - ABS(CA.ALLOCTOTAL) > 0.009
          AND PS.AGE <= @STARTPERIOD AND PS.AGE >= @ENDPERIOD
ORDER BY CT.SEQNO
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, CONVERT(VARCHAR, @@ROWCOUNT) + ' Allocation Errors', 'TEXT'
END
ELSE
BEGIN
IF CHARINDEX('L', @CONFIG) = 0
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'No Creditor Allocation Errors found', 'TEXT'
END
END
  END

  --CHECK FOR NULL TRANS_SEQNO IN CREDITOR ALLOCATIONS
  IF CHARINDEX('A', @CONFIG) <> 0 AND CHARINDEX('C', @CONFIG) <> 0
  BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'Check for Orphan Creditor Allocation sets' , 'TEXT'
IF EXISTS(
SELECT CA.ALLOCNO FROM CR_ALLOCATIONS CA
JOIN PERIOD_STATUS PS ON CA.PERIOD_SEQNO=PS.SEQNO
WHERE CA.TRANS_SEQNO IS NULL
AND PS.AGE <= @STARTPERIOD AND PS.AGE >= @ENDPERIOD
)
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS, SOURCE_SEQ, LINETYPE)
SELECT @HDR_SEQNO, 'Alloc No. ' + CONVERT(VARCHAR, CA.ALLOCNO) + ' has no Creditor Transactions linked to it',
'C0013', CA.ALLOCNO, 'ERROR'
FROM CR_ALLOCATIONS CA
JOIN PERIOD_STATUS PS ON CA.PERIOD_SEQNO=PS.SEQNO
WHERE CA.TRANS_SEQNO IS NULL
AND PS.AGE <= @STARTPERIOD AND PS.AGE >= @ENDPERIOD
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, CONVERT(VARCHAR, @@ROWCOUNT) + ' Creditor Allocation Errors - Orphan Allocation Sets', 'TEXT'
END
ELSE
BEGIN
IF CHARINDEX('L', @CONFIG) = 0
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'No Creditor Orphan Allocation Sets found' , 'TEXT'
END
END
  END

  IF @STANDALONE = 'Y'
  BEGIN
    INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
    SELECT @HDR_SEQNO, 'Verification Completed '
      + LEFT(CONVERT(VARCHAR, GETDATE(), 109), 50) + ' '
      + CONVERT(VARCHAR(5), DATEDIFF(SECOND, (SELECT CREATEDATE FROM VERIFICATION_HDR WHERE SEQNO = @HDR_SEQNO), GETDATE())) + ' Seconds', 'TEXT'

SELECT MESSAGE FROM VERIFICATION_LINES WHERE HDR_SEQNO = @HDR_SEQNO
  END
  ELSE
  BEGIN
    SET @ENDTIME = GETDATE()
    INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
    SELECT @HDR_SEQNO, 'Duration for creditor verification: '
      + CONVERT(VARCHAR(5), DATEDIFF(SECOND, @STARTTIME, @ENDTIME)) + ' Seconds', 'TEXT'
  END
END


Procedure: DATA_VERIFICATION_CRACCBALANCING
NameDATA_VERIFICATION_CRACCBALANCING
Note
CodeCREATE PROCEDURE [dbo].[DATA_VERIFICATION_CRACCBALANCING]
    @CONFIG CHAR(10) = 'DCGIAMS$',
    @HDR_SEQNO INT = -1,
    @STANDALONE CHAR(1)= 'Y'
AS
BEGIN

  SET NOCOUNT ON

  DECLARE @OUTPUT VARCHAR(512),
@IMBALANCES DOUBLE PRECISION,
@PAYABLE DOUBLE PRECISION,
@FOREXTOTAL DOUBLE PRECISION,
@CR_TRANS_AMOUNT DOUBLE PRECISION,
@GL_CONTROL_AMOUNT DOUBLE PRECISION,
@GL_CONTROL_FCAMOUNT DOUBLE PRECISION,
@FOREXTOTAL1AMOUNT DOUBLE PRECISION,
@MYGRATETOTALAMOUNT DOUBLE PRECISION,
@Current_period_seqno integer,
@STARTTIME DATETIME,
@ENDTIME DATETIME

  SET @STARTTIME = GETDATE()

  select @Current_period_seqno = seqno from period_status where age = 0 and Ledger = 'G'

  IF @CONFIG = 'Y'
  BEGIN
SET @CONFIG = 'YDCGIAMS$'
  END

  IF @CONFIG = 'N'
  BEGIN
SET @CONFIG = 'NDCGIAMS$'
  END

  IF @STANDALONE = 'Y'
  BEGIN
INSERT INTO VERIFICATION_HDR (CONFIG_FLAG, CREATED_BY, CREATEDATE )
SELECT @CONFIG, [dbo].FN_GET_STAFF_NO() , GETDATE()

SELECT @HDR_SEQNO = (SELECT MAX(SEQNO) FROM VERIFICATION_HDR)

--DATA VERIFICATION BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'MYOB EXO Business DATA VERIFICATION ' + CONVERT(VARCHAR, GETDATE()), 'TEXT'

SELECT @OUTPUT = USERNAME FROM GENERAL_INFO
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'Company Name: ' + @OUTPUT, 'TEXT'

SELECT @OUTPUT = SOFTWARE_VERSION FROM GENERAL_INFO
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'MYOB EXO Business Database Version: ' + @OUTPUT, 'TEXT'

IF CHARINDEX('L', @CONFIG) = 0
BEGIN
SELECT @OUTPUT = 'MYOB EXO Business Database configured for ' + COUNTRY_NAME FROM GENERAL_INFO G
JOIN COUNTRY C ON G.COUNTRY = C.COUNTRY_CODE
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, @OUTPUT, 'TEXT'
END

IF CHARINDEX('Y', @CONFIG) <> 0
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'Fix Imbalance is ''ON''', 'TEXT'
END
ELSE
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'Fix Imbalance is ''OFF''', 'TEXT'
END

IF CHARINDEX('N', @CONFIG) <> 0
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'MYOB VERIFICATION ''ON''', 'TEXT'
END
  END

  ----CHECK FOR CREDITOR LEDGER AGAINST GL CONTROL ACCOUNT FOR IMBALANCES
  IF CHARINDEX('C', @CONFIG) <> 0
  BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, ' ', 'TEXT'

INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'Verify Creditor Ledger balances with Creditor control account', 'TEXT'

set @GL_CONTROL_AMOUNT = isnull((select dbo.FN_GetCrControlAccBalance(@Current_period_seqno)), 0)
SET @MYGRATETOTALAMOUNT = isnull((select dbo.FN_GetCrFxMygrateExcep()), 0)
set @FOREXTOTAL = isnull((select dbo.FN_GetCrControlFXVariance(@Current_period_seqno)) , 0)
set @FOREXTOTAL = (@FOREXTOTAL) - ISNULL(@MYGRATETOTALAMOUNT, 0)
set @PAYABLE = isnull((select sum(balance) as Ledgeramount from fn_Cr_agedbalances_backwards_summary(@Current_period_seqno, 'N')), 0)
- @MYGRATETOTALAMOUNT
set @IMBALANCES = isnull((@PAYABLE - (@GL_CONTROL_AMOUNT*-1)), 0)



INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, ' Payable Value : ' + CONVERT(VARCHAR, CONVERT(MONEY, @PAYABLE)), 'TEXT'

INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, ' Account Balances : ' + CONVERT(VARCHAR, CONVERT(MONEY, (@GL_CONTROL_AMOUNT*-1))), 'TEXT'

IF ABS(ISNULL(@IMBALANCES, 0)) > 0.009
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS, SOURCE_SEQ, LINETYPE)
SELECT @HDR_SEQNO, ' Imbalance Amount : ' + CONVERT(VARCHAR, CONVERT(MONEY, @IMBALANCES)), 'CB007', '', 'ERROR'
END
ELSE
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, ' Imbalance Amount : ' + CONVERT(VARCHAR, CONVERT(MONEY, @IMBALANCES)), 'TEXT'
END

--INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
--SELECT @HDR_SEQNO, ' FOREX Variance : ' + CONVERT(VARCHAR, CONVERT(MONEY, @FOREXTOTAL)), 'TEXT'

IF ABS(ISNULL(@IMBALANCES, 0)) > 0.009 and (CHARINDEX('L', @CONFIG) = 0)
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, ' ', 'TEXT'

INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'Possible Causes of Exceptions : ', 'TEXT'

-- UNPOSTED TRANSACTIONS
IF EXISTS (
Select * from [FN_GET_CREDITORSLEDGER_IMBALANCEREASONS](0, DEFAULT, 'CB001')
)
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'Unposted Transactions', 'TEXT'
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, '------------------------------------------', 'TEXT'

INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS, SOURCE_SEQ, LINETYPE)
SELECT @HDR_SEQNO, ' Inv# ' + INVNO + ' Dated: ' + CONVERT(VARCHAR, transaction_date, 3)
+ ' -
Name = ' + CONVERT(VARCHAR, accname) + '
Trans Type = ' + CONVERT(VARCHAR, transaction_type) + '
Deposit Status = ' + CONVERT(VARCHAR, DEPOSIT_STATUS) + '
Age = ' + CONVERT(VARCHAR, period) + '
Amount = ' + CONVERT(VARCHAR, CONVERT(MONEY, amount )) +
+ ' ',
'CB001', source_seq, ''
FROM [FN_GET_CREDITORSLEDGER_IMBALANCEREASONS](0, DEFAULT, 'CB001')
ORDER BY transaction_type,
DEPOSIT_STATUS

INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, ' ', 'TEXT'
END

-- DIRECT POSTING
IF EXISTS (
Select * from [FN_GET_CREDITORSLEDGER_IMBALANCEREASONS](0, DEFAULT, 'CB002')
)
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'Direct Postings', 'TEXT'
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, '------------------------------------------', 'TEXT'

INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS, SOURCE_SEQ, LINETYPE)
SELECT @HDR_SEQNO, ' Inv# ' + INVNO + ' Dated: ' + CONVERT(VARCHAR, Transaction_date, 3)
+ ' -
Source = ' + CONVERT(VARCHAR, gl_source) + '
Batch Number = ' + CONVERT(VARCHAR, BATCHNO) + '
Details = ' + CONVERT(VARCHAR, DETAILS) + '
Age = ' + CONVERT(VARCHAR, period) + '
Amount = ' + CONVERT(VARCHAR, CONVERT(MONEY, amount)) + ' ',
'CB002', source_seq, ''
FROM [FN_GET_CREDITORSLEDGER_IMBALANCEREASONS](0, DEFAULT, 'CB002')

INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, ' ', 'TEXT'
END


-- Erroneous Payments and Adjustments
IF EXISTS (
Select * from [FN_GET_CREDITORSLEDGER_IMBALANCEREASONS](0, DEFAULT, 'CB003')
)
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'Erroneous Payments and Adjustments', 'TEXT'
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, '------------------------------------------', 'TEXT'

INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS, SOURCE_SEQ, LINETYPE)
SELECT @HDR_SEQNO, ' Inv# ' + INVNO + ' Dated: ' + CONVERT(VARCHAR, Transaction_date, 3)
+ ' -
Account = ' + CONVERT(VARCHAR, Accno) + '. ' + CONVERT(VARCHAR, Accname) + '
Trans Type = ' + CONVERT(VARCHAR, Transaction_type) + '
Age = ' + CONVERT(VARCHAR, Period) + '
Amount = ' + CONVERT(VARCHAR, CONVERT(MONEY, Amount)) + ' ',
'CB003', Source_seq, ''
FROM [FN_GET_CREDITORSLEDGER_IMBALANCEREASONS](0, DEFAULT, 'CB003')

INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, ' ', 'TEXT'
END



-- UNPOSTED GL POST RUN
IF EXISTS (
Select * from [FN_GET_CREDITORSLEDGER_IMBALANCEREASONS](0, DEFAULT, 'CB004')
)
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'Unposted GL Post Run', 'TEXT'
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, '------------------------------------------', 'TEXT'

INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS, SOURCE_SEQ, LINETYPE)
SELECT @HDR_SEQNO, ' Postrun# ' + convert(varchar, glpostrun_number) +
' Dated: ' + CONVERT(VARCHAR, transaction_date, 3)
+ ' -
Description = ' + CONVERT(VARCHAR, GLPOSTRUN_DESCRIPTION) + '
Initials = ' + CONVERT(VARCHAR, GLPOSTRUN_INITIALS) + '
Amount = ' + CONVERT(VARCHAR, CONVERT(MONEY, Amount)) + ' ',
'CB004', source_seq, ''
FROM [FN_GET_CREDITORSLEDGER_IMBALANCEREASONS](0, DEFAULT, 'CB004')

INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, ' ', 'TEXT'
END


-- UNREALISED FOREX GAINS / LOSSES
IF EXISTS (
Select * from [FN_GET_CREDITORSLEDGER_IMBALANCEREASONS](0, DEFAULT, 'CB006')
)
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'Unrealised FOREX Gains / Losses', 'TEXT'
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, '------------------------------------------', 'TEXT'

INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS, SOURCE_SEQ, LINETYPE)
SELECT @HDR_SEQNO, ' Dated: ' + CONVERT(VARCHAR, Transaction_date, 3)
+ ' -
BatchNo = ' + CONVERT(VARCHAR, BATCHNO) + ' Period = ' + CONVERT(VARCHAR, period) + '
Details = ' + CONVERT(VARCHAR, DETAILS) + '
Currency =' + CONVERT(VARCHAR, CurrencyName) + ' Amount = ' + CONVERT(VARCHAR, CONVERT(MONEY, AMOUNT )) + ' ',
'CB006', source_seq, ''
FROM [FN_GET_CREDITORSLEDGER_IMBALANCEREASONS](0, DEFAULT, 'CB006')

INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, ' ', 'TEXT'
END
END
ELSE
if (CHARINDEX('L', @CONFIG) = 0)
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'NO CR_TRANS IMBALANCES FOUND ', 'TEXT'
END
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, ' ', 'TEXT'
  END

  IF @STANDALONE = 'Y'
  BEGIN
    INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
    SELECT @HDR_SEQNO, 'Verification Completed '
      + LEFT(CONVERT(VARCHAR, GETDATE(), 109), 50) + ' '
      + CONVERT(VARCHAR(5), DATEDIFF(SECOND, (SELECT CREATEDATE FROM VERIFICATION_HDR WHERE SEQNO = @HDR_SEQNO), GETDATE())) + ' Seconds', 'TEXT'
SELECT MESSAGE FROM VERIFICATION_LINES WHERE HDR_SEQNO = @HDR_SEQNO
  END
  ELSE
  BEGIN
    SET @ENDTIME = GETDATE()
    INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
    SELECT @HDR_SEQNO, 'Duration for creditor ledger balances verification: '
      + CONVERT(VARCHAR(5), DATEDIFF(SECOND, @STARTTIME, @ENDTIME)) + ' Seconds', 'TEXT'
  END

END


Procedure: DATA_VERIFICATION_DR
NameDATA_VERIFICATION_DR
Note
CodeCREATE PROCEDURE [dbo].[DATA_VERIFICATION_DR]
    @CONFIG CHAR(10) = 'DCGIAMS$',
    @HDR_SEQNO INT = -1,
    @STANDALONE CHAR(1)= 'Y',
    @STARTPERIOD INT = 0,
    @ENDPERIOD INT = 0
AS
BEGIN

  SET NOCOUNT ON

  DECLARE @OUTPUT VARCHAR(512)
  DECLARE @STARTTIME DATETIME
  DECLARE @ENDTIME DATETIME

  SET @STARTTIME = GETDATE()

  IF @CONFIG = 'Y'
  BEGIN
        SET @CONFIG = 'YDCGIAMS$'
  END

  IF @CONFIG = 'N'
  BEGIN
        SET @CONFIG = 'NDCGIAMS$'
  END

  IF @STANDALONE = 'Y'
  BEGIN
INSERT INTO VERIFICATION_HDR (CONFIG_FLAG, CREATED_BY, CREATEDATE )
SELECT @CONFIG, [dbo].FN_GET_STAFF_NO() , GETDATE()

      SELECT @HDR_SEQNO = (SELECT MAX(SEQNO) FROM VERIFICATION_HDR)

--DATA VERIFICATION BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'MYOB EXO Business DATA VERIFICATION ' + CONVERT(VARCHAR, GETDATE()), 'TEXT'

SELECT @OUTPUT = USERNAME FROM GENERAL_INFO
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'Company Name: ' + @OUTPUT, 'TEXT'

SELECT @OUTPUT = SOFTWARE_VERSION FROM GENERAL_INFO
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'MYOB EXO Business Database Version: ' + @OUTPUT, 'TEXT'

IF CHARINDEX('L', @CONFIG) = 0
BEGIN
SELECT @OUTPUT = 'MYOB EXO Business Database configured for ' + COUNTRY_NAME FROM GENERAL_INFO G
JOIN COUNTRY C ON G.COUNTRY = C.COUNTRY_CODE
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, @OUTPUT, 'TEXT'
END

IF CHARINDEX('Y', @CONFIG) <> 0
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'Fix Imbalance is ''ON''', 'TEXT'
END
ELSE
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'Fix Imbalance is ''OFF''', 'TEXT'
END

IF CHARINDEX('N', @CONFIG) <> 0
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'MYOB VERIFICATION ''ON''', 'TEXT'
END
  END

  IF CHARINDEX('D', @CONFIG) <> 0
  BEGIN
        INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
        SELECT @HDR_SEQNO, 'Verify Tax Rates on Debtors', 'TEXT'

        IF EXISTS (
              SELECT A.ACCNO FROM DR_ACCS A
              LEFT JOIN TAX_RATES R ON A.TAXSTATUS = R.SEQNO
              LEFT JOIN TAX_KEY_POINT K ON K.COUNTRY = (SELECT COUNTRY FROM GENERAL_INFO) AND R.KEY_POINT = K.KEY_POINT
              AND K.DR_LEDGER = 'Y'
              WHERE A.TAXSTATUS <> -1 AND K.SEQNO IS NULL
        )
        BEGIN
              INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS, SOURCE_SEQ, LINETYPE)
              SELECT @HDR_SEQNO, 'Debtor Account No. ' + CONVERT(VARCHAR, A.ACCNO) + ' Named: ' + A.[NAME]
              + ' has a Tax Status of ' + CONVERT(VARCHAR, A.TAXSTATUS) + ' which does not have a matching ''Debtor'' Key Point
              This is an ' + CASE
                          WHEN A.ISACTIVE = 'Y' THEN 'ACTIVE Debtor'
                          ELSE 'INACTIVE Debtor'
                    END AS MESSAGE, CASE
                          WHEN A.ISACTIVE = 'Y' THEN 'D0001'
                          ELSE 'D0002'
                    END AS V_CLASS, A.ACCNO, 'ERROR'
              FROM DR_ACCS A
              LEFT JOIN TAX_RATES R ON A.TAXSTATUS = R.SEQNO
              LEFT JOIN TAX_KEY_POINT K ON K.COUNTRY = (SELECT COUNTRY FROM GENERAL_INFO) AND R.KEY_POINT = K.KEY_POINT
              AND K.DR_LEDGER='Y'
              WHERE A.TAXSTATUS <> -1 AND K.SEQNO IS NULL
ORDER BY A.ACCNO

              --MYOB MIGRATION ADDED FUNCTIONALITY
              IF CHARINDEX('N', @CONFIG) <> 0 AND (SELECT COUNT(NAME) FROM SYSOBJECTS WHERE NAME = 'MYOB_IMPORT_EXCEPTIONS') = 1
              BEGIN
                    --ADD ROWS TO MYOB_IMPORT_EXCEPTIONS FOR DEBTOR ACCOUNTS WITH INCORRECT TAX RATES WITH MISSING DEBTOR KEY POINT VALUES
                    INSERT INTO MYOB_IMPORT_EXCEPTIONS (EXONET_TABLE_NAME, SOURCE_TYPE, DESTINATION_REF_NO, PROBLEM_COLUMN,
                    PROBLEM_DESCRIPTION, PROBLEM_RESOLUTION)
                    SELECT 'DR_ACCS', 'MYGRATE', A.ACCNO, A.[NAME], 'MISSING DEBTOR KEY POINT ON TAX RATE', 'Verify the Sales Tax rate on the Debtor listed'
                    FROM DR_ACCS A
                    LEFT JOIN TAX_RATES R ON A.TAXSTATUS = R.SEQNO
                    LEFT JOIN TAX_KEY_POINT K ON K.COUNTRY = (SELECT COUNTRY FROM GENERAL_INFO) AND R.KEY_POINT = K.KEY_POINT
                    AND K.DR_LEDGER = 'Y'
                    WHERE A.TAXSTATUS <> -1 AND K.SEQNO IS NULL
                    ORDER BY A.ACCNO
              END
        END
        ELSE
        BEGIN
              IF CHARINDEX('L', @CONFIG) = 0
              BEGIN
                    INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
                    SELECT @HDR_SEQNO, 'Debtor tax rates are VALID', 'TEXT'
              END
        END
          --VERIFY DEBTOR PRIOR AGED BALANCE - ONLY VERIFYING IT- NOT FIXING IT
          SET NOCOUNT ON

          INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
          SELECT @HDR_SEQNO, MESSAGE = 'Checking Debtor Prior Aged Balances', 'TEXT'
        IF EXISTS(
        SELECT D.NAME
        FROM DR_ACCS D
        LEFT JOIN (
              SELECT A.ACCNO, PS.AGE, SUM(PREV_PERIOD_CLOSE) SUMPRIORAGEBAL
              FROM DR_ACCS A
              LEFT JOIN DR_TRANS T ON A.ACCNO = T.ACCNO
              JOIN PERIOD_STATUS PS ON T.PERIOD_SEQNO=PS.SEQNO
              WHERE PS.AGE = 1
              GROUP BY A.ACCNO, PS.AGE
        ) PRIOR0 ON D.ACCNO = PRIOR0.ACCNO
        LEFT JOIN (
              SELECT A.ACCNO, PS.AGE, SUM(PREV_PERIOD_CLOSE) SUMPRIORAGEBAL
              FROM DR_ACCS A
              LEFT JOIN DR_TRANS T ON A.ACCNO = T.ACCNO
              JOIN PERIOD_STATUS PS ON T.PERIOD_SEQNO=PS.SEQNO
              WHERE PS.AGE = 2
              GROUP BY A.ACCNO, PS.AGE
        ) PRIOR1 ON D.ACCNO = PRIOR1.ACCNO
        LEFT JOIN (
              SELECT A.ACCNO, PS.AGE, SUM(PREV_PERIOD_CLOSE) SUMPRIORAGEBAL
              FROM DR_ACCS A
              LEFT JOIN DR_TRANS T ON A.ACCNO = T.ACCNO
              JOIN PERIOD_STATUS PS ON T.PERIOD_SEQNO=PS.SEQNO
              WHERE PS.AGE = 3
              GROUP BY A.ACCNO, PS.AGE
        ) PRIOR2 ON D.ACCNO = PRIOR2.ACCNO
        LEFT JOIN (
              SELECT A.ACCNO, SUM(PREV_PERIOD_CLOSE) SUMPRIORAGEBAL
              FROM DR_ACCS A
              LEFT JOIN DR_TRANS T ON A.ACCNO = T.ACCNO
              JOIN PERIOD_STATUS PS ON T.PERIOD_SEQNO=PS.SEQNO
              WHERE PS.AGE > 3
              GROUP BY A.ACCNO
        ) PRIOR3 ON D.ACCNO = PRIOR3.ACCNO
        WHERE
              (ABS(ISNULL(PRIOR0.SUMPRIORAGEBAL, 0)- ISNULL(D.PRIOR_AGEDBAL0, 0))>0.009)
               OR (ABS(ISNULL(PRIOR1.SUMPRIORAGEBAL, 0)- ISNULL(D.PRIOR_AGEDBAL1, 0))>0.009)
               OR (ABS(ISNULL(PRIOR2.SUMPRIORAGEBAL, 0)- ISNULL(D.PRIOR_AGEDBAL2, 0))>0.009)
               OR (ABS(ISNULL(PRIOR3.SUMPRIORAGEBAL, 0)- ISNULL(D.PRIOR_AGEDBAL3, 0))>0.009)
          )
          BEGIN
        INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS, SOURCE_SEQ, LINETYPE)
        SELECT @HDR_SEQNO, MESSAGE =
          'Invalid Prior Aged Bals for Debtor a/c ''' + D.NAME + ''': '
          + ' Bal0= ' + convert(varchar, convert(money, isnull(D.PRIOR_AGEDBAL0, 0))) + ' Calc0= ' + convert(varchar, convert(money, isnull(PRIOR0.SUMPRIORAGEBAL, 0)))
          + '; Bal1= ' + convert(varchar, convert(money, isnull(D.PRIOR_AGEDBAL1, 0))) + ' Calc1= ' + convert(varchar, convert(money, isnull(PRIOR1.SUMPRIORAGEBAL, 0)))
          + '; Bal2= ' + convert(varchar, convert(money, isnull(D.PRIOR_AGEDBAL2, 0))) + ' Calc2= ' + convert(varchar, convert(money, isnull(PRIOR2.SUMPRIORAGEBAL, 0)))
          + '; Bal3= ' + convert(varchar, convert(money, isnull(D.PRIOR_AGEDBAL3, 0))) + ' Calc3= ' + convert(varchar, convert(money, isnull(PRIOR3.SUMPRIORAGEBAL, 0))),
          'D0003', D.ACCNO, 'ERROR'
        FROM DR_ACCS D
        LEFT JOIN (
              SELECT A.ACCNO, PS.AGE, SUM(PREV_PERIOD_CLOSE) SUMPRIORAGEBAL
              FROM DR_ACCS A
              LEFT JOIN DR_TRANS T ON A.ACCNO = T.ACCNO
              JOIN PERIOD_STATUS PS ON T.PERIOD_SEQNO=PS.SEQNO
              WHERE PS.AGE = 1
              GROUP BY A.ACCNO, PS.AGE
        ) PRIOR0 ON D.ACCNO = PRIOR0.ACCNO
        LEFT JOIN (
              SELECT A.ACCNO, PS.AGE, SUM(PREV_PERIOD_CLOSE) SUMPRIORAGEBAL
              FROM DR_ACCS A
              LEFT JOIN DR_TRANS T ON A.ACCNO = T.ACCNO
              JOIN PERIOD_STATUS PS ON T.PERIOD_SEQNO=PS.SEQNO
              WHERE PS.AGE = 2
              GROUP BY A.ACCNO, PS.AGE
        ) PRIOR1 ON D.ACCNO = PRIOR1.ACCNO
        LEFT JOIN (
              SELECT A.ACCNO, PS.AGE, SUM(PREV_PERIOD_CLOSE) SUMPRIORAGEBAL
              FROM DR_ACCS A
              LEFT JOIN DR_TRANS T ON A.ACCNO = T.ACCNO
              JOIN PERIOD_STATUS PS ON T.PERIOD_SEQNO=PS.SEQNO
              WHERE PS.AGE = 3
              GROUP BY A.ACCNO, PS.AGE
        ) PRIOR2 ON D.ACCNO = PRIOR2.ACCNO
        LEFT JOIN (
              SELECT A.ACCNO, SUM(PREV_PERIOD_CLOSE) SUMPRIORAGEBAL
              FROM DR_ACCS A
              LEFT JOIN DR_TRANS T ON A.ACCNO = T.ACCNO
              JOIN PERIOD_STATUS PS ON T.PERIOD_SEQNO=PS.SEQNO
              WHERE PS.AGE > 3
              GROUP BY A.ACCNO
        ) PRIOR3 ON D.ACCNO = PRIOR3.ACCNO
        WHERE
              (ABS(ISNULL(PRIOR0.SUMPRIORAGEBAL, 0)- ISNULL(D.PRIOR_AGEDBAL0, 0))>0.009)
               OR (ABS(ISNULL(PRIOR1.SUMPRIORAGEBAL, 0)- ISNULL(D.PRIOR_AGEDBAL1, 0))>0.009)
               OR (ABS(ISNULL(PRIOR2.SUMPRIORAGEBAL, 0)- ISNULL(D.PRIOR_AGEDBAL2, 0))>0.009)
               OR (ABS(ISNULL(PRIOR3.SUMPRIORAGEBAL, 0)- ISNULL(D.PRIOR_AGEDBAL3, 0))>0.009)
        END
          ELSE
          BEGIN
                    IF CHARINDEX('L', @CONFIG) = 0
                    BEGIN
                          INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
                          SELECT @HDR_SEQNO, MESSAGE = 'DEBTORS PRIOR BALANCES CORRECT', 'TEXT'
                    END
          END
          --VERIFY BALANCE IS CORRECT ON DR_ACCS BASED ON TRANSACTIONAL DATA
          SET NOCOUNT ON

        INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
        SELECT @HDR_SEQNO, MESSAGE = 'Checking Debtor Aged Balances', 'TEXT'

        IF EXISTS(
              SELECT D.NAME
              FROM DR_ACCS D
              LEFT JOIN (
                    SELECT A.ACCNO, PS.AGE, SUM(T.AMOUNT - T.ALLOCATEDBAL) SUMAGEBAL
                    FROM DR_ACCS A
                    LEFT JOIN DR_TRANS T ON A.ACCNO = T.ACCNO AND T.ALLOCATED = '0'
                    JOIN PERIOD_STATUS PS ON T.PERIOD_SEQNO=PS.SEQNO
                    WHERE PS.AGE = 0
                    GROUP BY A.ACCNO, PS.AGE
              ) AGE0 ON D.ACCNO = AGE0.ACCNO
              LEFT JOIN (
                    SELECT A.ACCNO, PS.AGE, SUM(T.AMOUNT - T.ALLOCATEDBAL) SUMAGEBAL
                    FROM DR_ACCS A
                    LEFT JOIN DR_TRANS T ON A.ACCNO = T.ACCNO AND T.ALLOCATED = '0'
                    JOIN PERIOD_STATUS PS ON T.PERIOD_SEQNO=PS.SEQNO
                    WHERE PS.AGE = 1
                    GROUP BY A.ACCNO, PS.AGE
              ) AGE1 ON D.ACCNO = AGE1.ACCNO
              LEFT JOIN (
                    SELECT A.ACCNO, PS.AGE, SUM(T.AMOUNT - T.ALLOCATEDBAL) SUMAGEBAL
                    FROM DR_ACCS A
                    LEFT JOIN DR_TRANS T ON A.ACCNO = T.ACCNO AND T.ALLOCATED = '0'
                    JOIN PERIOD_STATUS PS ON T.PERIOD_SEQNO=PS.SEQNO
                    WHERE PS.AGE = 2
                    GROUP BY A.ACCNO, PS.AGE
              ) AGE2 ON D.ACCNO = AGE2.ACCNO
              LEFT JOIN (
                    SELECT A.ACCNO, SUM(T.AMOUNT - T.ALLOCATEDBAL) SUMAGEBAL
                    FROM DR_ACCS A
                    LEFT JOIN DR_TRANS T ON A.ACCNO = T.ACCNO AND T.ALLOCATED = '0'
                    JOIN PERIOD_STATUS PS ON T.PERIOD_SEQNO=PS.SEQNO
                    WHERE PS.AGE >= 3
                    GROUP BY A.ACCNO
              ) AGE3 ON D.ACCNO = AGE3.ACCNO
        WHERE
              (ABS(ISNULL(AGE0.SUMAGEBAL, 0)- ISNULL(D.AGEDBAL0, 0))>0.009)
               OR (ABS(ISNULL(AGE1.SUMAGEBAL, 0)- ISNULL(D.AGEDBAL1, 0))>0.009)
               OR (ABS(ISNULL(AGE2.SUMAGEBAL, 0)- ISNULL(D.AGEDBAL2, 0))>0.009)
               OR (ABS(ISNULL(AGE3.SUMAGEBAL, 0)- ISNULL(D.AGEDBAL3, 0))>0.009)
        )
        BEGIN
        INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS, SOURCE_SEQ, LINETYPE)
        SELECT @HDR_SEQNO, MESSAGE =
        'Invalid Aged Bals for Debtor a/c ''' + D.NAME + ''': '
         + ' Bal0= ' + convert(varchar, convert(money, isnull(D.AGEDBAL0, 0))) + ' Calc0= ' + convert(varchar, convert(money, isnull(AGE0.SUMAGEBAL, 0)))
         + '; Bal1= ' + convert(varchar, convert(money, isnull(D.AGEDBAL1, 0))) + ' Calc1= ' + convert(varchar, convert(money, isnull(AGE1.SUMAGEBAL, 0)))
         + '; Bal2= ' + convert(varchar, convert(money, isnull(D.AGEDBAL2, 0))) + ' Calc2= ' + convert(varchar, convert(money, isnull(AGE2.SUMAGEBAL, 0)))
         + '; Bal3= ' + convert(varchar, convert(money, isnull(D.AGEDBAL3, 0))) + ' Calc3= ' + convert(varchar, convert(money, isnull(AGE3.SUMAGEBAL, 0))),
        'D0004', D.ACCNO, 'ERROR'
              FROM DR_ACCS D
              LEFT JOIN (
                    SELECT A.ACCNO, PS.AGE, SUM(T.AMOUNT - T.ALLOCATEDBAL) SUMAGEBAL
                    FROM DR_ACCS A
                    LEFT JOIN DR_TRANS T ON A.ACCNO = T.ACCNO AND T.ALLOCATED = '0'
                    JOIN PERIOD_STATUS PS ON T.PERIOD_SEQNO=PS.SEQNO
                    WHERE PS.AGE = 0
                    GROUP BY A.ACCNO, PS.AGE
              ) AGE0 ON D.ACCNO = AGE0.ACCNO
              LEFT JOIN (
                    SELECT A.ACCNO, PS.AGE, SUM(T.AMOUNT - T.ALLOCATEDBAL) SUMAGEBAL
                    FROM DR_ACCS A
                    LEFT JOIN DR_TRANS T ON A.ACCNO = T.ACCNO AND T.ALLOCATED = '0'
                    JOIN PERIOD_STATUS PS ON T.PERIOD_SEQNO=PS.SEQNO
                    WHERE PS.AGE = 1
                    GROUP BY A.ACCNO, PS.AGE
              ) AGE1 ON D.ACCNO = AGE1.ACCNO
              LEFT JOIN (
                    SELECT A.ACCNO, PS.AGE, SUM(T.AMOUNT - T.ALLOCATEDBAL) SUMAGEBAL
                    FROM DR_ACCS A
                    LEFT JOIN DR_TRANS T ON A.ACCNO = T.ACCNO AND T.ALLOCATED = '0'
                    JOIN PERIOD_STATUS PS ON T.PERIOD_SEQNO=PS.SEQNO
                    WHERE PS.AGE = 2
                    GROUP BY A.ACCNO, PS.AGE
              ) AGE2 ON D.ACCNO = AGE2.ACCNO
              LEFT JOIN (
                    SELECT A.ACCNO, SUM(T.AMOUNT - T.ALLOCATEDBAL) SUMAGEBAL
                    FROM DR_ACCS A
                    LEFT JOIN DR_TRANS T ON A.ACCNO = T.ACCNO AND T.ALLOCATED = '0'
                    JOIN PERIOD_STATUS PS ON T.PERIOD_SEQNO=PS.SEQNO
                    WHERE PS.AGE >= 3
                    GROUP BY A.ACCNO
              ) AGE3 ON D.ACCNO = AGE3.ACCNO
        WHERE
              (ABS(ISNULL(AGE0.SUMAGEBAL, 0)- ISNULL(D.AGEDBAL0, 0))>0.009)
               OR (ABS(ISNULL(AGE1.SUMAGEBAL, 0)- ISNULL(D.AGEDBAL1, 0))>0.009)
               OR (ABS(ISNULL(AGE2.SUMAGEBAL, 0)- ISNULL(D.AGEDBAL2, 0))>0.009)
               OR (ABS(ISNULL(AGE3.SUMAGEBAL, 0)- ISNULL(D.AGEDBAL3, 0))>0.009)

              IF CHARINDEX('Y', @CONFIG) <> 0
              BEGIN
                    INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
                    SELECT @HDR_SEQNO, MESSAGE = 'Fixing Debtors Aged Balances', 'TEXT'

                    UPDATE D
                    SET AGEDBAL0 = ISNULL(AGE0.SUMAGEBAL, 0),
                          AGEDBAL1 = ISNULL(AGE1.SUMAGEBAL, 0),
                          AGEDBAL2 = ISNULL(AGE2.SUMAGEBAL, 0),
                          AGEDBAL3 = ISNULL(AGE3.SUMAGEBAL, 0)
                    FROM DR_ACCS D
                    LEFT JOIN (
                          SELECT A.ACCNO, PS.AGE, SUM(T.AMOUNT - T.ALLOCATEDBAL) SUMAGEBAL
                          FROM DR_ACCS A
                          LEFT JOIN DR_TRANS T ON A.ACCNO = T.ACCNO AND T.ALLOCATED = '0'
                          JOIN PERIOD_STATUS PS ON T.PERIOD_SEQNO=PS.SEQNO
                          WHERE PS.AGE = 0
                          GROUP BY A.ACCNO, PS.AGE
                    ) AGE0 ON D.ACCNO = AGE0.ACCNO
                    LEFT JOIN (
                          SELECT A.ACCNO, PS.AGE, SUM(T.AMOUNT - T.ALLOCATEDBAL) SUMAGEBAL
                          FROM DR_ACCS A
                          LEFT JOIN DR_TRANS T ON A.ACCNO = T.ACCNO AND T.ALLOCATED = '0'
                          JOIN PERIOD_STATUS PS ON T.PERIOD_SEQNO=PS.SEQNO
                          WHERE PS.AGE = 1
                          GROUP BY A.ACCNO, PS.AGE
                    ) AGE1 ON D.ACCNO = AGE1.ACCNO
                    LEFT JOIN (
                          SELECT A.ACCNO, PS.AGE, SUM(T.AMOUNT - T.ALLOCATEDBAL) SUMAGEBAL
                          FROM DR_ACCS A
                          LEFT JOIN DR_TRANS T ON A.ACCNO = T.ACCNO AND T.ALLOCATED = '0'
                          JOIN PERIOD_STATUS PS ON T.PERIOD_SEQNO=PS.SEQNO
                          WHERE PS.AGE = 2
                          GROUP BY A.ACCNO, PS.AGE
                    ) AGE2 ON D.ACCNO = AGE2.ACCNO
                    LEFT JOIN (
                          SELECT A.ACCNO, SUM(T.AMOUNT - T.ALLOCATEDBAL) SUMAGEBAL
                          FROM DR_ACCS A
                          LEFT JOIN DR_TRANS T ON A.ACCNO = T.ACCNO AND T.ALLOCATED = '0'
                          JOIN PERIOD_STATUS PS ON T.PERIOD_SEQNO=PS.SEQNO
                          WHERE PS.AGE >= 3
                          GROUP BY A.ACCNO
                    ) AGE3 ON D.ACCNO = AGE3.ACCNO

                    INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
                    SELECT @HDR_SEQNO, 'DONE', 'TEXT'
              END
        END
        ELSE
        BEGIN
              IF CHARINDEX('L', @CONFIG) = 0
              BEGIN
                    INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
                    SELECT @HDR_SEQNO, 'DEBTORS CORRECT', 'TEXT'
              END
        END

      -- CHECK ORPHAN INVOICE LINES
      INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
      SELECT @HDR_SEQNO, 'Verify Orphan Debtor Invoice Lines', 'TEXT'

      IF EXISTS (
SELECT I.INVNO
          FROM DR_INVLINES I
LEFT JOIN DR_TRANS T ON T.SEQNO = I.HDR_SEQNO
WHERE T.SEQNO IS NULL
      )
      BEGIN

INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS, SOURCE_SEQ, LINETYPE)
SELECT @HDR_SEQNO, MESSAGE =
'Invalid invoice lines for Debtor a/c ' + I.INVNO + '',
'D0005', I.SEQNO, 'ERROR'
FROM DR_INVLINES I
LEFT JOIN DR_TRANS T ON T.SEQNO = I.HDR_SEQNO
WHERE T.SEQNO IS NULL

INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, ' ', 'TEXT'
END
ELSE
BEGIN
IF CHARINDEX('L', @CONFIG) = 0
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'INVOICE LINE ON DEBTOR CORRECT', 'TEXT'
END

END

      -- CHECK FOR INVALID STOCKCODES
      INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
      SELECT @HDR_SEQNO, 'Verify Stockcodes on Debtor', 'TEXT'

      IF EXISTS (
SELECT DI.STOCKCODE, DI.BOMTYPE, DI.DESCRIPTION
FROM DR_INVLINES DI
LEFT JOIN STOCK_ITEMS SI ON SI.STOCKCODE = DI.STOCKCODE
LEFT JOIN DR_TRANS T ON DI.HDR_SEQNO = T.SEQNO
JOIN PERIOD_STATUS PS ON T.PERIOD_SEQNO=PS.SEQNO
WHERE SI.STOCKCODE IS NULL
AND DI.STOCKCODE <> ''
AND (CHARINDEX('.', DI.STOCKCODE)=0 AND DI.STOCKCODE <> 'N')
AND PS.AGE <= @STARTPERIOD AND PS.AGE >= @ENDPERIOD
      )
      BEGIN

INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS, SOURCE_SEQ, LINETYPE)
          SELECT @HDR_SEQNO, ' Inv# ' + DI.INVNO + ' Dated: ' + CONVERT(VARCHAR, DI.TRANSDATE, 3)
+ ' - ERROR!
Account = ' + CONVERT(VARCHAR, DI.ACCNO) + '
Invalid STOCKCODES: ' + REPLACE(DI.STOCKCODE, '.', '') + ' BOMTYPE : ' + DI.BOMTYPE + '
Description : ' + DI.DESCRIPTION + ' ',
'D0006', DI.SEQNO, 'ERROR'
FROM DR_INVLINES DI
LEFT JOIN STOCK_ITEMS SI ON SI.STOCKCODE = DI.STOCKCODE
LEFT JOIN DR_TRANS T ON DI.HDR_SEQNO = T.SEQNO
JOIN PERIOD_STATUS PS ON T.PERIOD_SEQNO=PS.SEQNO
WHERE SI.STOCKCODE IS NULL
AND DI.STOCKCODE <> ''
AND (CHARINDEX('.', DI.STOCKCODE)=0 AND DI.STOCKCODE <> 'N')
AND PS.AGE <= @STARTPERIOD AND PS.AGE >= @ENDPERIOD
END
ELSE
BEGIN
IF CHARINDEX('L', @CONFIG) = 0
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'STOCKCODES ON DEBTOR CORRECT', 'TEXT'
END

END

      -- CHECK FOR INVALID GLCODES
      INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
      SELECT @HDR_SEQNO, 'Verify Analysis GL CODE on Debtor', 'TEXT'

      IF EXISTS (
          SELECT I.ANALYSIS, A.ACCNO
          FROM DR_INVLINES I
          LEFT JOIN GLACCS A ON I.ANALYSIS = A.ACCNO
          LEFT JOIN DR_TRANS T ON I.HDR_SEQNO = T.SEQNO
JOIN PERIOD_STATUS PS ON T.PERIOD_SEQNO=PS.SEQNO
          WHERE (I.ANALYSIS <> 0 AND A.ACCNO IS NULL )
          AND PS.AGE <= @STARTPERIOD AND PS.AGE >= @ENDPERIOD
      )
      BEGIN
          INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS, SOURCE_SEQ, LINETYPE)
          SELECT @HDR_SEQNO, MESSAGE = ' Inv# ' + I.INVNO +
                    + ' - ERROR!
          Stock Code = ' + CONVERT(VARCHAR, I.STOCKCODE) + '
          Batch = ' + CONVERT(VARCHAR, I.BATCHCODE) + '
          DR Analysis GL Code = ' + CONVERT(VARCHAR, I.ANALYSIS) + ' ',
          'D0007', I.SEQNO, 'ERROR'
              FROM DR_INVLINES I
          LEFT JOIN GLACCS A ON I.ANALYSIS = A.ACCNO
          LEFT JOIN DR_TRANS T ON I.HDR_SEQNO = T.SEQNO
JOIN PERIOD_STATUS PS ON T.PERIOD_SEQNO=PS.SEQNO
          WHERE (I.ANALYSIS <> 0 AND A.ACCNO IS NULL )
          AND PS.AGE <= @STARTPERIOD AND PS.AGE >= @ENDPERIOD

          INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE)
          SELECT @HDR_SEQNO, ' '
        END
        ELSE
        BEGIN
              IF CHARINDEX('L', @CONFIG) = 0
              BEGIN
                    INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
                    SELECT @HDR_SEQNO, 'ANALYSIS GL CODE ON DEBTOR CORRECT', 'TEXT'
              END
        END

      -- CHECK FOR INVALID BRANCH
      INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
      SELECT @HDR_SEQNO, 'Verify Branch on Debtor', 'TEXT'

      IF EXISTS (
SELECT DEBTOR.BRANCHNO, DEBTOR.INVNO
FROM (
SELECT I.BRANCHNO, I.INVNO FROM DR_INVLINES I
LEFT JOIN DR_TRANS T ON I.HDR_SEQNO = T.SEQNO
              JOIN PERIOD_STATUS PS ON T.PERIOD_SEQNO=PS.SEQNO
WHERE PS.AGE <= @STARTPERIOD AND PS.AGE >= @ENDPERIOD
UNION
SELECT T.BRANCHNO, T.INVNO FROM DR_TRANS T
JOIN PERIOD_STATUS PS ON T.PERIOD_SEQNO=PS.SEQNO
WHERE PS.AGE <= @STARTPERIOD AND PS.AGE >= @ENDPERIOD
) AS DEBTOR
LEFT JOIN BRANCHES B ON DEBTOR.BRANCHNO = B.BRANCHNO
WHERE (B.BRANCHNO IS NULL)
      )
      BEGIN
          INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS, SOURCE_SEQ, LINETYPE)
          SELECT @HDR_SEQNO, MESSAGE = ' Inv# ' + DEBTOR.INVNO +
                    + ' - ERROR!
          Branch No = ' + CONVERT(VARCHAR, DEBTOR.BRANCHNO) + ' ',
          'D0008', DEBTOR.SEQNO, 'ERROR'
          FROM (
SELECT I.BRANCHNO, I.INVNO, I.SEQNO FROM DR_INVLINES I
LEFT JOIN DR_TRANS T ON I.HDR_SEQNO = T.SEQNO
              JOIN PERIOD_STATUS PS ON T.PERIOD_SEQNO=PS.SEQNO
WHERE PS.AGE <= @STARTPERIOD AND PS.AGE >= @ENDPERIOD
UNION
SELECT T.BRANCHNO, T.INVNO, T.SEQNO FROM DR_TRANS T
JOIN PERIOD_STATUS PS ON T.PERIOD_SEQNO=PS.SEQNO
WHERE PS.AGE <= @STARTPERIOD AND PS.AGE >= @ENDPERIOD
) AS DEBTOR
LEFT JOIN BRANCHES B ON DEBTOR.BRANCHNO = B.BRANCHNO
WHERE (B.BRANCHNO IS NULL)

          INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
          SELECT @HDR_SEQNO, ' ', 'TEXT'
      END
      ELSE
      BEGIN
IF CHARINDEX('L', @CONFIG) = 0
          BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
              SELECT @HDR_SEQNO, 'BRANCH ON DEBTOR CORRECT', 'TEXT'
          END
      END

      -- CHECK FOR MULTIPLE GL POSTING
      SET NOCOUNT ON
      INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
      SELECT @HDR_SEQNO, 'Verify GL Posting on Debtor Transaction', 'TEXT'

        IF EXISTS (
              SELECT T.SEQNO, T.INVNO, T.TRANSDATE, T.ACCNO, T.AGE, T.BATCHNO, T.AMOUNT, GL.GLPOSTING
              FROM DR_TRANS T
              LEFT JOIN (
                          SELECT G.SOURCE_SEQ, COUNT(SOURCE_SEQ) AS GLPOSTING
                          FROM GLTRANS G
                          INNER JOIN DR_TRANS D ON D.SEQNO = G.SOURCE_SEQ AND G.SOURCE = 'd' AND G.SOURCE_INVLINEID = -1 AND CONVERT(MONEY, G.FCAMOUNT) = CONVERT(MONEY, D.AMOUNT)
                          GROUP BY G.SOURCE_SEQ
              ) GL ON T.SEQNO = GL.SOURCE_SEQ
JOIN PERIOD_STATUS PS ON T.PERIOD_SEQNO=PS.SEQNO
              WHERE GL.GLPOSTING > 1
              AND PS.AGE <= @STARTPERIOD AND PS.AGE >= @ENDPERIOD
      )
      BEGIN
          INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS, SOURCE_SEQ, LINETYPE)
           SELECT @HDR_SEQNO , MESSAGE = ' Inv# ' + T.INVNO + ' Dated: ' + CONVERT(VARCHAR, T.TRANSDATE, 3)
              + ' - ERROR!
Account = ' + CONVERT(VARCHAR, T.ACCNO) + '
Age = ' + CONVERT(VARCHAR, T.AGE) + '
Amount = ' + CONVERT(VARCHAR, CONVERT(MONEY, T.AMOUNT )) + '
              GL Posting times = ' + CONVERT(VARCHAR, GL.GLPOSTING) + ' ',
              'D0009', T.SEQNO, 'ERROR'
              FROM DR_TRANS T
              LEFT JOIN (
                          SELECT G.SOURCE_SEQ, COUNT(SOURCE_SEQ) AS GLPOSTING
                          FROM GLTRANS G
                          INNER JOIN DR_TRANS D ON D.SEQNO = G.SOURCE_SEQ AND G.SOURCE = 'd' AND G.SOURCE_INVLINEID = -1 AND CONVERT(MONEY, G.FCAMOUNT) = CONVERT(MONEY, D.AMOUNT)
                          GROUP BY G.SOURCE_SEQ
              ) GL ON T.SEQNO = GL.SOURCE_SEQ
JOIN PERIOD_STATUS PS ON T.PERIOD_SEQNO=PS.SEQNO
              WHERE GL.GLPOSTING > 1
AND PS.AGE <= @STARTPERIOD AND PS.AGE >= @ENDPERIOD

          INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE)
          SELECT @HDR_SEQNO, ' '
      END
      ELSE
      BEGIN
          IF CHARINDEX('L', @CONFIG) = 0
          BEGIN
                    INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
              SELECT @HDR_SEQNO, 'GL POSTING ON DEBTOR TRANSACTION CORRECT', 'TEXT'
          END
      END

  END

  IF CHARINDEX('I', @CONFIG) <> 0 AND CHARINDEX('D', @CONFIG) <> 0
  BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'Verify DR_TRAN header balance matches line totals', 'TEXT'
IF EXISTS(
SELECT DT.ACCNO FROM DR_TRANS DT
LEFT JOIN (
SELECT HDR_SEQNO, SUM(CONVERT(MONEY, ISNULL(LINETOTAL, 0))) AS LINETOTAL
FROM DR_INVLINES
GROUP BY HDR_SEQNO
) DL ON DT.SEQNO = DL.HDR_SEQNO
JOIN PERIOD_STATUS PS ON DT.PERIOD_SEQNO=PS.SEQNO
WHERE DT.TRANSTYPE = 1 AND ABS(SUBTOTAL - LINETOTAL) > 0.009
AND PS.AGE <= @STARTPERIOD AND PS.AGE >= @ENDPERIOD
)
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS, SOURCE_SEQ, LINETYPE)
SELECT @HDR_SEQNO, 'A/c ' + CONVERT(VARCHAR, DT.ACCNO) + ' Inv# ' + DT.INVNO + ' Dated: ' + CONVERT(VARCHAR, DT.TRANSDATE, 3)
+ ' - ERROR!
Header Sequence = ' + CONVERT(VARCHAR, DT.SEQNO) + '
Header Subtotal = ' + CONVERT(VARCHAR, CONVERT(MONEY, SUBTOTAL)) + '
Inv Lines Total = ' + CONVERT(VARCHAR, CONVERT(MONEY, LINETOTAL)) + '
Inv Imbalance = ' + CONVERT(VARCHAR, CONVERT(MONEY, SUBTOTAL - LINETOTAL)) + ' ',
'D0010', DT.SEQNO, 'ERROR'
FROM DR_TRANS DT
LEFT JOIN (
SELECT HDR_SEQNO, SUM(CONVERT(MONEY, ISNULL(LINETOTAL, 0))) AS LINETOTAL
FROM DR_INVLINES
GROUP BY HDR_SEQNO
) DL ON DT.SEQNO = DL.HDR_SEQNO
JOIN PERIOD_STATUS PS ON DT.PERIOD_SEQNO=PS.SEQNO
WHERE DT.TRANSTYPE = 1 AND ABS(SUBTOTAL - LINETOTAL) > 0.009
AND PS.AGE <= @STARTPERIOD AND PS.AGE >= @ENDPERIOD
ORDER BY DT.INVNO

INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, CONVERT(VARCHAR, @@ROWCOUNT) + ' Invoice Errors', 'TEXT'

--MYOB MIGRATION ADDED FUNCTIONALITY
IF CHARINDEX('N', @CONFIG) <> 0 AND (SELECT COUNT(NAME) FROM SYSOBJECTS WHERE NAME = 'MYOB_IMPORT_EXCEPTIONS') = 1
BEGIN
--ADD ROWS TO MYOB_IMPORT_EXCEPTIONS FOR DR_TRAN RECORDS WHERE HEADER BALANCE DOES NOT EQUAL LINE TOTALS
INSERT INTO MYOB_IMPORT_EXCEPTIONS (EXONET_TABLE_NAME, SOURCE_TYPE, DESTINATION_REF_NO, PROBLEM_COLUMN,
PROBLEM_DESCRIPTION, PROBLEM_RESOLUTION)
SELECT 'DR_TRANS', 'MYGRATE', DT.INVNO, 'LINE_TOTAL',
'HEADER BALANCE DOES NOT MATCH LINE TOTALS BY ' + CONVERT(VARCHAR, CONVERT(MONEY, SUBTOTAL - LINETOTAL)),
'Debtor Transaction Header does not match line totals. Data needs to be checks for this invoice in the database'
FROM DR_TRANS DT
LEFT JOIN (
SELECT HDR_SEQNO, SUM(CONVERT(MONEY, ISNULL(LINETOTAL, 0))) AS LINETOTAL
FROM DR_INVLINES
GROUP BY HDR_SEQNO
) DL ON DT.SEQNO = DL.HDR_SEQNO
JOIN PERIOD_STATUS PS ON DT.PERIOD_SEQNO=PS.SEQNO
WHERE DT.TRANSTYPE = 1 AND ABS(SUBTOTAL - LINETOTAL) > 0.009 AND PS.AGE = 0
ORDER BY DT.INVNO
END
END
ELSE
BEGIN
IF CHARINDEX('L', @CONFIG) = 0
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'No Debtor Invoice Errors found', 'TEXT'
END
END
  END

  --VERIFY DR_TRANS HEADER ALLOCATED BALANCE MATCHES ALLOCATION TOTALS
  IF CHARINDEX('A', @CONFIG) <> 0 AND CHARINDEX('D', @CONFIG) <> 0
  BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'Verify DR_TRANS header Allocated Balance matches Allocation totals', 'TEXT'
IF EXISTS(
SELECT DT.ACCNO FROM DR_TRANS DT
LEFT JOIN (
SELECT TRANS_SEQNO, SUM(CONVERT(MONEY, ISNULL(AMOUNT, 0))) AS ALLOCTOTAL
FROM DR_ALLOCATIONS
GROUP BY TRANS_SEQNO
) DA ON DT.SEQNO = DA.TRANS_SEQNO
JOIN PERIOD_STATUS PS ON DT.PERIOD_SEQNO=PS.SEQNO
WHERE ABS(DT.ALLOCATEDBAL) - ABS(DA.ALLOCTOTAL) > 0.009
AND PS.AGE <= @STARTPERIOD AND PS.AGE >= @ENDPERIOD
)
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS, SOURCE_SEQ, LINETYPE)
SELECT @HDR_SEQNO, 'A/c ' + CONVERT(VARCHAR, DT.ACCNO) + ' Transaction Dated: ' + CONVERT(VARCHAR, DT.TRANSDATE, 3)
+ ' - ERROR!
Header Sequence = ' + CONVERT(VARCHAR, DT.SEQNO) + '
Header AllocatedBal = ' + CONVERT(VARCHAR, CONVERT(MONEY, ALLOCATEDBAL)) + '
Allocation Lines Total = ' + CONVERT(VARCHAR, CONVERT(MONEY, ALLOCTOTAL)) + '
Allocation Imbalance = ' + CONVERT(VARCHAR, CONVERT(MONEY, ALLOCATEDBAL - ALLOCTOTAL)) + ' ',
'D0011', DT.SEQNO, 'ERROR'
FROM DR_TRANS DT
LEFT JOIN (
SELECT TRANS_SEQNO, SUM(CONVERT(MONEY, ISNULL(AMOUNT, 0))) AS ALLOCTOTAL
FROM DR_ALLOCATIONS
GROUP BY TRANS_SEQNO
) DA ON DT.SEQNO = DA.TRANS_SEQNO
JOIN PERIOD_STATUS PS ON DT.PERIOD_SEQNO=PS.SEQNO
WHERE ABS(DT.ALLOCATEDBAL) - ABS(DA.ALLOCTOTAL) > 0.009
AND PS.AGE <= @STARTPERIOD AND PS.AGE >= @ENDPERIOD
ORDER BY DT.SEQNO

INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, CONVERT(VARCHAR, @@ROWCOUNT) + ' Allocation Errors', 'TEXT'
END
ELSE
BEGIN
IF CHARINDEX('L', @CONFIG) = 0
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'No Debtor Allocation Errors found', 'TEXT'
END
END
  END

  --CHECK FOR NULL TRANS_SEQNO IN DEBTOR ALLOCATIONS
  IF CHARINDEX('A', @CONFIG) <> 0 AND CHARINDEX('D', @CONFIG) <> 0
  BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'Check for Orphan Debtor Allocation sets', 'TEXT'
IF EXISTS(
SELECT DA.ALLOCNO FROM DR_ALLOCATIONS DA
JOIN PERIOD_STATUS PS ON DA.PERIOD_SEQNO=PS.SEQNO
WHERE DA.TRANS_SEQNO IS NULL
AND PS.AGE <= @STARTPERIOD AND PS.AGE >= @ENDPERIOD
)
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS, SOURCE_SEQ, LINETYPE)
SELECT @HDR_SEQNO, 'Alloc No. ' + CONVERT(VARCHAR, DA.ALLOCNO) + ' has no Debtor Transactions linked to it',
'D0012', DA.ALLOCNO, 'ERROR'
FROM DR_ALLOCATIONS DA
JOIN PERIOD_STATUS PS ON DA.PERIOD_SEQNO=PS.SEQNO
WHERE DA.TRANS_SEQNO IS NULL
AND PS.AGE <= @STARTPERIOD AND PS.AGE >= @ENDPERIOD
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
VALUES (@HDR_SEQNO, (CONVERT(VARCHAR, @@ROWCOUNT) + ' Debtor Allocation Errors- Orphan allocation Sets' ), 'TEXT')
END
ELSE
BEGIN
IF CHARINDEX('L', @CONFIG) = 0
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'No Debtor Orphan Allocation Sets found', 'TEXT'
END
END
  END

  IF @STANDALONE = 'Y'
  BEGIN
    INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
    SELECT @HDR_SEQNO, 'Verification Completed '
      + LEFT(CONVERT(VARCHAR, GETDATE(), 109), 50) + ' '
      + CONVERT(VARCHAR(5), DATEDIFF(SECOND, (SELECT CREATEDATE FROM VERIFICATION_HDR WHERE SEQNO = @HDR_SEQNO), GETDATE())) + ' Seconds', 'TEXT'

    SELECT MESSAGE FROM VERIFICATION_LINES WHERE HDR_SEQNO = @HDR_SEQNO
  END
  ELSE
  BEGIN
    SET @ENDTIME = GETDATE()
    INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
    SELECT @HDR_SEQNO, 'Duration for debtor verification: '
      + CONVERT(VARCHAR(5), DATEDIFF(SECOND, @STARTTIME, @ENDTIME)) + ' Seconds', 'TEXT'
  END

END


Procedure: DATA_VERIFICATION_DRACCBALANCING
NameDATA_VERIFICATION_DRACCBALANCING
Note
CodeCREATE PROCEDURE [dbo].[DATA_VERIFICATION_DRACCBALANCING]
    @CONFIG CHAR(10) = 'DCGIAMS$',
    @HDR_SEQNO INT = -1,
    @STANDALONE CHAR(1)= 'Y'
AS
BEGIN

  SET NOCOUNT ON

  DECLARE @OUTPUT VARCHAR(512),
@IMBALANCES DOUBLE PRECISION,
@RECEIVEABLE DOUBLE PRECISION,
@FOREXTOTAL DOUBLE PRECISION,
@DR_TRANS_AMOUNT DOUBLE PRECISION,
@GL_CONTROL_AMOUNT DOUBLE PRECISION,
@GL_CONTROL_FCAMOUNT DOUBLE PRECISION,
@FOREXTOTAL1AMOUNT DOUBLE PRECISION,
@MYGRATETOTALAMOUNT DOUBLE PRECISION,
@Current_period_seqno integer,
@STARTTIME DATETIME,
@ENDTIME DATETIME

  SET @STARTTIME = GETDATE()


  select @Current_period_seqno = seqno from period_status where age = 0 and Ledger = 'G'

  IF @CONFIG = 'Y'
  BEGIN
SET @CONFIG = 'YDCGIAMS$'
  END

  IF @CONFIG = 'N'
  BEGIN
SET @CONFIG = 'NDCGIAMS$'
  END

  IF @STANDALONE = 'Y'
  BEGIN
INSERT INTO VERIFICATION_HDR (CONFIG_FLAG, CREATED_BY, CREATEDATE )
SELECT @CONFIG, [dbo].FN_GET_STAFF_NO() , GETDATE()

SELECT @HDR_SEQNO = (SELECT MAX(SEQNO) FROM VERIFICATION_HDR)

      --DATA VERIFICATION BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'MYOB EXO Business DATA VERIFICATION ' + CONVERT(VARCHAR, GETDATE()), 'TEXT'

SELECT @OUTPUT = USERNAME FROM GENERAL_INFO
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'Company Name: ' + @OUTPUT, 'TEXT'

SELECT @OUTPUT = SOFTWARE_VERSION FROM GENERAL_INFO
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'MYOB EXO Business Database Version: ' + @OUTPUT, 'TEXT'

IF CHARINDEX('L', @CONFIG) = 0
BEGIN
SELECT @OUTPUT = 'MYOB EXO Business Database configured for ' + COUNTRY_NAME FROM GENERAL_INFO G
JOIN COUNTRY C ON G.COUNTRY = C.COUNTRY_CODE
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, @OUTPUT, 'TEXT'
END

IF CHARINDEX('Y', @CONFIG) <> 0
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'Fix Imbalance is ''ON''', 'TEXT'
END
ELSE
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'Fix Imbalance is ''OFF''', 'TEXT'
END

IF CHARINDEX('N', @CONFIG) <> 0
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'MYOB VERIFICATION ''ON''', 'TEXT'
END
  END

  --CHECK FOR DEBTOR LEDGER AGAINST GL CONTROL ACCOUNT FOR IMBALANCES
  IF CHARINDEX('D', @CONFIG) <> 0
  BEGIN
      -- CHECK IMBALANCES
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'MYOB EXO Business DATA VERIFICATION ' + CONVERT(VARCHAR, GETDATE()), 'TEXT'

INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'Verify Debtor Ledger balances with Debtor control account', 'TEXT'

set @GL_CONTROL_AMOUNT = isnull((select dbo.FN_GetDrControlAccBalance(@Current_period_seqno)), 0)
set @MYGRATETOTALAMOUNT = isnull((select dbo.FN_GetDrFxMygrateExcep()), 0)
set @FOREXTOTAL = isnull((select dbo.FN_GetDrControlFXVariance(@Current_period_seqno)) - (select dbo.FN_GetDrFxMygrateExcep()), 0)
set @RECEIVEABLE = isnull((select sum(balance) as Ledgeramount from fn_dr_agedbalances_backwards_summary(@Current_period_seqno, 'N')), 0)
- @MYGRATETOTALAMOUNT
set @IMBALANCES = isnull((@RECEIVEABLE - @GL_CONTROL_AMOUNT), 0)




INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, ' Receivable Value : ' + CONVERT(VARCHAR, CONVERT(MONEY, @RECEIVEABLE)), 'TEXT'

INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, ' Account Balances : ' + CONVERT(VARCHAR, CONVERT(MONEY, @GL_CONTROL_AMOUNT)), 'TEXT'

IF ABS(ISNULL(@IMBALANCES, 0)) >0.009
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS, SOURCE_SEQ, LINETYPE)
SELECT @HDR_SEQNO, ' Imbalance Amount : ' + CONVERT(VARCHAR, CONVERT(MONEY, @IMBALANCES)), 'DB008', '', 'ERROR'
END
ELSE
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, ' Imbalance Amount : ' + CONVERT(VARCHAR, CONVERT(MONEY, @IMBALANCES)), 'TEXT'
END

--INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
--SELECT @HDR_SEQNO, ' FOREX Variance : ' + CONVERT(VARCHAR, CONVERT(MONEY, @FOREXTOTAL)), 'TEXT'

IF ABS(ISNULL(@IMBALANCES, 0)) >0.009 and (CHARINDEX('L', @CONFIG) = 0)
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, ' ', 'TEXT'

INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'Possible Causes of Imbalances : ', 'TEXT'



-- UNPOSTED TRANSACTIONS
IF EXISTS (
Select * from [FN_GET_DEBTORSLEDGER_IMBALANCEREASONS](0, DEFAULT, 'DB001')
)
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'Unposted Transactions', 'TEXT'
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, '------------------------------------------', 'TEXT'

INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS, SOURCE_SEQ, LINETYPE)
SELECT @HDR_SEQNO, ' Inv# ' + INVNO + ' Dated: ' + CONVERT(VARCHAR, transaction_date, 3)
+ ' -
Name = ' + CONVERT(VARCHAR, accname) + '
Trans Type = ' + CONVERT(VARCHAR, transaction_type) + '
Deposit Status = ' + CONVERT(VARCHAR, DEPOSIT_STATUS) + '
Age = ' + CONVERT(VARCHAR, period) + '
Amount = ' + CONVERT(VARCHAR, CONVERT(MONEY, amount )) +
+ ' ',
'DB001', source_seq, ''
FROM [FN_GET_DEBTORSLEDGER_IMBALANCEREASONS](0, DEFAULT, 'DB001')
ORDER BY transaction_type,
DEPOSIT_STATUS

INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, ' ', 'TEXT'
END

-- UNALLOCATED DEPOSIT
IF EXISTS (
Select * from [FN_GET_DEBTORSLEDGER_IMBALANCEREASONS](0, DEFAULT, 'DB002')
)
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'Unallocated Deposits', 'TEXT'
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, '------------------------------------------', 'TEXT'

INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS, SOURCE_SEQ, LINETYPE)
SELECT @HDR_SEQNO, ' Inv# ' + INVNO + ' Dated: ' + CONVERT(VARCHAR, transaction_date, 3)
+ ' -
Trans Name = ' + CONVERT(VARCHAR, accname) + '
Trans Type = ' + CONVERT(VARCHAR, transaction_date) + '
Deposit Status = ' + CONVERT(VARCHAR, DEPOSIT_STATUS) + '
Age = ' + CONVERT(VARCHAR, period) + '
Amount = ' + CONVERT(VARCHAR, CONVERT(MONEY, amount)) + ' ',
'DB002', source_seq, ''
FROM [FN_GET_DEBTORSLEDGER_IMBALANCEREASONS](0, DEFAULT, 'DB002')

INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, ' ', 'TEXT'
END

-- DIRECT POSTING
IF EXISTS (
Select * from [FN_GET_DEBTORSLEDGER_IMBALANCEREASONS](0, DEFAULT, 'DB003')
)
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'Direct Postings', 'TEXT'
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, '------------------------------------------', 'TEXT'

INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS, SOURCE_SEQ, LINETYPE)
SELECT @HDR_SEQNO, ' Inv# ' + INVNO + ' Dated: ' + CONVERT(VARCHAR, Transaction_date, 3)
+ ' -
Source = ' + CONVERT(VARCHAR, gl_source) + '
Batch Number = ' + CONVERT(VARCHAR, BATCHNO) + '
Details = ' + CONVERT(VARCHAR, DETAILS) + '
Age = ' + CONVERT(VARCHAR, period) + '
Amount = ' + CONVERT(VARCHAR, CONVERT(MONEY, amount)) + ' ',
'DB003', source_seq, ''
FROM [FN_GET_DEBTORSLEDGER_IMBALANCEREASONS](0, DEFAULT, 'DB003')

INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, ' ', 'TEXT'
END

-- Erroneous Payments and Adjustments
IF EXISTS (
Select * from [FN_GET_DEBTORSLEDGER_IMBALANCEREASONS](0, DEFAULT, 'DB004')
)
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'Erroneous Payments and Adjustments', 'TEXT'
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, '------------------------------------------', 'TEXT'

INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS, SOURCE_SEQ, LINETYPE)
SELECT @HDR_SEQNO, ' Inv# ' + INVNO + ' Dated: ' + CONVERT(VARCHAR, Transaction_date, 3)
+ ' -
Account = ' + CONVERT(VARCHAR, Accno) + '. ' + CONVERT(VARCHAR, Accname) + '
Trans Type = ' + CONVERT(VARCHAR, Transaction_type) + '
Age = ' + CONVERT(VARCHAR, Period) + '
Amount = ' + CONVERT(VARCHAR, CONVERT(MONEY, Amount)) + ' ',
'DB004', Source_seq, ''
FROM [FN_GET_DEBTORSLEDGER_IMBALANCEREASONS](0, DEFAULT, 'DB004')

INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, ' ', 'TEXT'
END

-- UNPOSTED GL POST RUN
IF EXISTS (
Select * from [FN_GET_DEBTORSLEDGER_IMBALANCEREASONS](0, DEFAULT, 'DB005')
)
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'Unposted GL Post Run', 'TEXT'
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, '------------------------------------------', 'TEXT'

INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS, SOURCE_SEQ, LINETYPE)
SELECT @HDR_SEQNO, ' Postrun# ' + convert(varchar, glpostrun_number) +
' Dated: ' + CONVERT(VARCHAR, transaction_date, 3)
+ ' -
Description = ' + CONVERT(VARCHAR, GLPOSTRUN_DESCRIPTION) + '
Initials = ' + CONVERT(VARCHAR, GLPOSTRUN_INITIALS) + '
Amount = ' + CONVERT(VARCHAR, CONVERT(MONEY, Amount)) + ' ',
'DB005', source_seq, ''
FROM [FN_GET_DEBTORSLEDGER_IMBALANCEREASONS](0, DEFAULT, 'DB005')

INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, ' ', 'TEXT'
END

-- UNREALISED FOREX GAINS / LOSSES
IF EXISTS (
Select * from [FN_GET_DEBTORSLEDGER_IMBALANCEREASONS](0, DEFAULT, 'DB006')
)
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'Unrealised FOREX Gains / Losses', 'TEXT'
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, '------------------------------------------', 'TEXT'

INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS, SOURCE_SEQ, LINETYPE)
SELECT @HDR_SEQNO, ' Dated: ' + CONVERT(VARCHAR, Transaction_date, 3)
+ ' -
BatchNo = ' + CONVERT(VARCHAR, BATCHNO) + ' Period = ' + CONVERT(VARCHAR, period) + '
Details = ' + CONVERT(VARCHAR, DETAILS) + '
Currency =' + CONVERT(VARCHAR, CurrencyName) + ' Amount = ' + CONVERT(VARCHAR, CONVERT(MONEY, AMOUNT )) + ' ',
'DB006', source_seq, ''
FROM [FN_GET_DEBTORSLEDGER_IMBALANCEREASONS](0, DEFAULT, 'DB006')

INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, ' ', 'TEXT'
END

END
ELSE
if (CHARINDEX('L', @CONFIG) = 0)
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'NO LEDGER RECONCILIATION ISSUES FOUND ', 'TEXT'
END
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, ' ', 'TEXT'
  END

  IF @STANDALONE = 'Y'
  BEGIN
    INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
    SELECT @HDR_SEQNO, 'Verification Completed '
      + LEFT(CONVERT(VARCHAR, GETDATE(), 109), 50) + ' '
      + CONVERT(VARCHAR(5), DATEDIFF(SECOND, (SELECT CREATEDATE FROM VERIFICATION_HDR WHERE SEQNO = @HDR_SEQNO), GETDATE())) + ' Seconds', 'TEXT'

SELECT MESSAGE FROM VERIFICATION_LINES WHERE HDR_SEQNO = @HDR_SEQNO
  END
  ELSE
  BEGIN
    SET @ENDTIME = GETDATE()
    INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
    SELECT @HDR_SEQNO, 'Duration for debtor ledger balances verification: '
      + CONVERT(VARCHAR(5), DATEDIFF(SECOND, @STARTTIME, @ENDTIME)) + ' Seconds', 'TEXT'
  END

END


Procedure: DATA_VERIFICATION_GL
NameDATA_VERIFICATION_GL
Note
CodeCREATE PROCEDURE [dbo].[DATA_VERIFICATION_GL]
    @CONFIG CHAR(10) = 'DCGIAMS$',
    @HDR_SEQNO INT = -1,
    @STANDALONE CHAR(1)= 'Y'
AS
BEGIN

  SET NOCOUNT ON

  DECLARE @OUTPUT VARCHAR(512)
  DECLARE @STARTTIME DATETIME
  DECLARE @ENDTIME DATETIME

    SET @STARTTIME = GETDATE()


  IF @CONFIG = 'Y'
  BEGIN
SET @CONFIG = 'YDCGIAMS$'
  END

  IF @CONFIG = 'N'
  BEGIN
SET @CONFIG = 'NDCGIAMS$'
  END

  IF @STANDALONE = 'Y'
  BEGIN
INSERT INTO VERIFICATION_HDR (CONFIG_FLAG, CREATED_BY, CREATEDATE )
SELECT @CONFIG, [dbo].FN_GET_STAFF_NO() , GETDATE()

SELECT @HDR_SEQNO = (SELECT MAX(SEQNO) FROM VERIFICATION_HDR)

--DATA VERIFICATION BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'MYOB EXO Business DATA VERIFICATION ' + CONVERT(VARCHAR, GETDATE()), 'TEXT'

SELECT @OUTPUT = USERNAME FROM GENERAL_INFO
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'Company Name: ' + @OUTPUT, 'TEXT'

SELECT @OUTPUT = SOFTWARE_VERSION FROM GENERAL_INFO
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'MYOB EXO Business Database Version: ' + @OUTPUT, 'TEXT'

IF CHARINDEX('L', @CONFIG) = 0
BEGIN
SELECT @OUTPUT = 'MYOB EXO Business Database configured for ' + COUNTRY_NAME FROM GENERAL_INFO G
JOIN COUNTRY C ON G.COUNTRY = C.COUNTRY_CODE
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, @OUTPUT, 'TEXT'
END

IF CHARINDEX('Y', @CONFIG) <> 0
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'Fix Imbalance is ''ON''', 'TEXT'
END
ELSE
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'Fix Imbalance is ''OFF''', 'TEXT'
END
IF CHARINDEX('N', @CONFIG) <> 0
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'MYOB VERIFICATION ''ON''', 'TEXT'
END
  END

  IF CHARINDEX('G', @CONFIG) <> 0
  BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'Verify Tax Rates on GL', 'TEXT'

IF EXISTS (
SELECT A.ACCNO FROM GLACCS A
LEFT JOIN TAX_RATES R ON A.TAXSTATUS = R.SEQNO
LEFT JOIN TAX_KEY_POINT K ON K.COUNTRY = (SELECT COUNTRY FROM GENERAL_INFO) AND R.KEY_POINT = K.KEY_POINT
WHERE A.TAXSTATUS <> -1 AND K.SEQNO IS NULL
)
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS, SOURCE_SEQ, LINETYPE)
SELECT @HDR_SEQNO, 'GL Account ' + CONVERT(VARCHAR, A.ACCNO) + ' Named: ' + A.[NAME]
+ ' has a Tax Status of ' + CONVERT(VARCHAR, A.TAXSTATUS) + ' which does not have a matching Key Point',
'G0001', A.ACCNO, 'ERROR'
FROM GLACCS A
LEFT JOIN TAX_RATES R ON A.TAXSTATUS = R.SEQNO
LEFT JOIN TAX_KEY_POINT K ON K.COUNTRY = (SELECT COUNTRY FROM GENERAL_INFO) AND R.KEY_POINT = K.KEY_POINT
WHERE A.TAXSTATUS <> -1 AND K.SEQNO IS NULL
ORDER BY A.ACCNO

--MYOB MIGRATION ADDED FUNCTIONALITY
IF CHARINDEX('N', @CONFIG) <> 0 AND (SELECT COUNT(NAME) FROM SYSOBJECTS WHERE NAME = 'MYOB_IMPORT_EXCEPTIONS') = 1
BEGIN
--ADD ROWS TO MYOB_IMPORT_EXCEPTIONS FOR GL ACCOUNTS WITH INCORRECT TAX RATES WITH MISSING DEBTOR KEY POINT VALUES
INSERT INTO MYOB_IMPORT_EXCEPTIONS (EXONET_TABLE_NAME, SOURCE_TYPE, DESTINATION_REF_NO, PROBLEM_COLUMN,
PROBLEM_DESCRIPTION, PROBLEM_RESOLUTION)
SELECT 'GLACCS', 'MYGRATE', A.ACCNO, A.[NAME], 'MISSING GL KEY POINT ON TAX RATE', 'Verify the Tax rate on the GL Account listed'
FROM GLACCS A
LEFT JOIN TAX_RATES R ON A.TAXSTATUS = R.SEQNO
LEFT JOIN TAX_KEY_POINT K ON K.COUNTRY = (SELECT COUNTRY FROM GENERAL_INFO) AND R.KEY_POINT = K.KEY_POINT
WHERE A.TAXSTATUS <> -1 AND K.SEQNO IS NULL
ORDER BY A.ACCNO
END
END
ELSE
BEGIN
IF CHARINDEX('L', @CONFIG) = 0
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'GL tax rates are VALID', 'TEXT'
END
END

INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'Verify GL Account Balances match transactional Data', 'TEXT'

INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS, SOURCE_SEQ, LINETYPE)
SELECT @HDR_SEQNO, 'GL Account number : ' + CONVERT(VARCHAR, G.ACCNO) + ' - ' + [NAME] + '
GL Account Balance: ' + CONVERT(VARCHAR, BALANCE) + '
GL Trans Balance : ' + CONVERT(VARCHAR, AMOUNTSUM) + '
Out By : ' + CONVERT(VARCHAR, BALANCE - AMOUNTSUM) + ' ',
'G0002', G.ACCNO, 'ERROR'
FROM GLACCS G
LEFT JOIN (
SELECT GT.ACCNO, SUM(AMOUNT) AS AMOUNTSUM
FROM GLTRANS GT
JOIN GLACCS GA ON GT.ACCNO = GA.ACCNO
JOIN PERIOD_STATUS P ON GT.PERIOD_SEQNO = P.SEQNO
WHERE (SECTION = 0 AND YEARAGE = 0) OR SECTION = 1
GROUP BY GT.ACCNO
) GT ON G.ACCNO = GT.ACCNO
WHERE ABS(BALANCE - AMOUNTSUM) > 0.009
ORDER BY G.ACCNO

INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, CONVERT(VARCHAR, @@ROWCOUNT) + ' Problem Records Found', 'TEXT'

INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, '----------------------------------------------------------------------------------------', 'TEXT'

  END

  IF @STANDALONE = 'Y'
  BEGIN
    INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
    SELECT @HDR_SEQNO, 'Verification Completed '
      + LEFT(CONVERT(VARCHAR, GETDATE(), 109), 50) + ' '
      + CONVERT(VARCHAR(5), DATEDIFF(SECOND, (SELECT CREATEDATE FROM VERIFICATION_HDR WHERE SEQNO = @HDR_SEQNO), GETDATE())) + ' Seconds', 'TEXT'

SELECT MESSAGE FROM VERIFICATION_LINES WHERE HDR_SEQNO = @HDR_SEQNO
  END
  ELSE
  BEGIN
    SET @ENDTIME = GETDATE()
    INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
    SELECT @HDR_SEQNO, 'Duration for GL verification: '
      + CONVERT(VARCHAR(5), DATEDIFF(SECOND, @STARTTIME, @ENDTIME)) + ' Seconds', 'TEXT'
  END

END


Procedure: DATA_VERIFICATION_MISC
NameDATA_VERIFICATION_MISC
Note
CodeCREATE PROCEDURE [dbo].[DATA_VERIFICATION_MISC]
    @CONFIG CHAR(10) = 'DCGIAMS$',
    @HDR_SEQNO INT = -1,
    @STANDALONE CHAR(1)= 'Y'
AS
BEGIN

  SET NOCOUNT ON

  DECLARE @OUTPUT VARCHAR(512)
  DECLARE @STARTTIME DATETIME
  DECLARE @ENDTIME DATETIME

  SET @STARTTIME = GETDATE()

  IF @CONFIG = 'Y'
  BEGIN
SET @CONFIG = 'YDCGIAMS$'
  END

  IF @CONFIG = 'N'
  BEGIN
SET @CONFIG = 'NDCGIAMS$'
  END

  IF @STANDALONE = 'Y'
  BEGIN
INSERT INTO VERIFICATION_HDR (CONFIG_FLAG, CREATED_BY, CREATEDATE )
SELECT @CONFIG, [dbo].FN_GET_STAFF_NO() , GETDATE()

SELECT @HDR_SEQNO = (SELECT MAX(SEQNO) FROM VERIFICATION_HDR)

--DATA VERIFICATION BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'MYOB EXO Business DATA VERIFICATION ' + CONVERT(VARCHAR, GETDATE()), 'TEXT'

SELECT @OUTPUT = USERNAME FROM GENERAL_INFO
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'Company Name: ' + @OUTPUT, 'TEXT'

SELECT @OUTPUT = SOFTWARE_VERSION FROM GENERAL_INFO
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'MYOB EXO Business Database Version: ' + @OUTPUT, 'TEXT'

IF CHARINDEX('L', @CONFIG) = 0
BEGIN
SELECT @OUTPUT = 'MYOB EXO Business Database configured for ' + COUNTRY_NAME FROM GENERAL_INFO G
JOIN COUNTRY C ON G.COUNTRY = C.COUNTRY_CODE
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, @OUTPUT, 'TEXT'
END

IF CHARINDEX('Y', @CONFIG) <> 0
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'Fix Imbalance is ''ON''', 'TEXT'
END
ELSE
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'Fix Imbalance is ''OFF''', 'TEXT'
END

IF CHARINDEX('N', @CONFIG) <> 0
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'MYOB VERIFICATION ''ON''', 'TEXT'
END
  END

  --CHECK TAX RATES HAVE MATCHING KEY POINT VALUES
  IF CHARINDEX('M', @CONFIG) <> 0
  BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'Verify Tax Rates', 'TEXT'
IF CHARINDEX('L', @CONFIG) = 0 AND (
SELECT COUNT(R.[NAME]) FROM TAX_RATES R
LEFT JOIN TAX_KEY_POINT K ON R.KEY_POINT = K.KEY_POINT AND COUNTRY = (SELECT COUNTRY FROM GENERAL_INFO)
WHERE K.KEY_POINT IS NULL
) > 0
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS, SOURCE_SEQ, LINETYPE)
SELECT @HDR_SEQNO, 'Checking ' + R.[NAME] + CASE
WHEN K.KEY_POINT IS NOT NULL THEN ' - OK'
ELSE ' - MISSING KEY POINT VALUE'
END AS MESSAGE, 'M0001' AS V_CLASS,
CASE WHEN K.KEY_POINT IS NOT NULL THEN -1 ELSE K.SEQNO END AS SOURCE_SEQ,
CASE WHEN K.KEY_POINT IS NOT NULL THEN '' ELSE 'ERROR' END AS LINETYPE
FROM TAX_RATES R
LEFT JOIN TAX_KEY_POINT K ON R.KEY_POINT = K.KEY_POINT AND COUNTRY = (SELECT COUNTRY FROM GENERAL_INFO)

--MYOB MIGRATION ADDED FUNCTIONALITY
IF CHARINDEX('N', @CONFIG) <> 0 AND (SELECT COUNT(NAME) FROM SYSOBJECTS WHERE NAME = 'MYOB_IMPORT_EXCEPTIONS') = 1
BEGIN
--ADD ROWS TO MYOB_IMPORT_EXCEPTIONS FOR TAX RATES WITH MISSING KEY POINT VALUES
INSERT INTO MYOB_IMPORT_EXCEPTIONS (EXONET_TABLE_NAME, SOURCE_TYPE, DESTINATION_REF_NO, PROBLEM_COLUMN,
PROBLEM_DESCRIPTION, PROBLEM_RESOLUTION)
SELECT 'TAX_RATES', 'MYGRATE', R.SEQNO, R.[NAME], 'MISSING KEY POINT VALUE', 'Check TAX RATES in ExoConfig'
FROM TAX_RATES R
LEFT JOIN TAX_KEY_POINT K ON R.KEY_POINT = K.KEY_POINT AND COUNTRY = (SELECT COUNTRY FROM GENERAL_INFO)
WHERE K.KEY_POINT IS NULL
END
END
ELSE
BEGIN
IF CHARINDEX('L', @CONFIG) = 0
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'Tax Rate Key Point Values are Valid', 'TEXT'
END
END

INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'Check Matching Period Status values exist for Transactional Data', 'TEXT'

IF (
SELECT COUNT(*)
FROM (
SELECT PERIOD_SEQNO, 'C' AS LEDGER FROM CR_TRANS
UNION
SELECT PERIOD_SEQNO, 'D' AS LEDGER FROM DR_TRANS
UNION
SELECT PERIOD_SEQNO, 'G' AS LEDGER FROM GLTRANS
WHERE (SOURCE = 'e') OR (SOURCE = 'e' AND TRANSTYPE = 'EYO')
UNION
SELECT PERIOD_SEQNO, 'S' AS LEDGER FROM STOCK_TRANS
) T
LEFT JOIN PERIOD_STATUS P ON T.PERIOD_SEQNO = P.SEQNO AND T.LEDGER = P.LEDGER
WHERE P.AGE IS NULL
) >= 1
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS, SOURCE_SEQ, LINETYPE)
SELECT @HDR_SEQNO, ISNULL('Period Status missing for ''' + CASE
WHEN T.LEDGER = 'C' THEN 'Creditors'
WHEN T.LEDGER = 'D' THEN 'Debtors'
WHEN T.LEDGER = 'G' THEN 'GL'
ELSE 'Stock'
END + ''' ledger entry for Age ''' + CONVERT(VARCHAR, T.AGE) + '''', '') AS MESSAGE,
CASE WHEN T.LEDGER = 'C' THEN 'M0002' WHEN T.LEDGER = 'D' THEN 'M0003'
WHEN T.LEDGER = 'G' THEN 'M0004' ELSE 'M0005' END AS V_CLASS, T.SEQNO, 'ERROR'
FROM (
SELECT AGE, PERIOD_SEQNO, 'C' AS LEDGER, SEQNO FROM CR_TRANS
UNION
SELECT AGE, PERIOD_SEQNO, 'D' AS LEDGER, SEQNO FROM DR_TRANS
UNION
SELECT PS.AGE, G.PERIOD_SEQNO, 'G' AS LEDGER, G.SEQNO
FROM GLTRANS G
JOIN PERIOD_STATUS PS ON PS.SEQNO = G.PERIOD_SEQNO
WHERE (G.SOURCE = 'e') OR (G.SOURCE = 'e' AND G.TRANSTYPE = 'EYO')
UNION
SELECT AGE, PERIOD_SEQNO, 'S' AS LEDGER, SEQNO FROM STOCK_TRANS
) T
LEFT JOIN PERIOD_STATUS P ON T.PERIOD_SEQNO = P.SEQNO AND T.LEDGER = P.LEDGER
WHERE P.AGE IS NULL
ORDER BY T.AGE

--MYOB MIGRATION ADDED FUNCTIONALITY
IF CHARINDEX('N', @CONFIG) <> 0 AND (SELECT COUNT(NAME) FROM SYSOBJECTS WHERE NAME = 'MYOB_IMPORT_EXCEPTIONS') = 1
BEGIN
--ADD ROWS TO MYOB_IMPORT_EXCEPTIONS FOR STOCK ITEMS WITH INCORRECT SALES TAX RATES WITH INVALID KEY POINT VALUES
INSERT INTO MYOB_IMPORT_EXCEPTIONS (EXONET_TABLE_NAME, SOURCE_TYPE, DESTINATION_REF_NO, PROBLEM_COLUMN,
PROBLEM_DESCRIPTION, PROBLEM_RESOLUTION)
SELECT 'PERIOD_STATUS', 'MYGRATE', T.AGE, 'AGE', 'MISSING OR INVALID AGE ENTRY IN ' + CASE
WHEN T.LEDGER = 'C' THEN 'Creditors '
WHEN T.LEDGER = 'D' THEN 'Debtors '
WHEN T.LEDGER = 'G' THEN 'GL '
ELSE 'Stock '
END, 'Period Status appears to be missing a record. This record will need to be created'
FROM (
SELECT AGE, PERIOD_SEQNO, 'C' AS LEDGER FROM CR_TRANS
UNION
SELECT AGE, PERIOD_SEQNO, 'D' AS LEDGER FROM DR_TRANS
UNION
SELECT PS.AGE, G.PERIOD_SEQNO, 'G' AS LEDGER
FROM GLTRANS G
JOIN PERIOD_STATUS PS ON PS.SEQNO = G.PERIOD_SEQNO
WHERE (G.SOURCE = 'e') OR (G.SOURCE = 'e' AND G.TRANSTYPE = 'EYO')
UNION
SELECT AGE, PERIOD_SEQNO, 'S' AS LEDGER FROM STOCK_TRANS
) T
LEFT JOIN PERIOD_STATUS P ON T.PERIOD_SEQNO = P.SEQNO AND T.LEDGER = P.LEDGER
WHERE P.AGE IS NULL
ORDER BY T.AGE
END
END
ELSE
BEGIN
IF CHARINDEX('L', @CONFIG) = 0
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'No missing Period Status entries found', 'TEXT'
END
END

    INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
    SELECT @HDR_SEQNO, 'Check Matching Period Status values exist for Allocation Data', 'TEXT'
    IF (
SELECT COUNT(*)
FROM (
SELECT PERIOD_SEQNO, 'C' AS LEDGER FROM CR_ALLOCATIONS
UNION
SELECT PERIOD_SEQNO, 'D' AS LEDGER FROM DR_ALLOCATIONS
) A
LEFT JOIN PERIOD_STATUS P ON A.PERIOD_SEQNO = P.SEQNO AND A.LEDGER = P.LEDGER
WHERE P.AGE IS NULL
  ) >= 1
  BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS, SOURCE_SEQ, LINETYPE)
SELECT @HDR_SEQNO, 'Period Status missing for ''' + CASE
WHEN A.LEDGER = 'C' THEN 'Creditors'
WHEN A.LEDGER = 'D' THEN 'Debtors'
END + ''' allocation record : Allocno= ' + CONVERT(VARCHAR, a.allocno)
        + ' , Alloc Seqno = ' + CONVERT(VARCHAR, a.seqno)
        + ' , Alloc Period_seqno = ' + CONVERT(VARCHAR, a.period_seqno)
        + ' , Age =''' + isnull(CONVERT(VARCHAR, A.AGE), '') + '''' AS MESSAGE,
        CASE WHEN A.LEDGER = 'C' THEN 'M0006' WHEN A.LEDGER = 'D' THEN 'M0007' END AS V_CLASS,
        A.SEQNO, 'ERROR'
FROM (
SELECT ALLOCNO, SEQNO, AGE, PERIOD_SEQNO, 'C' AS LEDGER FROM CR_ALLOCATIONS
UNION
SELECT ALLOCNO, SEQNO, AGE, PERIOD_SEQNO, 'D' AS LEDGER FROM DR_ALLOCATIONS
) A
LEFT JOIN PERIOD_STATUS P ON A.PERIOD_SEQNO = P.SEQNO AND A.LEDGER = P.LEDGER
WHERE P.AGE IS NULL
ORDER BY A.AGE
--MYOB MIGRATION ADDED FUNCTIONALITY
IF CHARINDEX('N', @CONFIG) <> 0 AND (SELECT COUNT(NAME) FROM SYSOBJECTS WHERE NAME = 'MYOB_IMPORT_EXCEPTIONS') = 1
BEGIN
--ADD ROWS TO MYOB_IMPORT_EXCEPTIONS FOR STOCK ITEMS WITH INCORRECT SALES TAX RATES WITH INVALID KEY POINT VALUES
INSERT INTO MYOB_IMPORT_EXCEPTIONS (EXONET_TABLE_NAME, SOURCE_TYPE, DESTINATION_REF_NO, PROBLEM_COLUMN, PROBLEM_DESCRIPTION,
PROBLEM_RESOLUTION)
SELECT 'PERIOD_STATUS', 'MYGRATE', A.AGE, 'AGE', 'MISSING OR INVALID AGE ENTRY IN' + CASE
WHEN A.LEDGER = 'C' THEN 'Creditors '
WHEN A.LEDGER = 'D' THEN 'Debtors '
END, 'Period Status appears to be missing a record. This record will need to be created'
FROM (
SELECT AGE, PERIOD_SEQNO, 'C' AS LEDGER FROM CR_ALLOCATIONS
UNION
SELECT AGE, PERIOD_SEQNO, 'D' AS LEDGER FROM DR_ALLOCATIONS
) A
LEFT JOIN PERIOD_STATUS P ON A.PERIOD_SEQNO = P.SEQNO AND A.LEDGER = P.LEDGER
WHERE P.AGE IS NULL
ORDER BY A.AGE
END
  END
  ELSE
  BEGIN
IF CHARINDEX('L', @CONFIG) = 0
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'No missing Period Status entries found', 'TEXT'
END
  END

INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'Verifying MYOB EXO Business GL Control accounts', 'TEXT'

IF NOT EXISTS (SELECT ACCNO FROM GLACCS G JOIN GL_CONTROL C ON G.ACCNO = C.DEBTORS)
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS, SOURCE_SEQ, LINETYPE)
SELECT @HDR_SEQNO, 'GL Control Account for ''DEBTORS'' is incorrect', 'M0008' AS V_CLASS,
CASE WHEN C.DEBTORS IS NULL THEN -1 ELSE C.DEBTORS END, 'ERROR'
FROM GL_CONTROL C

IF CHARINDEX('N', @CONFIG) <> 0
BEGIN
--ADD ROWS TO MYOB_IMPORT_EXCEPTIONS FOR STOCK ITEMS WITH INCORRECT SALES TAX RATES WITH INVALID KEY POINT VALUES
INSERT INTO MYOB_IMPORT_EXCEPTIONS (EXONET_TABLE_NAME, SOURCE_TYPE, DESTINATION_REF_NO, PROBLEM_COLUMN,
PROBLEM_DESCRIPTION, PROBLEM_RESOLUTION)
SELECT 'GL_CONTROL', 'DEBTORS', '', 'DEBTORS', 'Missing or incorrect DEBTOR GL Code in GL_CONTROL', 'Need to verify GL_CONTROL accounts in ExoConfig '
END
END

  END

  IF @STANDALONE = 'Y'
  BEGIN
    INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
    SELECT @HDR_SEQNO, 'Verification Completed '
      + LEFT(CONVERT(VARCHAR, GETDATE(), 109), 50) + ' '
      + CONVERT(VARCHAR(5), DATEDIFF(SECOND, (SELECT CREATEDATE FROM VERIFICATION_HDR WHERE SEQNO = @HDR_SEQNO), GETDATE())) + ' Seconds', 'TEXT'

SELECT MESSAGE FROM VERIFICATION_LINES WHERE HDR_SEQNO = @HDR_SEQNO
  END
  ELSE
  BEGIN
    SET @ENDTIME = GETDATE()
    INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
    SELECT @HDR_SEQNO, 'Duration for tax rates verification: '
      + CONVERT(VARCHAR(5), DATEDIFF(SECOND, @STARTTIME, @ENDTIME)) + ' Seconds', 'TEXT'
  END

END


Procedure: DATA_VERIFICATION_SP
NameDATA_VERIFICATION_SP
Note
CodeCREATE PROCEDURE [dbo].[DATA_VERIFICATION_SP]
@CONFIG CHAR(10) = 'DCGIAMS$',
@STARTPERIOD INT = 0,
@ENDPERIOD INT = 0
AS
SET NOCOUNT ON
--Config flags:
-- D = Debtors
-- C = Creditors
-- G = GL
-- I = Invoices
-- A = Allocations
-- M = Misc
-- S = Stock
-- N = MYOB Functionality (log to MYOB_IMPORT_EXCEPTIONS table if present)
-- L = List Errors Only (as opposed to '... OK' messages as well)
-- Y = Fix Imbalance
-- $ = AnalysisCodes
DECLARE @OUTPUT VARCHAR(512)
DECLARE @MCOUNT INT
DECLARE @HDR_SEQNO INT
DECLARE @CREATE_PERIOD_SEQNO INT
DECLARE @START_PERIOD_SEQNO INT
DECLARE @END_PERIOD_SEQNO INT
IF @CONFIG = 'Y'
BEGIN
SET @CONFIG = 'YDCGIAMS$'
END
IF @CONFIG = 'N'
BEGIN
SET @CONFIG = 'NDCGIAMS$'
END
SELECT @CREATE_PERIOD_SEQNO = (SELECT SEQNO FROM PERIOD_STATUS WHERE AGE = 0 AND LEDGER = 'G')
SELECT @START_PERIOD_SEQNO = (SELECT SEQNO FROM PERIOD_STATUS WHERE AGE = @STARTPERIOD AND LEDGER = 'G')
SELECT @END_PERIOD_SEQNO = (SELECT SEQNO FROM PERIOD_STATUS WHERE AGE = @ENDPERIOD AND LEDGER = 'G')

INSERT INTO VERIFICATION_HDR (CONFIG_FLAG, CREATED_BY, CREATEDATE, CREATE_PERIOD_SEQNO, START_PERIOD_SEQNO, END_PERIOD_SEQNO)
SELECT @CONFIG, [dbo].FN_GET_STAFF_NO() , GETDATE(), @CREATE_PERIOD_SEQNO, @START_PERIOD_SEQNO, @END_PERIOD_SEQNO

SELECT @HDR_SEQNO = (SELECT MAX(SEQNO) FROM VERIFICATION_HDR)

--DATA VERIFICATION BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'MYOB EXO Business DATA VERIFICATION ' + CONVERT(VARCHAR, GETDATE()), 'TEXT'
SELECT @OUTPUT = USERNAME FROM GENERAL_INFO
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'Company Name: ' + @OUTPUT, 'TEXT'
SELECT @OUTPUT = SOFTWARE_VERSION FROM GENERAL_INFO
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'MYOB EXO Business Database Version: ' + @OUTPUT, 'TEXT'
IF CHARINDEX('L', @CONFIG) = 0
BEGIN
SELECT @OUTPUT = 'MYOB EXO Business Database configured for ' + COUNTRY_NAME FROM GENERAL_INFO G
JOIN COUNTRY C ON G.COUNTRY = C.COUNTRY_CODE
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, @OUTPUT, 'TEXT'
END
IF CHARINDEX('Y', @CONFIG) <> 0
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'Fix Imbalance is ''ON''', 'TEXT'
END
ELSE
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'Fix Imbalance is ''OFF''', 'TEXT'
END
IF CHARINDEX('N', @CONFIG) <> 0
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'MYOB VERIFICATION ''ON''', 'TEXT'
END
--CHECK TAX RATES HAVE MATCHING KEY POINT VALUES
IF CHARINDEX('M', @CONFIG) <> 0
BEGIN
   EXEC DATA_VERIFICATION_MISC @CONFIG, @HDR_SEQNO, 'N'
END
IF CHARINDEX('G', @CONFIG) <> 0
BEGIN
   EXEC DATA_VERIFICATION_GL @CONFIG, @HDR_SEQNO, 'N'
END
IF CHARINDEX('D', @CONFIG) <> 0
BEGIN
   EXEC DATA_VERIFICATION_DR @CONFIG, @HDR_SEQNO, 'N', @STARTPERIOD, @ENDPERIOD
END
IF CHARINDEX('C', @CONFIG) <> 0
BEGIN
   EXEC DATA_VERIFICATION_CR @CONFIG, @HDR_SEQNO, 'N', @STARTPERIOD, @ENDPERIOD
END
IF CHARINDEX('S', @CONFIG) <> 0
BEGIN
   EXEC DATA_VERIFICATION_STOCK @CONFIG, @HDR_SEQNO, 'N'
END
IF CHARINDEX('$', @CONFIG) <> 0
BEGIN
   EXEC DATA_VERIFICATION_ANALYSISCODE @CONFIG, @HDR_SEQNO, 'N'
END
IF CHARINDEX('D', @CONFIG) <> 0
BEGIN
   EXEC DATA_VERIFICATION_DRACCBALANCING @CONFIG, @HDR_SEQNO, 'N'
END
IF CHARINDEX('C', @CONFIG) <> 0
BEGIN
   EXEC DATA_VERIFICATION_CRACCBALANCING @CONFIG, @HDR_SEQNO, 'N'
END
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'Verification Completed '
  + LEFT(CONVERT(VARCHAR, GETDATE(), 109), 50) + ' '
  + CONVERT(VARCHAR(5), DATEDIFF(SECOND, (SELECT CREATEDATE FROM VERIFICATION_HDR WHERE SEQNO = @HDR_SEQNO), GETDATE())) + ' Seconds', 'TEXT'

SELECT HDR_SEQNO, MESSAGE FROM VERIFICATION_LINES WHERE HDR_SEQNO = @HDR_SEQNO

DECLARE @ERRORCOUNT INT
SET @ERRORCOUNT= (SELECT COUNT(*) FROM VERIFICATION_LINES WHERE HDR_SEQNO = @HDR_SEQNO AND LINETYPE = 'ERROR')

UPDATE VERIFICATION_HDR
SET ERROR_COUNT = @ERRORCOUNT
WHERE SEQNO = @HDR_SEQNO


Procedure: DATA_VERIFICATION_STOCK
NameDATA_VERIFICATION_STOCK
Note
CodeCREATE PROCEDURE [dbo].[DATA_VERIFICATION_STOCK]
    @CONFIG CHAR(10) = 'DCGIAMS$',
    @HDR_SEQNO INT = -1,
    @STANDALONE CHAR(1)= 'Y'
AS
BEGIN

  SET NOCOUNT ON

  DECLARE @OUTPUT VARCHAR(512)
  DECLARE @STARTTIME DATETIME
  DECLARE @ENDTIME DATETIME

  SET @STARTTIME = GETDATE()


  IF @CONFIG = 'Y'
  BEGIN
SET @CONFIG = 'YDCGIAMS$'
  END

  IF @CONFIG = 'N'
  BEGIN
SET @CONFIG = 'NDCGIAMS$'
  END

  IF @STANDALONE = 'Y'
  BEGIN
INSERT INTO VERIFICATION_HDR (CONFIG_FLAG, CREATED_BY, CREATEDATE )
SELECT @CONFIG, [dbo].FN_GET_STAFF_NO() , GETDATE()

SELECT @HDR_SEQNO = (SELECT MAX(SEQNO) FROM VERIFICATION_HDR)

--DATA VERIFICATION BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'MYOB EXO Business DATA VERIFICATION ' + CONVERT(VARCHAR, GETDATE()), 'TEXT'

SELECT @OUTPUT = USERNAME FROM GENERAL_INFO
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'Company Name: ' + @OUTPUT, 'TEXT'

SELECT @OUTPUT = SOFTWARE_VERSION FROM GENERAL_INFO
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'MYOB EXO Business Database Version: ' + @OUTPUT, 'TEXT'

IF CHARINDEX('L', @CONFIG) = 0
BEGIN
SELECT @OUTPUT = 'MYOB EXO Business Database configured for ' + COUNTRY_NAME FROM GENERAL_INFO G
JOIN COUNTRY C ON G.COUNTRY = C.COUNTRY_CODE
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, @OUTPUT, 'TEXT'
END

IF CHARINDEX('Y', @CONFIG) <> 0
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'Fix Imbalance is ''ON''', 'TEXT'
END
ELSE
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'Fix Imbalance is ''OFF''', 'TEXT'
END

IF CHARINDEX('N', @CONFIG) <> 0
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'MYOB VERIFICATION ''ON''', 'TEXT'
END
  END

  IF CHARINDEX('S', @CONFIG) <> 0
  BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'Verify Purchase Tax Rates on STOCK', 'TEXT'

IF EXISTS (
SELECT A.STOCKCODE FROM STOCK_ITEMS A
LEFT JOIN TAX_RATES R ON A.PURCHTAXRATE = R.SEQNO
LEFT JOIN TAX_KEY_POINT K ON R.KEY_POINT = K.KEY_POINT AND K.COUNTRY = (SELECT COUNTRY FROM GENERAL_INFO)
AND K.CR_LEDGER = 'Y'
WHERE A.PURCHTAXRATE <> -1 AND K.SEQNO IS NULL
)
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS, SOURCE_SEQ, LINETYPE)
SELECT @HDR_SEQNO, 'Stock Item ''' + A.STOCKCODE + ''' (' + A.[DESCRIPTION]
+ ') has a Purchase Tax Rate of ' + CONVERT(VARCHAR, A.PURCHTAXRATE) + '(' + ISNULL(R.[NAME], '--INVALID--')
+ ') has an invalid Tax Key Point value of ' + ISNULL(R.KEY_POINT, 'NONE') + '
This Stock Item is currently ' + CASE
WHEN A.ISACTIVE = 'Y' THEN 'ACTIVE'
ELSE 'INACTIVE'
END AS MESSAGE,
CASE
                  WHEN A.ISACTIVE = 'Y' THEN 'S0001'
                  ELSE 'S0002'
              END AS V_CLASS, -1, 'ERROR'
FROM STOCK_ITEMS A
LEFT JOIN TAX_RATES R ON A.PURCHTAXRATE = R.SEQNO
LEFT JOIN TAX_KEY_POINT K ON R.KEY_POINT = K.KEY_POINT AND K.COUNTRY = (SELECT COUNTRY FROM GENERAL_INFO) AND K.CR_LEDGER = 'Y'
WHERE A.PURCHTAXRATE <> -1 AND K.SEQNO IS NULL
ORDER BY A.STOCKCODE


--MYOB MIGRATION ADDED FUNCTIONALITY
IF CHARINDEX('N', @CONFIG) <> 0 AND (SELECT COUNT(NAME) FROM SYSOBJECTS WHERE NAME = 'MYOB_IMPORT_EXCEPTIONS') = 1
BEGIN
--ADD ROWS TO MYOB_IMPORT_EXCEPTIONS FOR STOCK ITEMS WITH INCORRECT PURCHASE TAX RATES WITH INVALID KEY POINT VALUES
INSERT INTO MYOB_IMPORT_EXCEPTIONS (EXONET_TABLE_NAME, SOURCE_TYPE, DESTINATION_REF_NO, PROBLEM_COLUMN, PROBLEM_DESCRIPTION, PROBLEM_RESOLUTION)
SELECT 'STOCK_ITEMS', 'MYGRATE', A.STOCKCODE, A.[DESCRIPTION], 'MISSING STOCK KEY POINT ON PURCHASE TAX RATE', 'Verify the Tax Rate on the Stockcode listed'
FROM STOCK_ITEMS A
LEFT JOIN TAX_RATES R ON A.PURCHTAXRATE = R.SEQNO
LEFT JOIN TAX_KEY_POINT K ON K.COUNTRY = (SELECT COUNTRY FROM GENERAL_INFO) AND R.KEY_POINT = K.KEY_POINT
AND K.CR_LEDGER = 'Y'
WHERE A.PURCHTAXRATE <> -1 AND K.SEQNO IS NULL
ORDER BY A.STOCKCODE
END

END
ELSE
BEGIN
IF CHARINDEX('L', @CONFIG) = 0
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'Purchase Tax Rates on Stock Items are valid', 'TEXT'
END
END

----------------------------------------------------

INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'Verify Sales Tax Rates on STOCK' , 'TEXT'

IF EXISTS (
SELECT A.STOCKCODE FROM STOCK_ITEMS A
LEFT JOIN TAX_RATES R ON A.SALESTAXRATE=R.SEQNO
LEFT JOIN TAX_KEY_POINT K ON R.KEY_POINT=K.KEY_POINT AND K.COUNTRY = (SELECT COUNTRY FROM GENERAL_INFO)
AND K.DR_LEDGER = 'Y'
WHERE A.SALESTAXRATE <> -1 AND K.SEQNO IS NULL
)
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS, SOURCE_SEQ, LINETYPE)
SELECT @HDR_SEQNO, 'Stock Item ''' + A.STOCKCODE + ''' (' + A.[DESCRIPTION]
+ ') has a Sales Tax Rate of ' + CONVERT(VARCHAR, A.SALESTAXRATE) + '(' + ISNULL(R.[NAME], '--INVALID--')
+ ') has an invalid Tax Key Point value of ' + ISNULL(R.KEY_POINT, 'NONE') + '
  This Stock Item is currently ' + CASE
WHEN A.ISACTIVE = 'Y' THEN 'ACTIVE'
ELSE 'INACTIVE'
END AS MESSAGE,
CASE
                  WHEN A.ISACTIVE = 'Y' THEN 'S0003'
                  ELSE 'S0004'
              END AS V_CLASS, -1, 'ERROR'

FROM STOCK_ITEMS A
LEFT JOIN TAX_RATES R ON A.SALESTAXRATE = R.SEQNO
LEFT JOIN TAX_KEY_POINT K ON R.KEY_POINT = K.KEY_POINT AND K.COUNTRY = (SELECT COUNTRY FROM GENERAL_INFO) AND K.DR_LEDGER = 'Y'
WHERE A.SALESTAXRATE <> -1 AND K.SEQNO IS NULL
ORDER BY A.STOCKCODE

--MYOB MIGRATION ADDED FUNCTIONALITY
IF CHARINDEX('N', @CONFIG) <> 0 AND (SELECT COUNT(NAME) FROM SYSOBJECTS WHERE NAME = 'MYOB_IMPORT_EXCEPTIONS') = 1
BEGIN
--ADD ROWS TO MYOB_IMPORT_EXCEPTIONS FOR STOCK ITEMS WITH INCORRECT SALES TAX RATES WITH INVALID KEY POINT VALUES
INSERT INTO MYOB_IMPORT_EXCEPTIONS (EXONET_TABLE_NAME, SOURCE_TYPE, DESTINATION_REF_NO, PROBLEM_COLUMN, PROBLEM_DESCRIPTION, PROBLEM_RESOLUTION)
SELECT 'STOCK_ITEMS', 'MYGRATE', A.STOCKCODE, A.[DESCRIPTION], 'MISSING STOCK KEY POINT ON SALES TAX RATE', 'Verify the Tax Rate on the Stockcode listed'
FROM STOCK_ITEMS A
LEFT JOIN TAX_RATES R ON A.SALESTAXRATE = R.SEQNO
LEFT JOIN TAX_KEY_POINT K ON K.COUNTRY = (SELECT COUNTRY FROM GENERAL_INFO) AND R.KEY_POINT = K.KEY_POINT AND K.DR_LEDGER = 'Y'
WHERE A.PURCHTAXRATE <> -1 AND K.SEQNO IS NULL
ORDER BY A.STOCKCODE
END
END
ELSE
BEGIN
IF CHARINDEX('L', @CONFIG) = 0
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'Sales Tax Rates on Stock Items are valid', 'TEXT'
END
END

   ----------------------------------------------------

INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'Verify STOCK_LOC_INFO records against transactional data by location' , 'TEXT'

IF EXISTS(
SELECT SLI.STOCKCODE FROM (
SELECT STOCKCODE, SUM(QUANTITY) AS SUMQTY, LOCATION FROM STOCK_TRANS GROUP BY STOCKCODE, LOCATION
) ST
LEFT JOIN (
SELECT STOCKCODE, QTY AS SLIQTY, LOCATION FROM STOCK_LOC_INFO
) SLI ON ST.STOCKCODE = SLI.STOCKCODE AND ST.LOCATION = SLI.LOCATION
INNER JOIN (
SELECT STOCKCODE FROM STOCK_ITEMS WHERE STATUS = 'S'
) S ON SLI.STOCKCODE = S.STOCKCODE
LEFT JOIN STOCK_LOCATIONS SL ON SLI.LOCATION = SL.LOCNO
WHERE ABS(ABS(ISNULL(SUMQTY, 0))- ABS(ISNULL(SLIQTY, 0))) > 0.1
)
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS, SOURCE_SEQ, LINETYPE)
SELECT @HDR_SEQNO, ' Item Stockcode : ' + SLI.STOCKCODE + '
Stock Location : ' + CONVERT(VARCHAR, SLI.LOCATION) + ' - ' + LNAME + '
Total of Transactions : ' + CONVERT(VARCHAR, ST.SUMQTY) + '
STOCK_LOC_INFO Total : ' + CONVERT(VARCHAR, SLIQTY) + '
Out By: ' + CONVERT(VARCHAR, SLIQTY - SUMQTY) + ' ',
'S0005', -1, 'ERROR'
FROM (
SELECT STOCKCODE, SUM(QUANTITY) AS SUMQTY, LOCATION FROM STOCK_TRANS GROUP BY STOCKCODE, LOCATION
) ST
LEFT JOIN (
SELECT STOCKCODE, QTY AS SLIQTY, LOCATION FROM STOCK_LOC_INFO
) SLI ON ST.STOCKCODE = SLI.STOCKCODE AND ST.LOCATION = SLI.LOCATION
INNER JOIN (
SELECT STOCKCODE FROM STOCK_ITEMS WHERE STATUS = 'S'
) S ON SLI.STOCKCODE = S.STOCKCODE
LEFT JOIN STOCK_LOCATIONS SL ON SLI.LOCATION = SL.LOCNO
WHERE ABS(ABS(ISNULL(SUMQTY, 0))- ABS(ISNULL(SLIQTY, 0))) > 0.1
ORDER BY SLI.STOCKCODE

INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, CONVERT(VARCHAR, @@ROWCOUNT) + ' Problem Records Found', 'TEXT'

--IF CHARINDEX('T', @CONFIG) <> 0 AND @@ROWCOUNT > 0 --QUESTION: does this work or is it now the rowcount from the above insert?
--BEGIN
-- INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
-- SELECT @HDR_SEQNO, 'Fixing STOCK_LOC_INFO Totals to match transaction data' , 'TEXT'

-- UPDATE SLI
-- SET QTY = ST.SUMQTY
-- FROM STOCK_LOC_INFO SLI
-- JOIN STOCK_ITEMS S ON SLI.STOCKCODE = S.STOCKCODE AND S.STATUS <> 'L'
-- JOIN (
-- SELECT STOCKCODE, SUM(QUANTITY) AS SUMQTY, LOCATION FROM STOCK_TRANS GROUP BY STOCKCODE, LOCATION
-- ) ST ON SLI.STOCKCODE = ST.STOCKCODE AND SLI.LOCATION = ST.LOCATION

-- INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
-- SELECT @HDR_SEQNO, CONVERT(VARCHAR, @@ROWCOUNT) + ' Records Fixed', 'TEXT'
--END
END
ELSE
BEGIN
IF CHARINDEX('L', @CONFIG) = 0
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'No STOCK_LOC_INFO Errors found', 'TEXT'
END
END

---------------------------------------------------------------------------

INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'Verify TOTALSTOCK figures match STOCK_LOC_INFO totals', 'TEXT'

IF EXISTS(
SELECT SLI.STOCKCODE FROM STOCK_LOC_INFO SLI
JOIN STOCK_ITEMS S ON SLI.STOCKCODE = S.STOCKCODE
INNER JOIN STOCK_LOCATIONS L ON SLI.LOCATION = L.LOCNO AND L.IS_WIPLOCATION <> 'Y' -- Exclude WIP locations
WHERE S.STATUS <> 'L'
GROUP BY SLI.STOCKCODE, S.TOTALSTOCK
HAVING ABS(ABS(ISNULL(SUM(SLI.QTY), 0))- ABS(ISNULL(S.TOTALSTOCK, 0))) > 0.1
)
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS, SOURCE_SEQ, LINETYPE)
SELECT @HDR_SEQNO, 'Stockcode: ' + SLI.STOCKCODE
+ ' Stock_Loc_Info Total: ' + CONVERT(VARCHAR, SUM(QTY))
+ ' Total Stock: ' + CONVERT(VARCHAR, S.TOTALSTOCK)
+ ' Out By: ' + CONVERT(VARCHAR, S.TOTALSTOCK - SUM(QTY))
+ '' ,
'S0006', -1, 'ERROR'
FROM STOCK_LOC_INFO SLI
JOIN STOCK_ITEMS S ON SLI.STOCKCODE = S.STOCKCODE
INNER JOIN STOCK_LOCATIONS L ON SLI.LOCATION = L.LOCNO AND L.IS_WIPLOCATION <> 'Y' -- Exclude WIP locations
WHERE S.STATUS <> 'L'
GROUP BY SLI.STOCKCODE, S.TOTALSTOCK
HAVING ABS(ABS(ISNULL(SUM(SLI.QTY), 0))- ABS(ISNULL(S.TOTALSTOCK, 0))) > 0.1

INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, CONVERT(VARCHAR, @@ROWCOUNT) + ' Problem Records Found', 'TEXT'

IF CHARINDEX('Y', @CONFIG) <> 0
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'Fixing Total Stock Figure', 'TEXT'

UPDATE S
SET TOTALSTOCK = SUMQTY
FROM STOCK_ITEMS S
JOIN (
SELECT STOCKCODE, SUM(QTY) AS SUMQTY FROM STOCK_LOC_INFO
INNER JOIN STOCK_LOCATIONS L ON STOCK_LOC_INFO.LOCATION = L.LOCNO AND L.IS_WIPLOCATION <> 'Y' -- Exclude WIP locations
GROUP BY STOCKCODE
) SLI ON S.STOCKCODE = SLI.STOCKCODE
WHERE ABS(ABS(ISNULL(SUMQTY, 0))- ABS(ISNULL(S.TOTALSTOCK, 0))) > 0.1 AND S.STATUS <> 'L'

INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, CONVERT(VARCHAR, @@ROWCOUNT) + ' Records Fixed', 'TEXT'
END
END
ELSE
BEGIN
IF CHARINDEX('L', @CONFIG) = 0
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'No Total Stock Errors found', 'TEXT'
END
END

-------------------------------------------------------------------------

INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'Check for invalid STOCK CODES', 'TEXT'
    DECLARE @COUNT INTEGER
    DECLARE @INVALID_REC_COUNT INTEGER
    DECLARE @INVALIDCHAR CHAR(1)
    DECLARE @REC_COUNT INTEGER
DECLARE @TEMP_INVALID_CHARS VARCHAR(200)
DECLARE @INVALID_CHAR CHAR(1)
DECLARE @INVALID_CHARSTR VARCHAR(200)
DECLARE @INDEX INT
EXECUTE GET_PROFILE_VALUE 'PREVENT_STOCKITEM_CHARACTERS', @TEMP_INVALID_CHARS OUTPUT
IF LEN(@TEMP_INVALID_CHARS) > 0
BEGIN
SET @INVALID_CHARSTR = ''
SET @INDEX = CHARINDEX(', ', @TEMP_INVALID_CHARS)
WHILE @INDEX > 0
BEGIN
SET @INVALID_CHAR = CHAR(Substring(@TEMP_INVALID_CHARS, 1, @INDEX-1))

SET @INVALID_CHARSTR = @INVALID_CHARSTR + @INVALID_CHAR
SET @TEMP_INVALID_CHARS = RIGHT(@TEMP_INVALID_CHARS, LEN(@TEMP_INVALID_CHARS)-@INDEX) --GET THE REMANING CHARS AFTER THE LOCATED COMMA
SET @INDEX = CHARINDEX(', ', @TEMP_INVALID_CHARS)
END
SET @INVALID_CHARSTR = @INVALID_CHARSTR + CHAR(@TEMP_INVALID_CHARS)
END



    SET @COUNT = 0
    SET @INVALID_REC_COUNT = 0
    SELECT @REC_COUNT = COUNT(1) FROM VERIFICATION_LINES

    DECLARE @ESCAPECHAR1 VARCHAR(1)
      DECLARE @ESCAPECHAR2 VARCHAR(1)
    IF @INVALID_CHARSTR IS NOT NULL
    BEGIN
      SET @COUNT = LEN(@INVALID_CHARSTR)
      WHILE @COUNT > 0
      BEGIN
        SELECT @INVALIDCHAR = SUBSTRING(@INVALID_CHARSTR, @COUNT, 1)
        IF @INVALIDCHAR = '%' OR @INVALIDCHAR = '_' OR @INVALIDCHAR = '['
        BEGIN
          SET @ESCAPECHAR1 = '['
          SET @ESCAPECHAR2 = ']'
        END
        ELSE
        BEGIN
          SET @ESCAPECHAR1 = ''
          SET @ESCAPECHAR2 = ''
        END

        INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS, SOURCE_SEQ, LINETYPE)
        SELECT @HDR_SEQNO,
              '' + STOCKCODE + '' + SPACE(25 - LEN(STOCKCODE)) + '' + [DESCRIPTION] + '' + SPACE(42 - LEN(DESCRIPTION))
              + 'INVALID STOCKCODE - CONTAINS INVALID CHARACTER ' + @INVALIDCHAR,
              'S0010',
              -1,
              'ERROR'
        FROM STOCK_ITEMS WHERE STOCKCODE LIKE '%' + @ESCAPECHAR1 + @INVALIDCHAR + @ESCAPECHAR2+ '%'
        SET @COUNT = @COUNT -1
      END
    END
    SELECT @INVALID_REC_COUNT = (SELECT COUNT(1) FROM VERIFICATION_LINES) - @REC_COUNT


IF EXISTS(
SELECT STOCKCODE FROM STOCK_ITEMS WHERE LEN(STOCKCODE) = 0
)
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS, SOURCE_SEQ, LINETYPE)
SELECT @HDR_SEQNO, '' + STOCKCODE + '' + SPACE(25 - LEN(STOCKCODE)) + '' + [DESCRIPTION] + '' + SPACE(42 - LEN(DESCRIPTION))
      'STOCKCODE BLANK', 'S0007', -1, 'ERROR'
FROM STOCK_ITEMS
WHERE LEN(STOCKCODE) = 0
END
ELSE
BEGIN
IF (CHARINDEX('L', @CONFIG) = 0) AND (@INVALID_REC_COUNT = 0)
BEGIN
INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
SELECT @HDR_SEQNO, 'No invalid STOCKCODES found', 'TEXT'
END
END
  END

  IF @STANDALONE = 'Y'
  BEGIN
    INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
    SELECT @HDR_SEQNO, 'Verification Completed '
      + LEFT(CONVERT(VARCHAR, GETDATE(), 109), 50) + ' '
      + CONVERT(VARCHAR(5), DATEDIFF(SECOND, (SELECT CREATEDATE FROM VERIFICATION_HDR WHERE SEQNO = @HDR_SEQNO), GETDATE())) + ' Seconds', 'TEXT'

SELECT MESSAGE FROM VERIFICATION_LINES WHERE HDR_SEQNO = @HDR_SEQNO
  END
  ELSE
  BEGIN
    SET @ENDTIME = GETDATE()
    INSERT INTO VERIFICATION_LINES (HDR_SEQNO, MESSAGE, V_CLASS)
    SELECT @HDR_SEQNO, 'Duration for stock verification: '
      + CONVERT(VARCHAR(5), DATEDIFF(SECOND, @STARTTIME, @ENDTIME)) + ' Seconds', 'TEXT'
  END

END


Procedure: DRACCS_BALANCE
NameDRACCS_BALANCE
Note
CodeCREATE PROCEDURE [dbo].[DRACCS_BALANCE]
 AS
 BEGIN

   INSERT INTO ACCS_BALANCE (ACCNO, ALPHACODE, NAME, ACCGROUP, CURRENCYNO, HEAD_ACCNO, ISHEADOFFICE, AGEDBAL0,
   AGEDBAL1, AGEDBAL2, AGEDBAL3, BALANCE, PRIOR_AGEDBAL0, PRIOR_AGEDBAL1, PRIOR_AGEDBAL2, PRIOR_AGEDBAL3, PRIOR_BALANCE, POST_CODE)
   SELECT ACCNO, ALPHACODE, NAME, ACCGROUP, CURRENCYNO, ACCNO, 'Y',
     (Select Sum(AGEDBAL0) from Dr_Accs where Head_AccNO = HeadOffice.AccNo or AccNo = HeadOffice.AccNo) AGEDBAL0,
     (Select Sum(AGEDBAL1) from Dr_Accs where Head_AccNO = HeadOffice.AccNo or AccNo = HeadOffice.AccNo) AGEDBAL1,
     (Select Sum(AGEDBAL2) from Dr_Accs where Head_AccNO = HeadOffice.AccNo or AccNo = HeadOffice.AccNo) AGEDBAL2,
     (Select Sum(AGEDBAL3) from Dr_Accs where Head_AccNO = HeadOffice.AccNo or AccNo = HeadOffice.AccNo) AGEDBAL3,
     (Select Sum(BALANCE) from Dr_Accs where Head_AccNO = HeadOffice.AccNo or AccNo = HeadOffice.AccNo) BALANCE,
     (Select Sum(PRIOR_AGEDBAL0) from Dr_Accs where Head_AccNO = HeadOffice.AccNo or AccNo = HeadOffice.AccNo) PRIOR_AGEDBAL0,
     (Select Sum(PRIOR_AGEDBAL1) from Dr_Accs where Head_AccNO = HeadOffice.AccNo or AccNo = HeadOffice.AccNo) PRIOR_AGEDBAL1,
     (Select Sum(PRIOR_AGEDBAL2) from Dr_Accs where Head_AccNO = HeadOffice.AccNo or AccNo = HeadOffice.AccNo) PRIOR_AGEDBAL2,
     (Select Sum(PRIOR_AGEDBAL3) from Dr_Accs where Head_AccNO = HeadOffice.AccNo or AccNo = HeadOffice.AccNo) PRIOR_AGEDBAL3,
     (Select Sum(PRIOR_BALANCE) from Dr_Accs where Head_AccNO = HeadOffice.AccNo or AccNo = HeadOffice.AccNo) PRIOR_BALANCE,
     HeadOffice.POST_CODE
   FROM DR_ACCS HeadOffice
   WHERE (STATEMENT <> 'N') AND (HEAD_ACCNO IS NULL or HEAD_ACCNO = -1)
   ORDER BY HeadOffice.ACCNO

   INSERT INTO ACCS_BALANCE (ACCNO, ALPHACODE, NAME, ACCGROUP, CURRENCYNO, HEAD_ACCNO, ISHEADOFFICE, AGEDBAL0,
   AGEDBAL1, AGEDBAL2, AGEDBAL3, BALANCE, PRIOR_AGEDBAL0, PRIOR_AGEDBAL1, PRIOR_AGEDBAL2, PRIOR_AGEDBAL3, PRIOR_BALANCE, POST_CODE)
     SELECT D.ACCNO, D.ALPHACODE, D.NAME, D.ACCGROUP, D.CURRENCYNO, D.HEAD_ACCNO, 'N', D.AGEDBAL0,
     D.AGEDBAL1, D.AGEDBAL2, D.AGEDBAL3, D.BALANCE, D.PRIOR_AGEDBAL0, D.PRIOR_AGEDBAL1,
     D.PRIOR_AGEDBAL2, D.PRIOR_AGEDBAL3, D.PRIOR_BALANCE,
     D.POST_CODE
     FROM DR_ACCS D
     JOIN ACCS_BALANCE AB ON AB.ACCNO = D.HEAD_ACCNO AND AB.ISHEADOFFICE = 'Y'
     WHERE (STATEMENT <> 'N')
     ORDER BY D.ACCNO

 END


Procedure: DR_ACCS_BALFWD_BAL_DELTAS
NameDR_ACCS_BALFWD_BAL_DELTAS
Note
CodeCREATE PROCEDURE [dbo].[DR_ACCS_BALFWD_BAL_DELTAS]
  @ACCNO INTEGER, @TOAGEDBAL INTEGER, @AMOUNT FLOAT, @AGEDBAL0 FLOAT OUTPUT,
  @AGEDBAL1 FLOAT OUTPUT, @AGEDBAL2 FLOAT OUTPUT, @AGEDBAL3 FLOAT OUTPUT,
  @PRIOR_AGEDBAL0 FLOAT OUTPUT, @PRIOR_AGEDBAL1 FLOAT OUTPUT, @PRIOR_AGEDBAL2 FLOAT OUTPUT
AS
  DECLARE @ACC_AGEDBAL1 FLOAT
  DECLARE @ACC_AGEDBAL2 FLOAT
  DECLARE @ACC_AGEDBAL3 FLOAT
  DECLARE @ALLOC FLOAT
  DECLARE @AGE INTEGER
  DECLARE @AGEDBAL FLOAT
  DECLARE @AGEDBAL_DELTA FLOAT
BEGIN
  SET @AGEDBAL0 = 0
  SET @AGEDBAL1 = 0
  SET @AGEDBAL2 = 0
  SET @AGEDBAL3 = 0
  SET @PRIOR_AGEDBAL0 = 0
  SET @PRIOR_AGEDBAL1 = 0
  SET @PRIOR_AGEDBAL2 = 0

  IF (@TOAGEDBAL = 0)
    SET @AGEDBAL0 = @AMOUNT
  ELSE IF (@TOAGEDBAL = 1)
  BEGIN
    SET @AGEDBAL1 = @AMOUNT
    SET @PRIOR_AGEDBAL0 = @AGEDBAL1
  END
  ELSE IF (@TOAGEDBAL = 2)
  BEGIN
    SET @AGEDBAL2 = @AMOUNT
    SET @PRIOR_AGEDBAL1 = @AGEDBAL2
  END
  ELSE IF (@TOAGEDBAL = 3)
  BEGIN
    SET @AGEDBAL3 = @AMOUNT
    SET @PRIOR_AGEDBAL2 = @AGEDBAL3
  END
  ELSE /* From Oldest */
  BEGIN
    SELECT @ACC_AGEDBAL1 = AGEDBAL1, @ACC_AGEDBAL2 = AGEDBAL2, @ACC_AGEDBAL3 = AGEDBAL3
      FROM DR_ACCS WHERE ACCNO = @ACCNO

    SET @ALLOC = @AMOUNT
    SET @AGE = 3
    WHILE ((@ALLOC <> 0) AND (@AGE > 0))
    BEGIN
      SET @AGEDBAL = 0
      SET @AGEDBAL_DELTA = 0
      IF (@AGE = 1)
        SET @AGEDBAL = @ACC_AGEDBAL1
      ELSE IF (@AGE = 2)
        SET @AGEDBAL = @ACC_AGEDBAL2
      ELSE IF (@AGE = 3)
        SET @AGEDBAL = @ACC_AGEDBAL3

      IF (((@AGEDBAL < 0) AND (@ALLOC > 0)) OR ((@AGEDBAL > 0) AND (@ALLOC < 0)))
      BEGIN
        IF (((@ALLOC > 0) AND (@ALLOC > -@AGEDBAL)) OR ((@ALLOC < 0) AND (-@ALLOC > @AGEDBAL)))
        BEGIN
          SET @AGEDBAL_DELTA = -@AGEDBAL
          SET @ALLOC = @ALLOC + @AGEDBAL
        END
        ELSE
        BEGIN
          SET @AGEDBAL_DELTA = @ALLOC
          SET @ALLOC = 0
        END
      END

      IF (@AGE = 1)
      BEGIN
        SET @AGEDBAL1 = @AGEDBAL_DELTA
        SET @PRIOR_AGEDBAL0 = @AGEDBAL1
      END
      ELSE IF (@AGE = 2)
      BEGIN
        SET @AGEDBAL2 = @AGEDBAL_DELTA
        SET @PRIOR_AGEDBAL1 = @AGEDBAL2
      END
      ELSE IF (@AGE = 3)
      BEGIN
        SET @AGEDBAL3 = @AGEDBAL_DELTA
        SET @PRIOR_AGEDBAL2 = @AGEDBAL3
      END

      SET @AGE = @AGE - 1
    END

    IF (@ALLOC <> 0)
      SET @AGEDBAL0 = @ALLOC
  END
END


Procedure: DR_CR_ALLOCATION_AVE_DAYS_SP
NameDR_CR_ALLOCATION_AVE_DAYS_SP
Note
CodeCREATE PROCEDURE [dbo].[DR_CR_ALLOCATION_AVE_DAYS_SP]
@ACCNO INT = -1,
@AVERAGE_DAYS INT = 0 OUTPUT, /** OUTPUT DR AVERAGE DAY COUNT FOR SINGLE QUERY USE **/
@AVERAGE_DAYS_CR INT = 0 OUTPUT /** SAME, BUT FOR CREDITORS **/

AS
SET NOCOUNT ON
DECLARE @SPAN INT

/** IF IT HAS BEEN RUN TODAY ALREADY, DONT RECALCULATE **/
IF (@ACCNO = -1 AND (SELECT (CONVERT(INT, ISNULL(AVE_DAYS_SP_LASTRUN, CONVERT(DATETIME, '1900-01-01')))) FROM GENERAL_INFO) = CONVERT(INT, GETDATE()))
RETURN

/** Calculate avg debtors invoice age **/
SELECT @SPAN = ISNULL(PV.FIELDVALUE, P.DEFAULTVALUE) FROM PROFILE_FIELDS P
LEFT JOIN PROFILE_VALUES PV ON P.FIELDNAME = PV.FIELDNAME WHERE P.FIELDNAME = 'AVG_DEBTORDAY_CALCULATIONSPAN'
IF (SELECT ISNULL(PV.FIELDVALUE, P.DEFAULTVALUE) FROM PROFILE_FIELDS P LEFT JOIN PROFILE_VALUES PV ON P.FIELDNAME = PV.FIELDNAME WHERE P.FIELDNAME = 'AVG_DEBTORDAY') = 'Y'
  BEGIN
  IF @ACCNO = -1 /** RUN UPDATE FOR ALL ACCNOS IF INPUT ACCNO IS 0 **/
BEGIN
    UPDATE D
    SET AVE_DAYS_TO_PAY = ISNULL(CASE WHEN UP.ACCNO IS NULL THEN AVEDAYSP ELSE (AVEDAYSP + AVEDAYSUP) / 2 END, 0)
    FROM DR_ACCS D
    LEFT JOIN (
    SELECT DT.ACCNO, AVG(DATEDIFF(DD, TRANSDATE, ALLOCTIME)) AS AVEDAYSP
    FROM DR_ALLOCATIONS D
    JOIN DR_TRANS DT ON D.TRANS_SEQNO = DT.SEQNO AND DATEDIFF(M, TRANSDATE, GETDATE()) <= @SPAN
    GROUP BY DT.ACCNO
    ) P ON D.ACCNO = P.ACCNO
    LEFT JOIN (
    SELECT ACCNO, AVG(DATEDIFF(DD, TRANSDATE, GETDATE())) AS AVEDAYSUP
    FROM DR_TRANS
    WHERE TRANSTYPE = 1 AND ALLOCATED <> 2 AND PAY_STATUS <> 1
    GROUP BY ACCNO
    ) UP ON D.ACCNO = UP.ACCNO
    END
  ELSE
    BEGIN
    UPDATE D
    SET AVE_DAYS_TO_PAY = ISNULL(CASE WHEN UP.ACCNO IS NULL THEN AVEDAYSP ELSE (AVEDAYSP + AVEDAYSUP) / 2 END, 0)
    FROM DR_ACCS D
    LEFT JOIN (
    SELECT DT.ACCNO, AVG(DATEDIFF(DD, TRANSDATE, ALLOCTIME)) AS AVEDAYSP
    FROM DR_ALLOCATIONS D
    JOIN DR_TRANS DT ON D.TRANS_SEQNO = DT.SEQNO
    WHERE DT.ACCNO = @ACCNO
    GROUP BY DT.ACCNO
    ) P ON D.ACCNO = P.ACCNO
    LEFT JOIN (
    SELECT ACCNO, AVG(DATEDIFF(DD, TRANSDATE, GETDATE())) AS AVEDAYSUP
    FROM DR_TRANS
    WHERE ACCNO = @ACCNO AND TRANSTYPE = 1 AND ALLOCATED <> 2 AND PAY_STATUS <> 1
    GROUP BY ACCNO
    ) UP ON D.ACCNO = UP.ACCNO
    WHERE D.ACCNO = @ACCNO
    SELECT @AVERAGE_DAYS = AVE_DAYS_TO_PAY FROM DR_ACCS WHERE ACCNO = @ACCNO
    END
  END

/** Calculate avg creditors invoice age **/
SELECT @SPAN = ISNULL(PV.FIELDVALUE, P.DEFAULTVALUE) FROM PROFILE_FIELDS P
LEFT JOIN PROFILE_VALUES PV ON P.FIELDNAME = PV.FIELDNAME WHERE P.FIELDNAME = 'AVG_CREDITORDAY_CALCULATIONSPAN'

IF (SELECT ISNULL(PV.FIELDVALUE, P.DEFAULTVALUE) FROM PROFILE_FIELDS P LEFT JOIN PROFILE_VALUES PV ON P.FIELDNAME = PV.FIELDNAME WHERE P.FIELDNAME = 'AVG_DEBTORDAY') = 'Y'
  BEGIN
  IF @ACCNO = -1 /**RUN UPDATE FOR ALL ACCNOS IF INPUT ACCNO IS 0 **/
BEGIN
    UPDATE C
    SET AVE_DAYS_TO_PAY = ISNULL(CASE WHEN UP.ACCNO IS NULL THEN AVEDAYSP ELSE (AVEDAYSP + AVEDAYSUP) / 2 END, 0)
    FROM CR_ACCS C
    LEFT JOIN (
    SELECT CT.ACCNO, AVG(DATEDIFF(DD, TRANSDATE, ALLOCTIME)) AS AVEDAYSP
    FROM CR_ALLOCATIONS C
    JOIN CR_TRANS CT ON C.TRANS_SEQNO = CT.SEQNO AND DATEDIFF(M, TRANSDATE, GETDATE()) <= @SPAN
    GROUP BY CT.ACCNO
    ) P ON C.ACCNO = P.ACCNO
    LEFT JOIN (
    SELECT ACCNO, AVG(DATEDIFF(DD, TRANSDATE, GETDATE())) AS AVEDAYSUP
    FROM CR_TRANS
    WHERE TRANSTYPE = 1 AND ALLOCATED <> 2 AND PAYSTATUS <> 1
    GROUP BY ACCNO
    ) UP ON C.ACCNO = UP.ACCNO
    END
  ELSE
    BEGIN
    UPDATE C
    SET AVE_DAYS_TO_PAY = ISNULL(CASE WHEN UP.ACCNO IS NULL THEN AVEDAYSP ELSE (AVEDAYSP + AVEDAYSUP) / 2 END, 0)
    FROM CR_ACCS C
    LEFT JOIN (
    SELECT CT.ACCNO, AVG(DATEDIFF(DD, TRANSDATE, ALLOCTIME)) AS AVEDAYSP
    FROM CR_ALLOCATIONS C
    JOIN CR_TRANS CT ON C.TRANS_SEQNO = CT.SEQNO
    WHERE CT.ACCNO = @ACCNO
    GROUP BY CT.ACCNO
    ) P ON C.ACCNO = P.ACCNO
    LEFT JOIN (
    SELECT ACCNO, AVG(DATEDIFF(DD, TRANSDATE, GETDATE())) AS AVEDAYSUP
    FROM CR_TRANS
    WHERE ACCNO = @ACCNO AND TRANSTYPE = 1 AND ALLOCATED <> 2 AND PAYSTATUS <> 1
    GROUP BY ACCNO
    ) UP ON C.ACCNO = UP.ACCNO
    WHERE C.ACCNO = @ACCNO
    SELECT @AVERAGE_DAYS_CR = AVE_DAYS_TO_PAY FROM CR_ACCS WHERE ACCNO = @ACCNO
    END
  END

UPDATE GENERAL_INFO SET AVE_DAYS_SP_LASTRUN = GETDATE()


Procedure: DR_WEEKLY_AGED_BALANCES
NameDR_WEEKLY_AGED_BALANCES
Note
CodeCREATE PROCEDURE [dbo].[DR_WEEKLY_AGED_BALANCES]
  @ACCNO INTEGER,
  @TODAYS_DATE DATETIME,
  @BY_TRADE_TYPE CHAR(1)
AS
  DECLARE @WEEK_BAL_0 FLOAT,
          @WEEK_BAL_1 FLOAT,
          @WEEK_BAL_2 FLOAT,
          @WEEK_BAL_3 FLOAT,
          @BALANCE FLOAT,
          @WEEK_NO_0 INTEGER,
          @WEEK_NO_1 INTEGER,
          @WEEK_NO_2 INTEGER,
          @WEEK_NO INTEGER,
          @TRTOT FLOAT,
          @X_TRADETYPE VARCHAR(2)
BEGIN
  IF (@TODAYS_DATE IS NULL)
    SELECT @TODAYS_DATE=GETDATE()
  SELECT @WEEK_NO_0=MAX(WEEK_NO) FROM WEEK_DATES
    WHERE @TODAYS_DATE>=START_DATE
    AND @TODAYS_DATE<(END_DATE+1)
  SELECT @WEEK_NO_1=@WEEK_NO_0-1
  SELECT @WEEK_NO_2=@WEEK_NO_0-2

  SELECT @X_TRADETYPE=NULL;
  SELECT @WEEK_BAL_0=0;
  SELECT @WEEK_BAL_1=0;
  SELECT @WEEK_BAL_2=0;
  SELECT @WEEK_BAL_3=0;

  DECLARE DR_TRANS_CURSOR CURSOR
    FOR SELECT WEEK_NO, SUM(AMOUNT-ALLOCATEDBAL) TRTOT FROM DR_TRANS
    WHERE ACCNO=@ACCNO GROUP BY WEEK_NO ORDER BY WEEK_NO
  OPEN DR_TRANS_CURSOR
  FETCH NEXT FROM DR_TRANS_CURSOR
    INTO @WEEK_NO, @TRTOT

  WHILE @@FETCH_STATUS = 0
  BEGIN
    IF ((@WEEK_NO>0) AND (@WEEK_NO=@WEEK_NO_0))
      SELECT @WEEK_BAL_0=@TRTOT
    ELSE IF ((@WEEK_NO>0) AND (@WEEK_NO=@WEEK_NO_1))
      SELECT @WEEK_BAL_1=@TRTOT
    ELSE IF ((@WEEK_NO>0) AND (@WEEK_NO=@WEEK_NO_2))
      SELECT @WEEK_BAL_2=@TRTOT
    ELSE IF ((@WEEK_NO<=0) OR (@WEEK_NO<@WEEK_NO_2))
      SELECT @WEEK_BAL_3=@WEEK_BAL_3+@TRTOT

    FETCH NEXT FROM DR_TRANS_CURSOR
      INTO @WEEK_NO, @TRTOT
  END
  CLOSE DR_TRANS_CURSOR
  DEALLOCATE DR_TRANS_CURSOR
  SELECT @BALANCE=@WEEK_BAL_0+@WEEK_BAL_1+@WEEK_BAL_2+@WEEK_BAL_3
  SELECT @WEEK_BAL_0 "WEEK_BAL_0", @WEEK_BAL_1 "WEEK_BAL_1",
    @WEEK_BAL_2 "WEEK_BAL_2", @WEEK_BAL_3 "WEEK_BAL_3",
    @BALANCE "BALANCE", @WEEK_NO_0 "WEEK_NO_0",
    @X_TRADETYPE "X_TRADETYPE"
END


Procedure: dt_addtosourcecontrol
Namedt_addtosourcecontrol
Note
Codecreate proc [dbo].[dt_addtosourcecontrol]
    @vchSourceSafeINI varchar(255) = '',
    @vchProjectName varchar(255) ='',
    @vchComment varchar(255) ='',
    @vchLoginName varchar(255) ='',
    @vchPassword varchar(255) =''

as

set nocount on

declare @iReturn int
declare @iObjectId int
select @iObjectId = 0

declare @iStreamObjectId int
select @iStreamObjectId = 0

declare @VSSGUID varchar(100)
select @VSSGUID = 'SQLVersionControl.VCS_SQL'

declare @vchDatabaseName varchar(255)
select @vchDatabaseName = db_name()

declare @iReturnValue int
select @iReturnValue = 0

declare @iPropertyObjectId int
declare @vchParentId varchar(255)

declare @iObjectCount int
select @iObjectCount = 0

    exec @iReturn = master.dbo.sp_OACreate @VSSGUID, @iObjectId OUT
    if @iReturn <> 0 GOTO E_OAError


    /* Create Project in SS */
    exec @iReturn = master.dbo.sp_OAMethod @iObjectId,
'AddProjectToSourceSafe',
NULL,
@vchSourceSafeINI,
@vchProjectName output,
@@SERVERNAME,
@vchDatabaseName,
@vchLoginName,
@vchPassword,
@vchComment


    if @iReturn <> 0 GOTO E_OAError

    /* Set Database Properties */

    begin tran SetProperties

    /* add high level object */

    exec @iPropertyObjectId = dbo.dt_adduserobject_vcs 'VCSProjectID'

    select @vchParentId = CONVERT(varchar(255), @iPropertyObjectId)

    exec dbo.dt_setpropertybyid @iPropertyObjectId, 'VCSProjectID', @vchParentId , NULL
    exec dbo.dt_setpropertybyid @iPropertyObjectId, 'VCSProject' , @vchProjectName , NULL
    exec dbo.dt_setpropertybyid @iPropertyObjectId, 'VCSSourceSafeINI' , @vchSourceSafeINI , NULL
    exec dbo.dt_setpropertybyid @iPropertyObjectId, 'VCSSQLServer', @@SERVERNAME, NULL
    exec dbo.dt_setpropertybyid @iPropertyObjectId, 'VCSSQLDatabase', @vchDatabaseName, NULL

    if @@error <> 0 GOTO E_General_Error

    commit tran SetProperties

    select @iObjectCount = 0;

CleanUp:
    select @vchProjectName
    select @iObjectCount
    return

E_General_Error:
    /* this is an all or nothing. No specific error messages */
    goto CleanUp

E_OAError:
    exec dbo.dt_displayoaerror @iObjectId, @iReturn
    goto CleanUp


Procedure: dt_addtosourcecontrol_u
Namedt_addtosourcecontrol_u
Note
Codecreate proc [dbo].[dt_addtosourcecontrol_u]
    @vchSourceSafeINI nvarchar(255) = '',
    @vchProjectName nvarchar(255) ='',
    @vchComment nvarchar(255) ='',
    @vchLoginName nvarchar(255) ='',
    @vchPassword nvarchar(255) =''

as
-- This procedure should no longer be called; dt_addtosourcecontrol should be called instead.
-- Calls are forwarded to dt_addtosourcecontrol to maintain backward compatibility
set nocount on
exec dbo.dt_addtosourcecontrol
@vchSourceSafeINI,
@vchProjectName,
@vchComment,
@vchLoginName,
@vchPassword


Procedure: dt_adduserobject
Namedt_adduserobject
Note
Code/*
** Add an object to the dtproperties table
*/
create procedure [dbo].[dt_adduserobject]
as
set nocount on
/*
** Create the user object if it does not exist already
*/
begin transaction
insert dbo.dtproperties (property) VALUES ('DtgSchemaOBJECT')
update dbo.dtproperties set objectid=@@identity
where id=@@identity and property='DtgSchemaOBJECT'
commit
return @@identity


Procedure: dt_adduserobject_vcs
Namedt_adduserobject_vcs
Note
Codecreate procedure [dbo].[dt_adduserobject_vcs]
    @vchProperty varchar(64)

as

set nocount on

declare @iReturn int
    /*
    ** Create the user object if it does not exist already
    */
    begin transaction
        select @iReturn = objectid from dbo.dtproperties where property = @vchProperty
        if @iReturn IS NULL
        begin
            insert dbo.dtproperties (property) VALUES (@vchProperty)
            update dbo.dtproperties set objectid=@@identity
                    where id=@@identity and property=@vchProperty
            select @iReturn = @@identity
        end
    commit
    return @iReturn


Procedure: dt_checkinobject
Namedt_checkinobject
Note
Codecreate proc [dbo].[dt_checkinobject]
    @chObjectType char(4),
    @vchObjectName varchar(255),
    @vchComment varchar(255)='',
    @vchLoginName varchar(255),
    @vchPassword varchar(255)='',
    @iVCSFlags int = 0,
    @iActionFlag int = 0, /* 0 => AddFile, 1 => CheckIn */
    @txStream1 Text = '', /* drop stream */ /* There is a bug that if items are NULL they do not pass to OLE servers */
    @txStream2 Text = '', /* create stream */
    @txStream3 Text = '' /* grant stream */


as

set nocount on

declare @iReturn int
declare @iObjectId int
select @iObjectId = 0
declare @iStreamObjectId int

declare @VSSGUID varchar(100)
select @VSSGUID = 'SQLVersionControl.VCS_SQL'

declare @iPropertyObjectId int
select @iPropertyObjectId = 0

    select @iPropertyObjectId = (select objectid from dbo.dtproperties where property = 'VCSProjectID')

    declare @vchProjectName varchar(255)
    declare @vchSourceSafeINI varchar(255)
    declare @vchServerName varchar(255)
    declare @vchDatabaseName varchar(255)
    declare @iReturnValue int
    declare @pos int
    declare @vchProcLinePiece varchar(255)


    exec dbo.dt_getpropertiesbyid_vcs @iPropertyObjectId, 'VCSProject', @vchProjectName OUT
    exec dbo.dt_getpropertiesbyid_vcs @iPropertyObjectId, 'VCSSourceSafeINI', @vchSourceSafeINI OUT
    exec dbo.dt_getpropertiesbyid_vcs @iPropertyObjectId, 'VCSSQLServer', @vchServerName OUT
    exec dbo.dt_getpropertiesbyid_vcs @iPropertyObjectId, 'VCSSQLDatabase', @vchDatabaseName OUT

    if @chObjectType = 'PROC'
    begin
        if @iActionFlag = 1
        begin
            /* Procedure Can have up to three streams
            Drop Stream, Create Stream, GRANT stream */

            begin tran compile_all

            /* try to compile the streams */
            exec (@txStream1)
            if @@error <> 0 GOTO E_Compile_Fail

            exec (@txStream2)
            if @@error <> 0 GOTO E_Compile_Fail

            exec (@txStream3)
            if @@error <> 0 GOTO E_Compile_Fail
        end

        exec @iReturn = master.dbo.sp_OACreate @VSSGUID, @iObjectId OUT
        if @iReturn <> 0 GOTO E_OAError

        exec @iReturn = master.dbo.sp_OAGetProperty @iObjectId, 'GetStreamObject', @iStreamObjectId OUT
        if @iReturn <> 0 GOTO E_OAError

        if @iActionFlag = 1
        begin

            declare @iStreamLength int

select @pos=1
select @iStreamLength = datalength(@txStream2)

if @iStreamLength > 0
begin

while @pos < @iStreamLength
begin

select @vchProcLinePiece = substring(@txStream2, @pos, 255)

exec @iReturn = master.dbo.sp_OAMethod @iStreamObjectId, 'AddStream', @iReturnValue OUT, @vchProcLinePiece
             if @iReturn <> 0 GOTO E_OAError

select @pos = @pos + 255

end

exec @iReturn = master.dbo.sp_OAMethod @iObjectId,
'CheckIn_StoredProcedure',
NULL,
@sProjectName = @vchProjectName,
@sSourceSafeINI = @vchSourceSafeINI,
@sServerName = @vchServerName,
@sDatabaseName = @vchDatabaseName,
@sObjectName = @vchObjectName,
@sComment = @vchComment,
@sLoginName = @vchLoginName,
@sPassword = @vchPassword,
@iVCSFlags = @iVCSFlags,
@iActionFlag = @iActionFlag,
@sStream = ''

end
        end
        else
        begin

            select colid, text into #ProcLines
            from syscomments
            where id = object_id(@vchObjectName)
            order by colid

            declare @iCurProcLine int
            declare @iProcLines int
            select @iCurProcLine = 1
            select @iProcLines = (select count(*) from #ProcLines)
            while @iCurProcLine <= @iProcLines
            begin
                select @pos = 1
                declare @iCurLineSize int
                select @iCurLineSize = len((select text from #ProcLines where colid = @iCurProcLine))
                while @pos <= @iCurLineSize
                begin
                    select @vchProcLinePiece = convert(varchar(255),
                        substring((select text from #ProcLines where colid = @iCurProcLine),
                                  @pos, 255 ))
                    exec @iReturn = master.dbo.sp_OAMethod @iStreamObjectId, 'AddStream', @iReturnValue OUT, @vchProcLinePiece
                    if @iReturn <> 0 GOTO E_OAError
                    select @pos = @pos + 255
                end
                select @iCurProcLine = @iCurProcLine + 1
            end
            drop table #ProcLines

            exec @iReturn = master.dbo.sp_OAMethod @iObjectId,
'CheckIn_StoredProcedure',
NULL,
@sProjectName = @vchProjectName,
@sSourceSafeINI = @vchSourceSafeINI,
@sServerName = @vchServerName,
@sDatabaseName = @vchDatabaseName,
@sObjectName = @vchObjectName,
@sComment = @vchComment,
@sLoginName = @vchLoginName,
@sPassword = @vchPassword,
@iVCSFlags = @iVCSFlags,
@iActionFlag = @iActionFlag,
@sStream = ''
        end

        if @iReturn <> 0 GOTO E_OAError

        if @iActionFlag = 1
        begin
            commit tran compile_all
            if @@error <> 0 GOTO E_Compile_Fail
        end

    end

CleanUp:
return

E_Compile_Fail:
declare @lerror int
select @lerror = @@error
rollback tran compile_all
RAISERROR (@lerror, 16, -1)
goto CleanUp

E_OAError:
if @iActionFlag = 1 rollback tran compile_all
exec dbo.dt_displayoaerror @iObjectId, @iReturn
goto CleanUp


Procedure: dt_checkinobject_u
Namedt_checkinobject_u
Note
Codecreate proc [dbo].[dt_checkinobject_u]
    @chObjectType char(4),
    @vchObjectName nvarchar(255),
    @vchComment nvarchar(255)='',
    @vchLoginName nvarchar(255),
    @vchPassword nvarchar(255)='',
    @iVCSFlags int = 0,
    @iActionFlag int = 0, /* 0 => AddFile, 1 => CheckIn */
    @txStream1 text = '', /* drop stream */ /* There is a bug that if items are NULL they do not pass to OLE servers */
    @txStream2 text = '', /* create stream */
    @txStream3 text = '' /* grant stream */

as
-- This procedure should no longer be called; dt_checkinobject should be called instead.
-- Calls are forwarded to dt_checkinobject to maintain backward compatibility.
set nocount on
exec dbo.dt_checkinobject
@chObjectType,
@vchObjectName,
@vchComment,
@vchLoginName,
@vchPassword,
@iVCSFlags,
@iActionFlag,
@txStream1,
@txStream2,
@txStream3


Procedure: dt_checkoutobject
Namedt_checkoutobject
Note
Codecreate proc [dbo].[dt_checkoutobject]
    @chObjectType char(4),
    @vchObjectName varchar(255),
    @vchComment varchar(255),
    @vchLoginName varchar(255),
    @vchPassword varchar(255),
    @iVCSFlags int = 0,
    @iActionFlag int = 0/* 0 => Checkout, 1 => GetLatest, 2 => UndoCheckOut */

as

set nocount on

declare @iReturn int
declare @iObjectId int
select @iObjectId =0

declare @VSSGUID varchar(100)
select @VSSGUID = 'SQLVersionControl.VCS_SQL'

declare @iReturnValue int
select @iReturnValue = 0

declare @vchTempText varchar(255)

/* this is for our strings */
declare @iStreamObjectId int
select @iStreamObjectId = 0

    declare @iPropertyObjectId int
    select @iPropertyObjectId = (select objectid from dbo.dtproperties where property = 'VCSProjectID')

    declare @vchProjectName varchar(255)
    declare @vchSourceSafeINI varchar(255)
    declare @vchServerName varchar(255)
    declare @vchDatabaseName varchar(255)
    exec dbo.dt_getpropertiesbyid_vcs @iPropertyObjectId, 'VCSProject', @vchProjectName OUT
    exec dbo.dt_getpropertiesbyid_vcs @iPropertyObjectId, 'VCSSourceSafeINI', @vchSourceSafeINI OUT
    exec dbo.dt_getpropertiesbyid_vcs @iPropertyObjectId, 'VCSSQLServer', @vchServerName OUT
    exec dbo.dt_getpropertiesbyid_vcs @iPropertyObjectId, 'VCSSQLDatabase', @vchDatabaseName OUT

    if @chObjectType = 'PROC'
    begin
        /* Procedure Can have up to three streams
           Drop Stream, Create Stream, GRANT stream */

        exec @iReturn = master.dbo.sp_OACreate @VSSGUID, @iObjectId OUT

        if @iReturn <> 0 GOTO E_OAError

        exec @iReturn = master.dbo.sp_OAMethod @iObjectId,
'CheckOut_StoredProcedure',
NULL,
@sProjectName = @vchProjectName,
@sSourceSafeINI = @vchSourceSafeINI,
@sObjectName = @vchObjectName,
@sServerName = @vchServerName,
@sDatabaseName = @vchDatabaseName,
@sComment = @vchComment,
@sLoginName = @vchLoginName,
@sPassword = @vchPassword,
@iVCSFlags = @iVCSFlags,
@iActionFlag = @iActionFlag

        if @iReturn <> 0 GOTO E_OAError


        exec @iReturn = master.dbo.sp_OAGetProperty @iObjectId, 'GetStreamObject', @iStreamObjectId OUT

        if @iReturn <> 0 GOTO E_OAError

        create table #commenttext (id int identity, sourcecode varchar(255))


        select @vchTempText = 'STUB'
        while @vchTempText is not null
        begin
            exec @iReturn = master.dbo.sp_OAMethod @iStreamObjectId, 'GetStream', @iReturnValue OUT, @vchTempText OUT
            if @iReturn <> 0 GOTO E_OAError

            if (@vchTempText = '') set @vchTempText = null
            if (@vchTempText is not null) insert into #commenttext (sourcecode) select @vchTempText
        end

        select 'VCS'=sourcecode from #commenttext order by id
        select 'SQL'=text from syscomments where id = object_id(@vchObjectName) order by colid

    end

CleanUp:
    return

E_OAError:
    exec dbo.dt_displayoaerror @iObjectId, @iReturn
    GOTO CleanUp


Procedure: dt_checkoutobject_u
Namedt_checkoutobject_u
Note
Codecreate proc [dbo].[dt_checkoutobject_u]
    @chObjectType char(4),
    @vchObjectName nvarchar(255),
    @vchComment nvarchar(255),
    @vchLoginName nvarchar(255),
    @vchPassword nvarchar(255),
    @iVCSFlags int = 0,
    @iActionFlag int = 0/* 0 => Checkout, 1 => GetLatest, 2 => UndoCheckOut */

as

-- This procedure should no longer be called; dt_checkoutobject should be called instead.
-- Calls are forwarded to dt_checkoutobject to maintain backward compatibility.
set nocount on
exec dbo.dt_checkoutobject
@chObjectType,
@vchObjectName,
@vchComment,
@vchLoginName,
@vchPassword,
@iVCSFlags,
@iActionFlag


Procedure: dt_displayoaerror
Namedt_displayoaerror
Note
CodeCREATE PROCEDURE [dbo].[dt_displayoaerror]
    @iObject int,
    @iresult int
as

set nocount on

declare @vchOutput varchar(255)
declare @hr int
declare @vchSource varchar(255)
declare @vchDescription varchar(255)

    exec @hr = master.dbo.sp_OAGetErrorInfo @iObject, @vchSource OUT, @vchDescription OUT

    select @vchOutput = @vchSource + ': ' + @vchDescription
    raiserror (@vchOutput, 16, -1)

    return


Procedure: dt_displayoaerror_u
Namedt_displayoaerror_u
Note
CodeCREATE PROCEDURE [dbo].[dt_displayoaerror_u]
    @iObject int,
    @iresult int
as
-- This procedure should no longer be called; dt_displayoaerror should be called instead.
-- Calls are forwarded to dt_displayoaerror to maintain backward compatibility.
set nocount on
exec dbo.dt_displayoaerror
@iObject,
@iresult


Procedure: dt_droppropertiesbyid
Namedt_droppropertiesbyid
Note
Code/*
** Drop one or all the associated properties of an object or an attribute
**
** dt_dropproperties objid, null or '' -- drop all properties of the object itself
** dt_dropproperties objid, property -- drop the property
*/
create procedure [dbo].[dt_droppropertiesbyid]
@id int,
@property varchar(64)
as
set nocount on

if (@property is null) or (@property = '')
delete from dbo.dtproperties where objectid=@id
else
delete from dbo.dtproperties
where objectid=@id and property=@property


Procedure: dt_dropuserobjectbyid
Namedt_dropuserobjectbyid
Note
Code/*
** Drop an object from the dbo.dtproperties table
*/
create procedure [dbo].[dt_dropuserobjectbyid]
@id int
as
set nocount on
delete from dbo.dtproperties where objectid=@id


Procedure: dt_generateansiname
Namedt_generateansiname
Note
Code/*
** Generate an ansi name that is unique in the dtproperties.value column
*/
create procedure [dbo].[dt_generateansiname](@name varchar(255) output)
as
declare @prologue varchar(20)
declare @indexstring varchar(20)
declare @index integer

set @prologue = 'MSDT-A-'
set @index = 1

while 1 = 1
begin
set @indexstring = cast(@index as varchar(20))
set @name = @prologue + @indexstring
if not exists (select value from dtproperties where value = @name)
break

set @index = @index + 1

if (@index = 10000)
goto TooMany
end

Leave:

return

TooMany:

set @name = 'DIAGRAM'
goto Leave


Procedure: dt_getobjwithprop
Namedt_getobjwithprop
Note
Code/*
** Retrieve the owner object(s) of a given property
*/
create procedure [dbo].[dt_getobjwithprop]
@property varchar(30),
@value varchar(255)
as
set nocount on

if (@property is null) or (@property = '')
begin
raiserror('Must specify a property name.', -1, -1)
return (1)
end

if (@value is null)
select objectid id from dbo.dtproperties
where property=@property

else
select objectid id from dbo.dtproperties
where property=@property and value=@value


Procedure: dt_getobjwithprop_u
Namedt_getobjwithprop_u
Note
Code/*
** Retrieve the owner object(s) of a given property
*/
create procedure [dbo].[dt_getobjwithprop_u]
@property varchar(30),
@uvalue nvarchar(255)
as
set nocount on

if (@property is null) or (@property = '')
begin
raiserror('Must specify a property name.', -1, -1)
return (1)
end

if (@uvalue is null)
select objectid id from dbo.dtproperties
where property=@property

else
select objectid id from dbo.dtproperties
where property=@property and uvalue=@uvalue


Procedure: dt_getpropertiesbyid
Namedt_getpropertiesbyid
Note
Code/*
** Retrieve properties by id's
**
** dt_getproperties objid, null or '' -- retrieve all properties of the object itself
** dt_getproperties objid, property -- retrieve the property specified
*/
create procedure [dbo].[dt_getpropertiesbyid]
@id int,
@property varchar(64)
as
set nocount on

if (@property is null) or (@property = '')
select property, version, value, lvalue
from dbo.dtproperties
where @id=objectid
else
select property, version, value, lvalue
from dbo.dtproperties
where @id=objectid and @property=property


Procedure: dt_getpropertiesbyid_u
Namedt_getpropertiesbyid_u
Note
Code/*
** Retrieve properties by id's
**
** dt_getproperties objid, null or '' -- retrieve all properties of the object itself
** dt_getproperties objid, property -- retrieve the property specified
*/
create procedure [dbo].[dt_getpropertiesbyid_u]
@id int,
@property varchar(64)
as
set nocount on

if (@property is null) or (@property = '')
select property, version, uvalue, lvalue
from dbo.dtproperties
where @id=objectid
else
select property, version, uvalue, lvalue
from dbo.dtproperties
where @id=objectid and @property=property


Procedure: dt_getpropertiesbyid_vcs
Namedt_getpropertiesbyid_vcs
Note
Codecreate procedure [dbo].[dt_getpropertiesbyid_vcs]
    @id int,
    @property varchar(64),
    @value varchar(255) = NULL OUT

as

    set nocount on

    select @value = (
        select value
                from dbo.dtproperties
                where @id=objectid and @property=property
                )


Procedure: dt_getpropertiesbyid_vcs_u
Namedt_getpropertiesbyid_vcs_u
Note
Codecreate procedure [dbo].[dt_getpropertiesbyid_vcs_u]
    @id int,
    @property varchar(64),
    @value nvarchar(255) = NULL OUT

as

    -- This procedure should no longer be called; dt_getpropertiesbyid_vcsshould be called instead.
-- Calls are forwarded to dt_getpropertiesbyid_vcs to maintain backward compatibility.
set nocount on
    exec dbo.dt_getpropertiesbyid_vcs
@id,
@property,
@value output


Procedure: dt_isundersourcecontrol
Namedt_isundersourcecontrol
Note
Codecreate proc [dbo].[dt_isundersourcecontrol]
    @vchLoginName varchar(255) = '',
    @vchPassword varchar(255) = '',
    @iWhoToo int = 0 /* 0 => Just check project; 1 => get list of objs */

as

set nocount on

declare @iReturn int
declare @iObjectId int
select @iObjectId = 0

declare @VSSGUID varchar(100)
select @VSSGUID = 'SQLVersionControl.VCS_SQL'

declare @iReturnValue int
select @iReturnValue = 0

declare @iStreamObjectId int
select @iStreamObjectId = 0

declare @vchTempText varchar(255)

    declare @iPropertyObjectId int
    select @iPropertyObjectId = (select objectid from dbo.dtproperties where property = 'VCSProjectID')

    declare @vchProjectName varchar(255)
    declare @vchSourceSafeINI varchar(255)
    declare @vchServerName varchar(255)
    declare @vchDatabaseName varchar(255)
    exec dbo.dt_getpropertiesbyid_vcs @iPropertyObjectId, 'VCSProject', @vchProjectName OUT
    exec dbo.dt_getpropertiesbyid_vcs @iPropertyObjectId, 'VCSSourceSafeINI', @vchSourceSafeINI OUT
    exec dbo.dt_getpropertiesbyid_vcs @iPropertyObjectId, 'VCSSQLServer', @vchServerName OUT
    exec dbo.dt_getpropertiesbyid_vcs @iPropertyObjectId, 'VCSSQLDatabase', @vchDatabaseName OUT

    if (@vchProjectName = '') set @vchProjectName = null
    if (@vchSourceSafeINI = '') set @vchSourceSafeINI = null
    if (@vchServerName = '') set @vchServerName = null
    if (@vchDatabaseName = '') set @vchDatabaseName = null

    if (@vchProjectName is null) or (@vchSourceSafeINI is null) or (@vchServerName is null) or (@vchDatabaseName is null)
    begin
        RAISERROR('Not Under Source Control', 16, -1)
        return
    end

    if @iWhoToo = 1
    begin

        /* Get List of Procs in the project */
        exec @iReturn = master.dbo.sp_OACreate @VSSGUID, @iObjectId OUT
        if @iReturn <> 0 GOTO E_OAError

        exec @iReturn = master.dbo.sp_OAMethod @iObjectId,
'GetListOfObjects',
NULL,
@vchProjectName,
@vchSourceSafeINI,
@vchServerName,
@vchDatabaseName,
@vchLoginName,
@vchPassword

        if @iReturn <> 0 GOTO E_OAError

        exec @iReturn = master.dbo.sp_OAGetProperty @iObjectId, 'GetStreamObject', @iStreamObjectId OUT

        if @iReturn <> 0 GOTO E_OAError

        create table #ObjectList (id int identity, vchObjectlist varchar(255))

        select @vchTempText = 'STUB'
        while @vchTempText is not null
        begin
            exec @iReturn = master.dbo.sp_OAMethod @iStreamObjectId, 'GetStream', @iReturnValue OUT, @vchTempText OUT
            if @iReturn <> 0 GOTO E_OAError

            if (@vchTempText = '') set @vchTempText = null
            if (@vchTempText is not null) insert into #ObjectList (vchObjectlist ) select @vchTempText
        end

        select vchObjectlist from #ObjectList order by id
    end

CleanUp:
    return

E_OAError:
    exec dbo.dt_displayoaerror @iObjectId, @iReturn
    goto CleanUp


Procedure: dt_isundersourcecontrol_u
Namedt_isundersourcecontrol_u
Note
Codecreate proc [dbo].[dt_isundersourcecontrol_u]
    @vchLoginName nvarchar(255) = '',
    @vchPassword nvarchar(255) = '',
    @iWhoToo int = 0 /* 0 => Just check project; 1 => get list of objs */

as
-- This procedure should no longer be called; dt_isundersourcecontrol should be called instead.
-- Calls are forwarded to dt_isundersourcecontrol to maintain backward compatibility.
set nocount on
exec dbo.dt_isundersourcecontrol
@vchLoginName,
@vchPassword,
@iWhoToo


Procedure: dt_removefromsourcecontrol
Namedt_removefromsourcecontrol
Note
Codecreate procedure [dbo].[dt_removefromsourcecontrol]

as

    set nocount on

    declare @iPropertyObjectId int
    select @iPropertyObjectId = (select objectid from dbo.dtproperties where property = 'VCSProjectID')

    exec dbo.dt_droppropertiesbyid @iPropertyObjectId, null

    /* -1 is returned by dt_droppopertiesbyid */
    if @@error <> 0 and @@error <> -1 return 1

    return 0


Procedure: dt_setpropertybyid
Namedt_setpropertybyid
Note
Code/*
** If the property already exists, reset the value; otherwise add property
** id -- the id in sysobjects of the object
** property -- the name of the property
** value -- the text value of the property
** lvalue -- the binary value of the property (image)
*/
create procedure [dbo].[dt_setpropertybyid]
@id int,
@property varchar(64),
@value varchar(255),
@lvalue image
as
set nocount on
declare @uvalue nvarchar(255)
set @uvalue = convert(nvarchar(255), @value)
if exists (select * from dbo.dtproperties
where objectid=@id and property=@property)
begin
--
-- bump the version count for this row as we update it
--
update dbo.dtproperties set value=@value, uvalue=@uvalue, lvalue=@lvalue, version=version+1
where objectid=@id and property=@property
end
else
begin
--
-- version count is auto-set to 0 on initial insert
--
insert dbo.dtproperties (property, objectid, value, uvalue, lvalue)
values (@property, @id, @value, @uvalue, @lvalue)
end


Procedure: dt_setpropertybyid_u
Namedt_setpropertybyid_u
Note
Code/*
** If the property already exists, reset the value; otherwise add property
** id -- the id in sysobjects of the object
** property -- the name of the property
** uvalue -- the text value of the property
** lvalue -- the binary value of the property (image)
*/
create procedure [dbo].[dt_setpropertybyid_u]
@id int,
@property varchar(64),
@uvalue nvarchar(255),
@lvalue image
as
set nocount on
--
-- If we are writing the name property, find the ansi equivalent.
-- If there is no lossless translation, generate an ansi name.
--
declare @avalue varchar(255)
set @avalue = null
if (@uvalue is not null)
begin
if (convert(nvarchar(255), convert(varchar(255), @uvalue)) = @uvalue)
begin
set @avalue = convert(varchar(255), @uvalue)
end
else
begin
if 'DtgSchemaNAME' = @property
begin
exec dbo.dt_generateansiname @avalue output
end
end
end
if exists (select * from dbo.dtproperties
where objectid=@id and property=@property)
begin
--
-- bump the version count for this row as we update it
--
update dbo.dtproperties set value=@avalue, uvalue=@uvalue, lvalue=@lvalue, version=version+1
where objectid=@id and property=@property
end
else
begin
--
-- version count is auto-set to 0 on initial insert
--
insert dbo.dtproperties (property, objectid, value, uvalue, lvalue)
values (@property, @id, @avalue, @uvalue, @lvalue)
end


Procedure: dt_validateloginparams
Namedt_validateloginparams
Note
Codecreate proc [dbo].[dt_validateloginparams]
    @vchLoginName varchar(255),
    @vchPassword varchar(255)
as

set nocount on

declare @iReturn int
declare @iObjectId int
select @iObjectId =0

declare @VSSGUID varchar(100)
select @VSSGUID = 'SQLVersionControl.VCS_SQL'

    declare @iPropertyObjectId int
    select @iPropertyObjectId = (select objectid from dbo.dtproperties where property = 'VCSProjectID')

    declare @vchSourceSafeINI varchar(255)
    exec dbo.dt_getpropertiesbyid_vcs @iPropertyObjectId, 'VCSSourceSafeINI', @vchSourceSafeINI OUT

    exec @iReturn = master.dbo.sp_OACreate @VSSGUID, @iObjectId OUT
    if @iReturn <> 0 GOTO E_OAError

    exec @iReturn = master.dbo.sp_OAMethod @iObjectId,
'ValidateLoginParams',
NULL,
@sSourceSafeINI = @vchSourceSafeINI,
@sLoginName = @vchLoginName,
@sPassword = @vchPassword
    if @iReturn <> 0 GOTO E_OAError

CleanUp:
    return

E_OAError:
    exec dbo.dt_displayoaerror @iObjectId, @iReturn
    GOTO CleanUp


Procedure: dt_validateloginparams_u
Namedt_validateloginparams_u
Note
Codecreate proc [dbo].[dt_validateloginparams_u]
    @vchLoginName nvarchar(255),
    @vchPassword nvarchar(255)
as

-- This procedure should no longer be called; dt_validateloginparams should be called instead.
-- Calls are forwarded to dt_validateloginparams to maintain backward compatibility.
set nocount on
exec dbo.dt_validateloginparams
@vchLoginName,
@vchPassword


Procedure: dt_vcsenabled
Namedt_vcsenabled
Note
Codecreate proc [dbo].[dt_vcsenabled]

as

set nocount on

declare @iObjectId int
select @iObjectId = 0

declare @VSSGUID varchar(100)
select @VSSGUID = 'SQLVersionControl.VCS_SQL'

    declare @iReturn int
    exec @iReturn = master.dbo.sp_OACreate @VSSGUID, @iObjectId OUT
    if @iReturn <> 0 raiserror('', 16, -1) /* Can't Load Helper DLLC */


Procedure: dt_verstamp006
Namedt_verstamp006
Note
Code/*
** This procedure returns the version number of the stored
** procedures used by legacy versions of the Microsoft
** Visual Database Tools. Version is 7.0.00.
*/
create procedure [dbo].[dt_verstamp006]
as
select 7000


Procedure: dt_verstamp007
Namedt_verstamp007
Note
Code/*
** This procedure returns the version number of the stored
** procedures used by the the Microsoft Visual Database Tools.
** Version is 7.0.05.
*/
create procedure [dbo].[dt_verstamp007]
as
select 7005


Procedure: dt_whocheckedout
Namedt_whocheckedout
Note
Codecreate proc [dbo].[dt_whocheckedout]
        @chObjectType char(4),
        @vchObjectName varchar(255),
        @vchLoginName varchar(255),
        @vchPassword varchar(255)

as

set nocount on

declare @iReturn int
declare @iObjectId int
select @iObjectId =0

declare @VSSGUID varchar(100)
select @VSSGUID = 'SQLVersionControl.VCS_SQL'

    declare @iPropertyObjectId int

    select @iPropertyObjectId = (select objectid from dbo.dtproperties where property = 'VCSProjectID')

    declare @vchProjectName varchar(255)
    declare @vchSourceSafeINI varchar(255)
    declare @vchServerName varchar(255)
    declare @vchDatabaseName varchar(255)
    exec dbo.dt_getpropertiesbyid_vcs @iPropertyObjectId, 'VCSProject', @vchProjectName OUT
    exec dbo.dt_getpropertiesbyid_vcs @iPropertyObjectId, 'VCSSourceSafeINI', @vchSourceSafeINI OUT
    exec dbo.dt_getpropertiesbyid_vcs @iPropertyObjectId, 'VCSSQLServer', @vchServerName OUT
    exec dbo.dt_getpropertiesbyid_vcs @iPropertyObjectId, 'VCSSQLDatabase', @vchDatabaseName OUT

    if @chObjectType = 'PROC'
    begin
        exec @iReturn = master.dbo.sp_OACreate @VSSGUID, @iObjectId OUT

        if @iReturn <> 0 GOTO E_OAError

        declare @vchReturnValue varchar(255)
        select @vchReturnValue = ''

        exec @iReturn = master.dbo.sp_OAMethod @iObjectId,
'WhoCheckedOut',
@vchReturnValue OUT,
@sProjectName = @vchProjectName,
@sSourceSafeINI = @vchSourceSafeINI,
@sObjectName = @vchObjectName,
@sServerName = @vchServerName,
@sDatabaseName = @vchDatabaseName,
@sLoginName = @vchLoginName,
@sPassword = @vchPassword

        if @iReturn <> 0 GOTO E_OAError

        select @vchReturnValue

    end

CleanUp:
    return

E_OAError:
    exec dbo.dt_displayoaerror @iObjectId, @iReturn
    GOTO CleanUp


Procedure: dt_whocheckedout_u
Namedt_whocheckedout_u
Note
Codecreate proc [dbo].[dt_whocheckedout_u]
        @chObjectType char(4),
        @vchObjectName nvarchar(255),
        @vchLoginName nvarchar(255),
        @vchPassword nvarchar(255)

as

-- This procedure should no longer be called; dt_whocheckedout should be called instead.
-- Calls are forwarded to dt_whocheckedout to maintain backward compatibility.
set nocount on
exec dbo.dt_whocheckedout
@chObjectType,
@vchObjectName,
@vchLoginName,
@vchPassword


Procedure: EXECUTE_DECIMAL_METRIC
NameEXECUTE_DECIMAL_METRIC
Note
CodeCREATE PROCEDURE [dbo].[EXECUTE_DECIMAL_METRIC]
  @METRIC_ID INT,
  @OWNER_ID VARCHAR(64)
AS
BEGIN
  DECLARE @PROC_NAME VARCHAR(50)
  DECLARE @METRIC_RESULT DECIMAL
  DECLARE @RETURN_VALUE INT

  -- Take ownership of the metric --
  UPDATE EXO_METRICS SET NEXT_RUN = GETDATE() + DAYS_BETWEEN_RUNS, LAST_OWNER = @OWNER_ID WHERE ID = @METRIC_ID AND ISNULL(NEXT_RUN, GETDATE() -1) < GETDATE() AND ENABLED = 1

  SET @PROC_NAME = ''

  SELECT @PROC_NAME = PROC_NAME FROM EXO_METRICS WHERE ID = @METRIC_ID AND LAST_OWNER = @OWNER_ID

  -- Execute the metric --
  IF @PROC_NAME != ''
  BEGIN
    EXEC @RETURN_VALUE = @PROC_NAME @METRIC_RESULT = @METRIC_RESULT OUTPUT

    UPDATE EXO_METRICS SET DECIMAL_VALUE = @METRIC_RESULT, LAST_RUN = GETDATE() WHERE ID = @METRIC_ID

    RETURN @RETURN_VALUE
  END
  ELSE
    RETURN 0
END


Procedure: FN_CR_AGEDBALANCES_BACKWARDS
NameFN_CR_AGEDBALANCES_BACKWARDS
Note
Code-- =============================================
-- description: Calculates the aged balances of each transaction line as at a specified age.
-- Child/branch accounts are excluded.
-- Balances are calculated working backwards from the current balance.
-- Indexes on CR_allocations period_seqno and trans_seqno are required for this query to run efficiently.
-- =============================================
CREATE FUNCTION [dbo].[FN_CR_AGEDBALANCES_BACKWARDS]
(
@PERIOD INT = 0,
@ACCNO INT = -1,
@PERIODPARAM_IS_AGE CHAR(1) = 'Y' -- If 'N', then it is assumed that the param passed is periodSeqno
)
RETURNS
  @TMP_AGEDBALANCES
  TABLE (
ACCOUNTNAME VARCHAR(100),
ACCNO INTEGER NOT NULL,
CURRENCY VARCHAR(3),
CURRENCYNO INTEGER,
CURRENCYNAME VARCHAR(30),
ALPHACODE VARCHAR(30),
ACCGROUP INTEGER,
ACCGROUP_NAME VARCHAR(50),
ACCGROUP2 INTEGER,
ACCGROUP2_NAME VARCHAR(50),
TRANSDATE DATETIME,
REF1 VARCHAR(100),
REF2 VARCHAR(100),
REF3 VARCHAR(100),
INVNO VARCHAR(100),
SEQNO INTEGER,
PERIOD_SEQNO INTEGER,
AGEBAL_AGE INTEGER,
AMOUNT DOUBLE PRECISION NOT NULL DEFAULT(0),
EXCHRATE DOUBLE PRECISION NOT NULL DEFAULT(0),
EXCHRATE_ATENDOFPERIOD DOUBLE PRECISION DEFAULT(0), -- For current period this will be current exchrates;
-- For prior period it uses closing rates for the period
AGEDBAL0 DOUBLE PRECISION NOT NULL DEFAULT(0),
AGEDBAL0_FC DOUBLE PRECISION NOT NULL DEFAULT(0),
AGEDBAL1 DOUBLE PRECISION NOT NULL DEFAULT(0),
AGEDBAL1_FC DOUBLE PRECISION NOT NULL DEFAULT(0),
AGEDBAL2 DOUBLE PRECISION NOT NULL DEFAULT(0),
AGEDBAL2_FC DOUBLE PRECISION NOT NULL DEFAULT(0),
AGEDBAL3 DOUBLE PRECISION NOT NULL DEFAULT(0),
AGEDBAL3_FC DOUBLE PRECISION NOT NULL DEFAULT(0),
BALANCE DOUBLE PRECISION NOT NULL DEFAULT(0), -- working backwards(local currency)
BALANCE_FC DOUBLE PRECISION NOT NULL DEFAULT(0) -- working backwards(in currency of account),

)
BEGIN
Declare @period_seqno0 integer,
@MinTranSeqno0 integer,
@AGE integer,
@period_seqno1 integer,
@period_seqno2 integer,
@period_seqno3 integer,
@period_seqno_Current integer,
@MinTranSeqnoCurrent integer,
@Ledger char(1),
@GLPeriod_seqno integer,
@TmpCount integer


-- If the period parameter being passed through is not age then use the period_seqno being passed through
-- to work out the age.
if @PERIODPARAM_IS_AGE = 'N'
select @AGE = age from period_status where seqno = @period
else
select @AGE = @PERIOD

Set @Ledger = 'C'

--retrieve GL periodseqno that gets used to derive the closing rate for the period
select @GLPeriod_seqno = seqno from period_status
where ledger = 'G' and age = @AGE


-- Retrieve period_seqnos for ages.
select @period_seqno_Current = seqno, @MinTranSeqnoCurrent = MinTranSeqno
from PERIOD_STATUS
where AGE = 0 and LEDGER = @Ledger
if @AGE = 0
set @MinTranSeqno0 = @MinTranSeqnoCurrent
else
select @MinTranSeqno0 = MinTranSeqno from PERIOD_STATUS
where AGE = (@AGE - 1) and LEDGER = @Ledger

select @period_seqno0 =seqno from PERIOD_STATUS
where AGE = @AGE and LEDGER = @Ledger
select @period_seqno1 =seqno from PERIOD_STATUS
where AGE = (@AGE + 1) and LEDGER = @Ledger
select @period_seqno2 = seqno from PERIOD_STATUS
where AGE = (@AGE + 2) and LEDGER = @Ledger
select @period_seqno3 = seqno from PERIOD_STATUS
where AGE = (@AGE + 3) and LEDGER = @Ledger

If @ACCNO = -1
begin
--Retrieve all accounts with issues with balance issues. These will be all accounts where the balance based on
--individual transaction details does not match the balance calculated working backwards from the current balance.
--In such cases, we donot provide the ageing of individual transactions.
insert into @TMP_AGEDBALANCES(ACCNO, ACCOUNTNAME, CURRENCY, CURRENCYNO, CURRENCYNAME,
AGEDBAL0 , AGEDBAL0_FC, AGEDBAL1, AGEDBAL1_FC, AGEDBAL2,
AGEDBAL2_FC, AGEDBAL3, AGEDBAL3_FC, BALANCE , BALANCE_FC, EXCHRATE_ATENDOFPERIOD, ref1,
alphacode, accgroup, accgroup2, accgroup_name, accgroup2_name)
select ACCNO, ACCOUNTNAME, CURRENCY, CURRENCYNO, CURRENCYNAME,
AGEDBAL0 , AGEDBAL0_FC, AGEDBAL1, AGEDBAL1_FC, AGEDBAL2,
AGEDBAL2_FC, AGEDBAL3, AGEDBAL3_FC, BALANCE , BALANCE_FC, EXCHRATE_APPLIED, '-Balance Summary-',
alphacode, accgroup, accgroup2, accgroup_name, accgroup2_name
from FN_CR_AGEDBALANCES_BACKWARDS_SUMMARY(@AGE, DEFAULT)
where abs(Adjustment) > 0.01

INSERT INTO @TMP_AGEDBALANCES
(ACCNO, ACCOUNTNAME, CURRENCY, CURRENCYNO, CURRENCYNAME, transdate, ref1, ref2, ref3, invno, amount, exchrate,
Seqno, Period_seqno, EXCHRATE_ATENDOFPERIOD, AGEBAL_AGE,
alphacode, accgroup, accgroup2, accgroup_name, accgroup2_name)
select A.ACCNO, A.NAME, C.CURRCODE, A.CURRENCYNO, C.CURRNAME, T.transdate, T.ref1, T.ref2, T.ref3, T.invno,
isnull(T.AMOUNT, 0), T.EXCHRATE, isnull(T.SEQNO, 0), T.PERIOD_SEQNO,
ISNULL(CCR.CLOSING_BUYRATE, C.BUYRATE),
CASE
WHEN T.PERIOD_SEQNO = @period_seqno0 THEN 0
WHEN T.PERIOD_SEQNO = @period_seqno1 THEN 1
WHEN T.PERIOD_SEQNO = @period_seqno2 THEN 2
ELSE 3
END AGE,
A.alphacode, A.accgroup, A.accgroup2, AG.groupname, AG2.groupname
from CR_ACCS A
left join Cr_accgroups AG on AG.accgroup = A.accgroup
left join Cr_accgroup2s AG2 on AG2.accgroup = A.accgroup2
inner join CR_TRANS T on T.ACCNO = A.ACCNO
left join Currencies C on C.CURRENCYNO = T.CURRENCYNO
LEFT JOIN PERIOD_STATUS PS ON PS.SEQNO = T.PERIOD_SEQNO
LEFT JOIN CURRENCY_CLOSING_RATES CCR ON CCR.CURRENCYNO = T.CURRENCYNO
AND CCR.PERIOD_SEQNO = @GLPeriod_seqno
where T.PERIOD_SEQNO < = @period_seqno0
and A.head_accno = -1 -- exclude child/branch accounts
and T.accno not in (select accno from @TMP_AGEDBALANCES)
end
else
begin
--Retrieve all accounts with issues with balance issues. These will be all accounts where the balance based on
--individual transaction details does not match the balance calculated working backwards from the current balance.
--In such cases, we donot provide the ageing of individual transactions.
insert into @TMP_AGEDBALANCES(ACCNO, ACCOUNTNAME, CURRENCY, CURRENCYNO, CURRENCYNAME,
AGEDBAL0 , AGEDBAL0_FC, AGEDBAL1, AGEDBAL1_FC, AGEDBAL2,
AGEDBAL2_FC, AGEDBAL3, AGEDBAL3_FC, BALANCE , BALANCE_FC, EXCHRATE_ATENDOFPERIOD, ref1,
alphacode, accgroup, accgroup2, accgroup_name, accgroup2_name)
select ACCNO, ACCOUNTNAME, CURRENCY, CURRENCYNO, CURRENCYNAME,
AGEDBAL0 , AGEDBAL0_FC, AGEDBAL1, AGEDBAL1_FC, AGEDBAL2,
AGEDBAL2_FC, AGEDBAL3, AGEDBAL3_FC, BALANCE , BALANCE_FC, EXCHRATE_APPLIED, '-Balance Summary-',
alphacode, accgroup, accgroup2, accgroup_name, accgroup2_name
from FN_CR_AGEDBALANCES_BACKWARDS_SUMMARY(@AGE, DEFAULT)
where abs(Adjustment) > 0.01
and accno = @ACCNO


select @TmpCount = count(*) from @TMP_AGEDBALANCES

If @TmpCount = 0
begin
-- Retrieve all transaction lines
INSERT INTO @TMP_AGEDBALANCES
(ACCNO, ACCOUNTNAME, CURRENCY, CURRENCYNO, CURRENCYNAME, transdate, ref1, ref2, ref3, invno, amount, exchrate,
Seqno, Period_seqno, EXCHRATE_ATENDOFPERIOD, AGEBAL_AGE,
alphacode, accgroup, accgroup2, accgroup_name, accgroup2_name)
select A.ACCNO, A.NAME, C.CURRCODE, A.CURRENCYNO, C.CURRNAME, T.transdate, T.ref1, T.ref2, T.ref3, T.invno,
isnull(T.AMOUNT, 0), T.EXCHRATE, isnull(T.SEQNO, 0), T.PERIOD_SEQNO,
ISNULL(CCR.CLOSING_buyrate, C.buyrate),
CASE
WHEN T.PERIOD_SEQNO = @period_seqno0 THEN 0
WHEN T.PERIOD_SEQNO = @period_seqno1 THEN 1
WHEN T.PERIOD_SEQNO = @period_seqno2 THEN 2
ELSE 3
END AGE,
A.alphacode, A.accgroup, A.accgroup2, AG.groupname, AG2.groupname
from CR_ACCS A
left join Cr_accgroups AG on AG.accgroup = A.accgroup
left join Cr_accgroup2s AG2 on AG2.accgroup = A.accgroup2
inner join CR_TRANS T on A.ACCNO= T.ACCNO
left join Currencies C on C.currencyno = T.currencyno
LEFT JOIN PERIOD_STATUS PS ON PS.SEQNO = T.PERIOD_SEQNO
LEFT JOIN CURRENCY_CLOSING_RATES CCR ON CCR.CURRENCYNO = T.CURRENCYNO
AND CCR.PERIOD_SEQNO = @GLPeriod_seqno
where T.PERIOD_SEQNO < = @period_seqno0
and A.head_accno = -1 -- exclude child/branch accounts
and A.ACCNO = @ACCNO

end
end
-- Update aged balances
Update T set
AGEDBAL0_FC = case when T.Period_seqno = @period_seqno0 then (T.amount - (isnull(SUBQBAL_CURRENT.allocamount, 0)-isnull(SUBQBAL_DIFF.allocamount, 0))) else 0 end,
AGEDBAL1_FC = case when T.Period_seqno = @period_seqno1 then (T.amount - (isnull(SUBQBAL_CURRENT.allocamount, 0)-isnull(SUBQBAL_DIFF.allocamount, 0))) else 0 end,
AGEDBAL2_FC = case when T.Period_seqno = @period_seqno2 then (T.amount - (isnull(SUBQBAL_CURRENT.allocamount, 0)-isnull(SUBQBAL_DIFF.allocamount, 0))) else 0 end,
AGEDBAL3_FC = case when T.Period_seqno <= @period_seqno3 then (T.amount - (isnull(SUBQBAL_CURRENT.allocamount, 0)-isnull(SUBQBAL_DIFF.allocamount, 0))) else 0 end,
BALANCE_FC = (T.amount - (isnull(SUBQBAL_CURRENT.allocamount, 0)-isnull(SUBQBAL_DIFF.allocamount, 0))),
AGEDBAL0 = case when T.Period_seqno = @period_seqno0
then (T.amount - (isnull(SUBQBAL_CURRENT.allocamount, 0)-isnull(SUBQBAL_DIFF.allocamount, 0)))/T.EXCHRATE_ATENDOFPERIOD
else 0 end,
AGEDBAL1 = case when T.Period_seqno = @period_seqno1
then (T.amount - (isnull(SUBQBAL_CURRENT.allocamount, 0)-isnull(SUBQBAL_DIFF.allocamount, 0)))/T.EXCHRATE_ATENDOFPERIOD
else 0 end,
AGEDBAL2 = case when T.Period_seqno = @period_seqno2
then (T.amount - (isnull(SUBQBAL_CURRENT.allocamount, 0)-isnull(SUBQBAL_DIFF.allocamount, 0)))/T.EXCHRATE_ATENDOFPERIOD
else 0 end,
AGEDBAL3 = case when T.Period_seqno <= @period_seqno3
then (T.amount - (isnull(SUBQBAL_CURRENT.allocamount, 0)-isnull(SUBQBAL_DIFF.allocamount, 0)))/T.EXCHRATE_ATENDOFPERIOD
else 0 end,
BALANCE = (T.amount - (isnull(SUBQBAL_CURRENT.allocamount, 0)-isnull(SUBQBAL_DIFF.allocamount, 0)))/T.EXCHRATE_ATENDOFPERIOD
from @TMP_AGEDBALANCES T
LEFT JOIN -- allocations as at current period
(select trans_seqno, SUM(amount) as allocamount
from Cr_allocations
group by TRANS_SEQNO ) as SUBQBAL_CURRENT on T.SEQNO = SUBQBAL_CURRENT.TRANS_SEQNO
LEFT JOIN -- allocations between current period and the retrospective period
(select trans_seqno, SUM(amount) as allocamount
from Cr_allocations
where PERIOD_SEQNO > @period_seqno0
group by TRANS_SEQNO ) as SUBQBAL_DIFF on T.SEQNO = SUBQBAL_DIFF.TRANS_SEQNO
where T.seqno is not NULL

-- Any imbalances go in agedbal3
Update @TMP_AGEDBALANCES
set AGEDBAL3 = AGEDBAL3 + (BALANCE - (AGEDBAL0+AGEDBAL1+AGEDBAL2+AGEDBAL3)),
AGEDBAL3_FC = AGEDBAL3_FC + (BALANCE_FC - (AGEDBAL0_FC+AGEDBAL1_FC+AGEDBAL2_FC+AGEDBAL3_FC))

Update @TMP_AGEDBALANCES
Set AGEDBAL0 = ROUND(AGEDBAL0, 2),
AGEDBAL0_FC = ROUND(AGEDBAL0_FC, 2),
AGEDBAL1 = ROUND(AGEDBAL1, 2),
AGEDBAL1_FC = ROUND(AGEDBAL1_FC, 2),
AGEDBAL2 = ROUND(AGEDBAL2, 2),
AGEDBAL2_FC = ROUND(AGEDBAL2_FC, 2),
AGEDBAL3 = ROUND(AGEDBAL3, 2),
AGEDBAL3_FC = ROUND(AGEDBAL3_FC, 2),
BALANCE = ROUND(BALANCE, 2),
BALANCE_FC = ROUND(BALANCE_FC, 2)

  RETURN
END


Procedure: FN_CR_AGEDBALANCES_BACKWARDS_SUMMARY
NameFN_CR_AGEDBALANCES_BACKWARDS_SUMMARY
Note
Code-- =============================================
-- description: Calculates the aged balances of each account as at a specified age.
-- Child/branch accounts are excluded.
-- Balances are calculated working backwards from the current balance.
-- Indexes on CR_allocations period_seqno and trans_seqno are required for this query to run efficiently.
-- =============================================
CREATE FUNCTION [dbo].[FN_CR_AGEDBALANCES_BACKWARDS_SUMMARY]
(
@PERIOD INT = 0,
@PERIODPARAM_IS_AGE CHAR(1) = 'Y' -- If 'N', then it is assumed that the param passed is periodSeqno

)
RETURNS
  @TMP_AGEDBALANCES
  TABLE (
ACCOUNTNAME VARCHAR(100),
ACCNO INTEGER NOT NULL,
CURRENCY VARCHAR(3),
CURRENCYNO INTEGER,
CURRENCYNAME VARCHAR(30),
ALPHACODE VARCHAR(30),
ACCGROUP INTEGER,
ACCGROUP_NAME VARCHAR(50),
ACCGROUP2 INTEGER,
ACCGROUP2_NAME VARCHAR(50),
EXCHRATE_CURRENT DOUBLE PRECISION DEFAULT(0),
AGEDBAL0 DOUBLE PRECISION DEFAULT(0),
AGEDBAL0_FC DOUBLE PRECISION DEFAULT(0),
AGEDBAL1 DOUBLE PRECISION DEFAULT(0),
AGEDBAL1_FC DOUBLE PRECISION DEFAULT(0),
AGEDBAL2 DOUBLE PRECISION DEFAULT(0),
AGEDBAL2_FC DOUBLE PRECISION DEFAULT(0),
AGEDBAL3 DOUBLE PRECISION DEFAULT(0),
AGEDBAL3_FC DOUBLE PRECISION DEFAULT(0),
BALANCE DOUBLE PRECISION DEFAULT(0), -- working backwards(local currency)
BALANCE_FC DOUBLE PRECISION DEFAULT(0), -- working backwards(in currency of account)
ADJUSTMENT DOUBLE PRECISION DEFAULT(0),
ADJUSTMENT_FC DOUBLE PRECISION DEFAULT(0),
ROUNDING_ADJUSTMENT DOUBLE PRECISION DEFAULT(0),
ROUNDING_ADJUSTMENT_FC DOUBLE PRECISION DEFAULT(0),
EXCHRATE_APPLIED DOUBLE PRECISION DEFAULT(0) -- For current period this will be current exchrates;
-- For prior period it uses closing rates for the period
)
BEGIN
Declare @period_seqno0 integer,
@MinTranSeqno0 integer,
@AGE integer,
@period_seqno1 integer,
@period_seqno2 integer,
@period_seqno3 integer,
@period_seqno_Current integer,
@MinTranSeqnoCurrent integer,
@Ledger char(1),
@GLPeriod_seqno integer

-- If the period parameter being passed through is not age then use the period_seqno being passed through
-- to work out the age.
if @PERIODPARAM_IS_AGE = 'N'
select @AGE = age from period_status where seqno = @period
else
select @AGE = @PERIOD

Set @Ledger = 'C'

--retrieve GL periodseqno that gets used to derive the closing rate for the period
select @GLPeriod_seqno = seqno from period_status
where ledger = 'G' and age = @AGE


-- Retrieve period_seqnos for ages.
select @period_seqno_Current = seqno, @MinTranSeqnoCurrent = MinTranSeqno from PERIOD_STATUS
where AGE = 0 and LEDGER = @Ledger
If @AGE = 0
set @MinTranSeqno0 = @MinTranSeqnoCurrent
else
select @MinTranSeqno0 = MinTranSeqno from PERIOD_STATUS
where AGE = (@AGE-1) and LEDGER = @Ledger
select @period_seqno0 =seqno from PERIOD_STATUS
where AGE = @AGE and LEDGER = @Ledger
select @period_seqno1 =seqno from PERIOD_STATUS
where AGE = (@AGE + 1) and LEDGER = @Ledger
select @period_seqno2 = seqno from PERIOD_STATUS
where AGE = (@AGE + 2) and LEDGER = @Ledger
select @period_seqno3 = seqno from PERIOD_STATUS
where AGE = (@AGE + 3) and LEDGER = @Ledger

insert into @TMP_AGEDBALANCES
(accno, accountname, currencyno, currency, CURRENCYNAME, agedbal0_fc, agedbal1_fc, agedbal2_fc, agedbal3_fc, balance_fc,
agedbal0, agedbal1, agedbal2, agedbal3, balance, EXCHRATE_CURRENT, EXCHRATE_APPLIED,
alphacode, accgroup, accgroup2, accgroup_name, accgroup2_name)
select D.accno, D.name, D.currencyno, C.currcode, C.CURRNAME,
AGEDBAL0_FC = ISNULL(AGE0.SUMAGEBAL_FC, 0),
AGEDBAL1_FC = ISNULL(AGE1.SUMAGEBAL_FC, 0),
AGEDBAL2_FC = ISNULL(AGE2.SUMAGEBAL_FC, 0),
AGEDBAL3_FC = ISNULL(AGE3.SUMAGEBAL_FC, 0),
BALANCE_FC = ISNULL(BALANCE.SUMAGEBAL_FC, 0),
AGEDBAL0 = ISNULL(AGE0.SUMAGEBAL_FC, 0)/isnull(CCR1.Closing_buyrate, C.buyrate),
AGEDBAL1 = ISNULL(AGE1.SUMAGEBAL_FC, 0)/isnull(CCR1.Closing_buyrate, C.buyrate),
AGEDBAL2 = ISNULL(AGE2.SUMAGEBAL_FC, 0)/isnull(CCR1.Closing_buyrate, C.buyrate),
AGEDBAL3 = ISNULL(AGE3.SUMAGEBAL_FC, 0)/isnull(CCR1.Closing_buyrate, C.buyrate),
BALANCE = ISNULL(BALANCE.SUMAGEBAL_FC, 0)/isnull(CCR1.Closing_buyrate, C.buyrate),
C.buyrate, isnull(CCR1.Closing_buyrate, C.buyrate),
D.alphacode, D.accgroup, D.accgroup2, AG.groupname, AG2.groupname
FROM CR_ACCS D
left join cr_accgroups AG on AG.accgroup = D.accgroup
left join cr_accgroup2s AG2 on AG2.accgroup = D.accgroup2
left join currencies C on C.currencyno = D.currencyno
left join currency_closing_rates CCR1 on CCR1.Currencyno = D.currencyno and CCR1.period_seqno = @GLPeriod_seqno
LEFT JOIN (
SELECT A.ACCNO, SUM(T.AMOUNT - (isnull(SUBQ_CURRENT.allocamount, 0)- isnull(SUBQ_DIFF.allocamount, 0))) SUMAGEBAL_FC
FROM CR_ACCS A
LEFT JOIN CR_TRANS T ON A.ACCNO = T.ACCNO
left join
(select trans_SEQNO, ISNULL(SUM(amount), 0) as allocamount
from Cr_allocations
group by trans_seqno) as SUBQ_CURRENT ON SUBQ_CURRENT.TRANS_SEQNO = T.SEQNO
left join
(select trans_SEQNO, ISNULL(SUM(amount), 0) as allocamount
from Cr_allocations
where PERIOD_SEQNO > @period_seqno0
group by trans_seqno) as SUBQ_DIFF ON SUBQ_DIFF.TRANS_SEQNO = T.SEQNO
LEFT JOIN PERIOD_STATUS PS ON T.PERIOD_SEQNO=PS.SEQNO
WHERE PS.AGE = @AGE
GROUP BY A.ACCNO, PS.AGE
) AGE0 ON D.ACCNO = AGE0.ACCNO
LEFT JOIN (
SELECT A.ACCNO, SUM(T.AMOUNT - (isnull(SUBQ_CURRENT.allocamount, 0)- isnull(SUBQ_DIFF.allocamount, 0))) SUMAGEBAL_FC
FROM CR_ACCS A
LEFT JOIN CR_TRANS T ON A.ACCNO = T.ACCNO
LEFT JOIN CURRENCIES C ON C.CURRENCYNO = T.CURRENCYNO
left join
(select trans_SEQNO, ISNULL(SUM(amount), 0) as allocamount
from CR_allocations
group by trans_seqno) as SUBQ_CURRENT ON SUBQ_CURRENT.TRANS_SEQNO = T.SEQNO
left join
(select trans_SEQNO, ISNULL(SUM(amount), 0) as allocamount
from Cr_allocations
where PERIOD_SEQNO > @period_seqno0
group by trans_seqno) as SUBQ_DIFF ON SUBQ_DIFF.TRANS_SEQNO = T.SEQNO
LEFT JOIN PERIOD_STATUS PS ON T.PERIOD_SEQNO=PS.SEQNO
WHERE PS.AGE = @AGE + 1
GROUP BY A.ACCNO, PS.AGE
) AGE1 ON D.ACCNO = AGE1.ACCNO
LEFT JOIN (
SELECT A.ACCNO, SUM(T.AMOUNT - (isnull(SUBQ_CURRENT.allocamount, 0)- isnull(SUBQ_DIFF.allocamount, 0))) SUMAGEBAL_FC
FROM CR_ACCS A
LEFT JOIN CR_TRANS T ON A.ACCNO = T.ACCNO
LEFT JOIN CURRENCIES C ON C.CURRENCYNO = T.CURRENCYNO
left join
(select trans_SEQNO, ISNULL(SUM(amount), 0) as allocamount
from CR_allocations
group by trans_seqno) as SUBQ_CURRENT ON SUBQ_CURRENT.TRANS_SEQNO = T.SEQNO
left join
(select trans_SEQNO, ISNULL(SUM(amount), 0) as allocamount
from Cr_allocations
where PERIOD_SEQNO > @period_seqno0
group by trans_seqno) as SUBQ_DIFF ON SUBQ_DIFF.TRANS_SEQNO = T.SEQNO
LEFT JOIN PERIOD_STATUS PS ON T.PERIOD_SEQNO=PS.SEQNO
WHERE PS.AGE = @AGE + 2
GROUP BY A.ACCNO, PS.AGE
) AGE2 ON D.ACCNO = AGE2.ACCNO
LEFT JOIN (
SELECT A.ACCNO, SUM(T.AMOUNT - (isnull(SUBQ_CURRENT.allocamount, 0)- isnull(SUBQ_DIFF.allocamount, 0))) SUMAGEBAL_FC
FROM CR_ACCS A
LEFT JOIN CR_TRANS T ON A.ACCNO = T.ACCNO
LEFT JOIN CURRENCIES C ON C.CURRENCYNO = T.CURRENCYNO
left join
(select trans_SEQNO, ISNULL(SUM(amount), 0) as allocamount
from CR_allocations
group by trans_seqno) as SUBQ_CURRENT ON SUBQ_CURRENT.TRANS_SEQNO = T.SEQNO
left join
(select trans_SEQNO, ISNULL(SUM(amount), 0) as allocamount
from Cr_allocations
where PERIOD_SEQNO > @period_seqno0
group by trans_seqno) as SUBQ_DIFF ON SUBQ_DIFF.TRANS_SEQNO = T.SEQNO
LEFT JOIN PERIOD_STATUS PS ON T.PERIOD_SEQNO=PS.SEQNO
WHERE PS.AGE >= @AGE + 3
GROUP BY A.ACCNO
) AGE3 ON D.ACCNO = AGE3.ACCNO
  LEFT JOIN (
select A.accno, (ISNULL(T1.amount, 0) - ISNULL(T2.amount, 0)) as SUMAGEBAL_FC
from Cr_accs A
left join
(select accno, sum(amount) as amount from Cr_trans group by accno) as T1 on T1.accno = A.accno
left join
(select accno, sum(amount) as amount from Cr_trans where period_seqno > @period_seqno0 and seqno >= @MinTranSeqno0 group by accno ) as T2 on T2.accno = A.accno

) BALANCE ON D.ACCNO = BALANCE.ACCNO
where D.head_accno = -1 -- exclude child/branch accounts

Update @TMP_AGEDBALANCES
set
ADJUSTMENT = (BALANCE - (AGEDBAL0+AGEDBAL1+AGEDBAL2+AGEDBAL3)),
ADJUSTMENT_FC = (BALANCE_FC - (AGEDBAL0_FC+AGEDBAL1_FC+AGEDBAL2_FC+AGEDBAL3_FC))

-- Any imbalances go in agedbal3
Update @TMP_AGEDBALANCES
set AGEDBAL3 = AGEDBAL3 + (BALANCE - (AGEDBAL0+AGEDBAL1+AGEDBAL2+AGEDBAL3)),
AGEDBAL3_FC = AGEDBAL3_FC + (BALANCE_FC - (AGEDBAL0_FC+AGEDBAL1_FC+AGEDBAL2_FC+AGEDBAL3_FC))

-- Round to 2dp
Update @TMP_AGEDBALANCES
Set AGEDBAL0 = ROUND(AGEDBAL0, 2),
AGEDBAL0_FC = ROUND(AGEDBAL0_FC, 2),
AGEDBAL1 = ROUND(AGEDBAL1, 2),
AGEDBAL1_FC = ROUND(AGEDBAL1_FC, 2),
AGEDBAL2 = ROUND(AGEDBAL2, 2),
AGEDBAL2_FC = ROUND(AGEDBAL2_FC, 2),
AGEDBAL3 = ROUND(AGEDBAL3, 2),
AGEDBAL3_FC = ROUND(AGEDBAL3_FC, 2),
BALANCE = ROUND(BALANCE, 2),
BALANCE_FC = ROUND(BALANCE_FC, 2)

-- Check for rounding adjustments
Update @TMP_AGEDBALANCES
set ROUNDING_ADJUSTMENT = round(BALANCE - (AGEDBAL0 + AGEDBAL1 + AGEDBAL2 + AGEDBAL3), 2),
ROUNDING_ADJUSTMENT_FC = round(BALANCE_FC - (AGEDBAL0_FC + AGEDBAL1_FC + AGEDBAL2_FC + AGEDBAL3_FC), 2)

  RETURN
END


Procedure: FN_CR_UNREALISED_FOREX_VARIANCES
NameFN_CR_UNREALISED_FOREX_VARIANCES
Note
Code-- =============================================
-- description: Calculates the unrealised forex gains/losses as at any period.
-- Takes in age/period_seqno as a parameter.
-- Child/branch accounts are excluded.
-- Balances are calculated working backwards from the current balance.
-- Indexes on Cr_allocations period_seqno and trans_seqno are required for this query to run efficiently.
-- =============================================
CREATE FUNCTION [dbo].[FN_CR_UNREALISED_FOREX_VARIANCES]
(
@PERIOD INT = 0,
@PERIODPARAM_IS_AGE CHAR(1) = 'Y' -- If 'N', then it is assumed that the param passed is periodSeqno
)
RETURNS
  @TMP_AGEDBALANCES
  TABLE (
ACCOUNTNAME VARCHAR(100),
ACCNO INTEGER NOT NULL,
CURRNAME VARCHAR(30),
CURRENCY VARCHAR(3),
CURRENCYNO INTEGER,
BRANCHNO INTEGER,
TRANSDATE DATETIME,
REF1 VARCHAR(100),
REF2 VARCHAR(100),
REF3 VARCHAR(100),
INVNO VARCHAR(100),
SEQNO INTEGER,
PERIOD_SEQNO INTEGER,
AGE INTEGER,
AMOUNT DOUBLE PRECISION NOT NULL DEFAULT(0),
EXCHRATE DOUBLE PRECISION NOT NULL DEFAULT(0),
EXCHRATE_ATENDOFPERIOD DOUBLE PRECISION DEFAULT(0),
UNALLOCATED_BAL DOUBLE PRECISION DEFAULT(0), -- WORKING BACKWARDS
VARIANCE DOUBLE PRECISION DEFAULT(0)
)
BEGIN
Declare @GLPeriod_seqno0 integer,
@period_seqno0 integer,
@MinTranSeqno0 integer,
@AGE integer,
@period_seqno1 integer,
@period_seqno2 integer,
@period_seqno3 integer,
@period_seqno_Current integer,
@MinTranSeqnoCurrent integer,
@Ledger char(1)

-- If the period parameter being passed through is not age then use the period_seqno being passed through
-- to work out the age.
if @PERIODPARAM_IS_AGE = 'N'
select @AGE = age from period_status where seqno = @period
else
select @AGE = @PERIOD

Set @Ledger = 'C'

-- Retrieve period_seqnos for ages.
SELECT @PERIOD_SEQNO_CURRENT = SEQNO, @MINTRANSEQNOCURRENT = MINTRANSEQNO
FROM PERIOD_STATUS
WHERE AGE = 0 AND LEDGER = @Ledger

SELECT @PERIOD_SEQNO0 =SEQNO, @MINTRANSEQNO0 = MINTRANSEQNO
FROM PERIOD_STATUS
WHERE AGE = @AGE AND LEDGER = @Ledger

SELECT @PERIOD_SEQNO1 =SEQNO
FROM PERIOD_STATUS
WHERE AGE = (@AGE + 1) AND LEDGER = @Ledger

SELECT @PERIOD_SEQNO2 = SEQNO
FROM PERIOD_STATUS
WHERE AGE = (@AGE + 2) AND LEDGER = @Ledger

SELECT @PERIOD_SEQNO3 = SEQNO
FROM PERIOD_STATUS
WHERE AGE = (@AGE + 3) AND LEDGER = @Ledger

SELECT @GLPeriod_seqno0 = SEQNO
FROM PERIOD_STATUS
WHERE AGE = @AGE AND LEDGER = 'G'

INSERT INTO @TMP_AGEDBALANCES (ACCNO, ACCOUNTNAME, CURRNAME, CURRENCY, CURRENCYNO, TRANSDATE,
REF1, REF2, REF3, INVNO, AMOUNT, EXCHRATE, SEQNO, PERIOD_SEQNO, AGE,
BRANCHNO, EXCHRATE_ATENDOFPERIOD, UNALLOCATED_BAL)
SELECT A.ACCNO, A.NAME, C.CURRNAME, C.CURRCODE, A.CURRENCYNO, T.TRANSDATE, T.REF1,
T.REF2, T.REF3, T.INVNO, ISNULL(T.AMOUNT, 0), T.EXCHRATE, ISNULL(T.SEQNO, 0),
T.PERIOD_SEQNO, PS.AGE, T.BRANCHNO, ISNULL(CCR.CLOSING_BUYRATE, C.BUYRATE),
ISNULL(ROUND((T.AMOUNT - (ISNULL(SUBQBAL_CURRENT.ALLOCAMOUNT, 0)-ISNULL(SUBQBAL_DIFF.ALLOCAMOUNT, 0))), 2), 0) -- UNALLOCATED AMOUNT
FROM CR_ACCS A
LEFT JOIN CR_TRANS T ON A.ACCNO= T.ACCNO
LEFT JOIN CURRENCY_CLOSING_RATES CCR ON CCR.CURRENCYNO = T.CURRENCYNO AND CCR.PERIOD_SEQNO = @GLPeriod_seqno0
LEFT JOIN CURRENCIES C ON C.CURRENCYNO = T.CURRENCYNO
LEFT JOIN -- ALLOCATIONS AS AT CURRENT PERIOD
(SELECT TRANS_SEQNO, SUM(AMOUNT) AS ALLOCAMOUNT
FROM CR_ALLOCATIONS
WHERE PERIOD_SEQNO <= @PERIOD_SEQNO_CURRENT
GROUP BY TRANS_SEQNO ) AS SUBQBAL_CURRENT ON T.SEQNO = SUBQBAL_CURRENT.TRANS_SEQNO
LEFT JOIN -- ALLOCATIONS BETWEEN CURRENT PERIOD AND THE RETROSPECTIVE PERIOD
(SELECT TRANS_SEQNO, SUM(AMOUNT) AS ALLOCAMOUNT
FROM CR_ALLOCATIONS
WHERE PERIOD_SEQNO <= @PERIOD_SEQNO_CURRENT AND PERIOD_SEQNO >@PERIOD_SEQNO0 AND TRANS_SEQNO >= @MINTRANSEQNO0
GROUP BY TRANS_SEQNO ) AS SUBQBAL_DIFF ON T.SEQNO = SUBQBAL_DIFF.TRANS_SEQNO
LEFT JOIN PERIOD_STATUS PS ON T.PERIOD_SEQNO = PS.SEQNO
WHERE T.PERIOD_SEQNO < = @PERIOD_SEQNO0
AND A.CURRENCYNO > 0 -- ONLY FOREIGN CURRENCY ACCOUNTS
AND A.HEAD_ACCNO = -1 -- EXCLUDE CHILD/BRANCH ACCOUNTS

-- CALCULATE THE FOREX VARIANCE BASED ON UNALLOCATED AMOUNT TAKING INTO CONSIDERATION THE EXCHRATE ON
-- THE TRANSACTION AND THE NEAR TERM EXCHRATE FOR THAT PERIOD.
UPDATE @TMP_AGEDBALANCES
SET VARIANCE = (UNALLOCATED_BAL * (EXCHRATE_ATENDOFPERIOD-EXCHRATE))/(EXCHRATE_ATENDOFPERIOD*EXCHRATE)

Delete from @TMP_AGEDBALANCES where UNALLOCATED_BAL = 0

  RETURN
END


Procedure: FN_CSVtoTable
NameFN_CSVtoTable
Note
CodeCREATE FUNCTION [dbo].[FN_CSVtoTable](
    @sInputList VARCHAR(8000) -- List of delimited items
  , @sDelimiter VARCHAR(8000) = ', ' -- delimiter that separates items
) RETURNS @List TABLE (item VARCHAR(8000))

BEGIN
       DECLARE @sItem VARCHAR(8000)
       WHILE CHARINDEX(@sDelimiter, @sInputList, 0) <> 0
       BEGIN
              SELECT
                     @sItem=RTRIM(LTRIM(SUBSTRING(@sInputList, 1, CHARINDEX(@sDelimiter, @sInputList, 0)-1))),
                     @sInputList=RTRIM(LTRIM(SUBSTRING(@sInputList, CHARINDEX(@sDelimiter, @sInputList, 0)+LEN(@sDelimiter), LEN(@sInputList))))

              IF LEN(@sItem) > 0
                     INSERT INTO @List SELECT @sItem
       END

       IF LEN(@sInputList) > 0
              INSERT INTO @List SELECT @sInputList -- Put the last item in
       RETURN
END


Procedure: FN_DR_AGEDBALANCES_BACKWARDS
NameFN_DR_AGEDBALANCES_BACKWARDS
Note
Code-- =============================================
-- description: Calculates the aged balances of each transaction line as at a specified age.
-- Child/branch accounts are excluded.
-- Balances are calculated working backwards from the current balance.
-- Indexes on Dr_allocations period_seqno and trans_seqno are required for this query to run efficiently.
-- =============================================
CREATE FUNCTION [dbo].[FN_DR_AGEDBALANCES_BACKWARDS]
(
@PERIOD INT = 0,
@ACCNO INT = -1,
@PERIODPARAM_IS_AGE CHAR(1) = 'Y' -- If 'N', then it is assumed that the param passed is periodSeqno
)
RETURNS
  @TMP_AGEDBALANCES
  TABLE (
ACCOUNTNAME VARCHAR(100),
ACCNO INTEGER NOT NULL,
CURRENCY VARCHAR(3),
CURRENCYNO INTEGER,
CURRENCYNAME VARCHAR(30),
ALPHACODE VARCHAR(30),
ACCGROUP INTEGER,
ACCGROUP_NAME VARCHAR(50),
ACCGROUP2 INTEGER,
ACCGROUP2_NAME VARCHAR(50),
TRANSDATE DATETIME,
REF1 VARCHAR(100),
REF2 VARCHAR(100),
REF3 VARCHAR(100),
INVNO VARCHAR(100),
SEQNO INTEGER,
PERIOD_SEQNO INTEGER,
AGEBAL_AGE INTEGER,
AMOUNT DOUBLE PRECISION NOT NULL DEFAULT(0),
EXCHRATE DOUBLE PRECISION NOT NULL DEFAULT(0),
EXCHRATE_ATENDOFPERIOD DOUBLE PRECISION DEFAULT(0),
AGEDBAL0 DOUBLE PRECISION NOT NULL DEFAULT(0),
AGEDBAL0_FC DOUBLE PRECISION NOT NULL DEFAULT(0),
AGEDBAL1 DOUBLE PRECISION NOT NULL DEFAULT(0),
AGEDBAL1_FC DOUBLE PRECISION NOT NULL DEFAULT(0),
AGEDBAL2 DOUBLE PRECISION NOT NULL DEFAULT(0),
AGEDBAL2_FC DOUBLE PRECISION NOT NULL DEFAULT(0),
AGEDBAL3 DOUBLE PRECISION NOT NULL DEFAULT(0),
AGEDBAL3_FC DOUBLE PRECISION NOT NULL DEFAULT(0),
BALANCE DOUBLE PRECISION NOT NULL DEFAULT(0), -- working backwards(local currency)
BALANCE_FC DOUBLE PRECISION NOT NULL DEFAULT(0) -- working backwards(in currency of account)
)
BEGIN
Declare @period_seqno0 integer,
@MinTranSeqno0 integer,
@AGE integer,
@period_seqno1 integer,
@period_seqno2 integer,
@period_seqno3 integer,
@period_seqno_Current integer,
@MinTranSeqnoCurrent integer,
@Ledger char(1),
@GLPeriod_seqno integer,
@TmpCount integer


-- If the period parameter being passed through is not age then use the period_seqno being passed through
-- to work out the age.
if @PERIODPARAM_IS_AGE = 'N'
select @AGE = age from period_status where seqno = @period
else
select @AGE = @PERIOD

Set @Ledger = 'D'

--retrieve GL periodseqno that gets used to derive the closing rate for the period
select @GLPeriod_seqno = seqno from period_status
where ledger = 'G' and age = @AGE

-- Retrieve period_seqnos for ages.
select @period_seqno_Current = seqno, @MinTranSeqnoCurrent = MinTranSeqno from PERIOD_STATUS
where AGE = 0 and LEDGER = @Ledger
if @AGE = 0
set @MinTranSeqno0 = @MinTranSeqnoCurrent
else
select @MinTranSeqno0 = MinTranSeqno from PERIOD_STATUS
where AGE = (@AGE - 1) and LEDGER = @Ledger
select @period_seqno0 =seqno from PERIOD_STATUS
where AGE = @AGE and LEDGER = @Ledger
select @period_seqno1 =seqno from PERIOD_STATUS
where AGE = (@AGE + 1) and LEDGER = @Ledger
select @period_seqno2 = seqno from PERIOD_STATUS
where AGE = (@AGE + 2) and LEDGER = @Ledger
select @period_seqno3 = seqno from PERIOD_STATUS
where AGE = (@AGE + 3) and LEDGER = @Ledger


If @ACCNO = -1
begin
--Retrieve all accounts with issues with balance issues. These will be all accounts where the balance based on
--individual transaction details does not match the balance calculated working backwards from the current balance.
--In such cases, we donot provide the ageing of individual transactions.
insert into @TMP_AGEDBALANCES(ACCNO, ACCOUNTNAME, CURRENCY, CURRENCYNO, CURRENCYNAME,
AGEDBAL0 , AGEDBAL0_FC, AGEDBAL1, AGEDBAL1_FC, AGEDBAL2,
AGEDBAL2_FC, AGEDBAL3, AGEDBAL3_FC, BALANCE , BALANCE_FC, EXCHRATE_ATENDOFPERIOD, ref1,
alphacode, accgroup, accgroup2, accgroup_name, accgroup2_name)
select ACCNO, ACCOUNTNAME, CURRENCY, CURRENCYNO, CURRENCYNAME,
AGEDBAL0 , AGEDBAL0_FC, AGEDBAL1, AGEDBAL1_FC, AGEDBAL2,
AGEDBAL2_FC, AGEDBAL3, AGEDBAL3_FC, BALANCE , BALANCE_FC, EXCHRATE_APPLIED, '-Balance Summary-',
alphacode, accgroup, accgroup2, accgroup_name, accgroup2_name
from FN_DR_AGEDBALANCES_BACKWARDS_SUMMARY(@AGE, DEFAULT)
where abs(Adjustment) > 0.01

INSERT INTO @TMP_AGEDBALANCES
(ACCNO, ACCOUNTNAME, CURRENCY, CURRENCYNO, CURRENCYNAME, transdate, ref1, ref2, ref3, invno, amount, exchrate,
Seqno, Period_seqno, EXCHRATE_ATENDOFPERIOD, AGEBAL_AGE,
alphacode, accgroup, accgroup2, accgroup_name, accgroup2_name)
select A.ACCNO, A.NAME, C.CURRCODE, A.CURRENCYNO, C.CURRNAME, T.transdate, T.ref1, T.ref2, T.ref3, T.invno,
isnull(T.AMOUNT, 0), T.EXCHRATE, isnull(T.SEQNO, 0), T.PERIOD_SEQNO,
ISNULL(CCR.CLOSING_SELLRATE, C.SELLRATE),
CASE
WHEN T.PERIOD_SEQNO = @period_seqno0 THEN 0
WHEN T.PERIOD_SEQNO = @period_seqno1 THEN 1
WHEN T.PERIOD_SEQNO = @period_seqno2 THEN 2
ELSE 3
END AGE,
A.alphacode, A.accgroup, A.accgroup2, AG.groupname, AG2.groupname
from DR_ACCS A
left join dr_accgroups AG on AG.accgroup = A.accgroup
left join dr_accgroup2s AG2 on AG2.accgroup = A.accgroup2
inner join DR_TRANS T on T.ACCNO = A.ACCNO
left join Currencies C on C.CURRENCYNO = T.CURRENCYNO
LEFT JOIN PERIOD_STATUS PS ON PS.SEQNO = T.PERIOD_SEQNO
LEFT JOIN CURRENCY_CLOSING_RATES CCR ON CCR.CURRENCYNO = T.CURRENCYNO
AND CCR.PERIOD_SEQNO = @GLPeriod_seqno
where T.PERIOD_SEQNO < = @period_seqno0
and A.head_accno = -1 -- exclude child/branch accounts
and T.accno not in (select accno from @TMP_AGEDBALANCES)
end
else
begin
--Retrieve all accounts with issues with balance issues. These will be all accounts where the balance based on
--individual transaction details does not match the balance calculated working backwards from the current balance.
--In such cases, we donot provide the ageing of individual transactions.
insert into @TMP_AGEDBALANCES(ACCNO, ACCOUNTNAME, CURRENCY, CURRENCYNO, CURRENCYNAME,
AGEDBAL0 , AGEDBAL0_FC, AGEDBAL1, AGEDBAL1_FC, AGEDBAL2,
AGEDBAL2_FC, AGEDBAL3, AGEDBAL3_FC, BALANCE , BALANCE_FC, EXCHRATE_ATENDOFPERIOD, ref1,
alphacode, accgroup, accgroup2, accgroup_name, accgroup2_name)
select ACCNO, ACCOUNTNAME, CURRENCY, CURRENCYNO, CURRENCYNAME,
AGEDBAL0 , AGEDBAL0_FC, AGEDBAL1, AGEDBAL1_FC, AGEDBAL2,
AGEDBAL2_FC, AGEDBAL3, AGEDBAL3_FC, BALANCE , BALANCE_FC, EXCHRATE_APPLIED, '-Balance Summary-',
alphacode, accgroup, accgroup2, accgroup_name, accgroup2_name
from FN_DR_AGEDBALANCES_BACKWARDS_SUMMARY(@AGE, DEFAULT)
where abs(Adjustment) > 0.01
and accno = @ACCNO

select @TmpCount = count(*) from @TMP_AGEDBALANCES

If @TmpCount = 0
begin
-- Retrieve all transaction lines
INSERT INTO @TMP_AGEDBALANCES
(ACCNO, ACCOUNTNAME, CURRENCY, CURRENCYNO, CURRENCYNAME, transdate, ref1, ref2, ref3, invno, amount, exchrate,
Seqno, Period_seqno, EXCHRATE_ATENDOFPERIOD, AGEBAL_AGE,
alphacode, accgroup, accgroup2, accgroup_name, accgroup2_name)
select A.ACCNO, A.NAME, C.CURRCODE, A.CURRENCYNO, C.CURRNAME, T.transdate, T.ref1, T.ref2, T.ref3, T.invno,
isnull(T.AMOUNT, 0), T.EXCHRATE, isnull(T.SEQNO, 0), T.PERIOD_SEQNO,
ISNULL(CCR.CLOSING_SELLRATE, C.SELLRATE),
CASE
WHEN T.PERIOD_SEQNO = @period_seqno0 THEN 0
WHEN T.PERIOD_SEQNO = @period_seqno1 THEN 1
WHEN T.PERIOD_SEQNO = @period_seqno2 THEN 2
ELSE 3
END AGE,
A.alphacode, A.accgroup, A.accgroup2, AG.groupname, AG2.groupname
from DR_ACCS A
left join dr_accgroups AG on AG.accgroup = A.accgroup
left join dr_accgroup2s AG2 on AG2.accgroup = A.accgroup2
inner join DR_TRANS T on A.ACCNO= T.ACCNO
left join Currencies C on C.currencyno = T.currencyno
LEFT JOIN PERIOD_STATUS PS ON PS.SEQNO = T.PERIOD_SEQNO
LEFT JOIN CURRENCY_CLOSING_RATES CCR ON CCR.CURRENCYNO = T.CURRENCYNO
AND CCR.PERIOD_SEQNO = @GLPeriod_seqno
where T.PERIOD_SEQNO < = @period_seqno0
and A.head_accno = -1 -- exclude child/branch accounts
and A.ACCNO = @ACCNO

end
end
-- Update aged balances
Update T set
AGEDBAL0_FC = case when T.Period_seqno = @period_seqno0 then (T.amount - (isnull(SUBQBAL_CURRENT.allocamount, 0)-isnull(SUBQBAL_DIFF.allocamount, 0))) else 0 end,
AGEDBAL1_FC = case when T.Period_seqno = @period_seqno1 then (T.amount - (isnull(SUBQBAL_CURRENT.allocamount, 0)-isnull(SUBQBAL_DIFF.allocamount, 0))) else 0 end,
AGEDBAL2_FC = case when T.Period_seqno = @period_seqno2 then (T.amount - (isnull(SUBQBAL_CURRENT.allocamount, 0)-isnull(SUBQBAL_DIFF.allocamount, 0))) else 0 end,
AGEDBAL3_FC = case when T.Period_seqno <= @period_seqno3 then (T.amount - (isnull(SUBQBAL_CURRENT.allocamount, 0)-isnull(SUBQBAL_DIFF.allocamount, 0))) else 0 end,
BALANCE_FC = (T.amount - (isnull(SUBQBAL_CURRENT.allocamount, 0)-isnull(SUBQBAL_DIFF.allocamount, 0))),
AGEDBAL0 = case when T.Period_seqno = @period_seqno0
then (T.amount - (isnull(SUBQBAL_CURRENT.allocamount, 0)-isnull(SUBQBAL_DIFF.allocamount, 0)))/T.EXCHRATE_ATENDOFPERIOD
else 0 end,
AGEDBAL1 = case when T.Period_seqno = @period_seqno1
then (T.amount - (isnull(SUBQBAL_CURRENT.allocamount, 0)-isnull(SUBQBAL_DIFF.allocamount, 0)))/T.EXCHRATE_ATENDOFPERIOD
else 0 end,
AGEDBAL2 = case when T.Period_seqno = @period_seqno2
then (T.amount - (isnull(SUBQBAL_CURRENT.allocamount, 0)-isnull(SUBQBAL_DIFF.allocamount, 0)))/T.EXCHRATE_ATENDOFPERIOD
else 0 end,
AGEDBAL3 = case when T.Period_seqno <= @period_seqno3
then (T.amount - (isnull(SUBQBAL_CURRENT.allocamount, 0)-isnull(SUBQBAL_DIFF.allocamount, 0)))/T.EXCHRATE_ATENDOFPERIOD
else 0 end,
BALANCE = (T.amount - (isnull(SUBQBAL_CURRENT.allocamount, 0)-isnull(SUBQBAL_DIFF.allocamount, 0)))/T.EXCHRATE_ATENDOFPERIOD
from @TMP_AGEDBALANCES T
LEFT JOIN -- allocations as at current period
(select trans_seqno, SUM(amount) as allocamount
from dr_allocations
group by TRANS_SEQNO ) as SUBQBAL_CURRENT on T.SEQNO = SUBQBAL_CURRENT.TRANS_SEQNO
LEFT JOIN -- allocations between current period and the retrospective period
(select trans_seqno, SUM(amount) as allocamount
from dr_allocations
where PERIOD_SEQNO > @period_seqno0
group by TRANS_SEQNO ) as SUBQBAL_DIFF on T.SEQNO = SUBQBAL_DIFF.TRANS_SEQNO
where T.seqno is not NULL

-- Any imbalances go in agedbal3
Update @TMP_AGEDBALANCES
set AGEDBAL3 = AGEDBAL3 + (BALANCE - (AGEDBAL0+AGEDBAL1+AGEDBAL2+AGEDBAL3)),
AGEDBAL3_FC = AGEDBAL3_FC + (BALANCE_FC - (AGEDBAL0_FC+AGEDBAL1_FC+AGEDBAL2_FC+AGEDBAL3_FC))

Update @TMP_AGEDBALANCES
Set AGEDBAL0 = ROUND(AGEDBAL0, 2),
AGEDBAL0_FC = ROUND(AGEDBAL0_FC, 2),
AGEDBAL1 = ROUND(AGEDBAL1, 2),
AGEDBAL1_FC = ROUND(AGEDBAL1_FC, 2),
AGEDBAL2 = ROUND(AGEDBAL2, 2),
AGEDBAL2_FC = ROUND(AGEDBAL2_FC, 2),
AGEDBAL3 = ROUND(AGEDBAL3, 2),
AGEDBAL3_FC = ROUND(AGEDBAL3_FC, 2),
BALANCE = ROUND(BALANCE, 2),
BALANCE_FC = ROUND(BALANCE_FC, 2)

  RETURN
END


Procedure: FN_DR_AGEDBALANCES_BACKWARDS_SUMMARY
NameFN_DR_AGEDBALANCES_BACKWARDS_SUMMARY
Note
Code-- =============================================
-- description: Calculates the aged balances of each account as at a specified age.
-- Child/branch accounts are excluded.
-- Balances are calculated working backwards from the current balance.
-- Indexes on Dr_allocations period_seqno and trans_seqno are required for this query to run efficiently.
-- =============================================
CREATE FUNCTION [dbo].[FN_DR_AGEDBALANCES_BACKWARDS_SUMMARY]
(
@PERIOD INT = 0,
@PERIODPARAM_IS_AGE CHAR(1) = 'Y' -- If 'N', then it is assumed that the param passed is periodSeqno

)
RETURNS
  @TMP_AGEDBALANCES
  TABLE (
ACCOUNTNAME VARCHAR(100),
ACCNO INTEGER NOT NULL,
CURRENCY VARCHAR(3),
CURRENCYNO INTEGER,
CURRENCYNAME VARCHAR(30),
ALPHACODE VARCHAR(30),
ACCGROUP INTEGER,
ACCGROUP_NAME VARCHAR(50),
ACCGROUP2 INTEGER,
ACCGROUP2_NAME VARCHAR(50),
EXCHRATE_CURRENT DOUBLE PRECISION DEFAULT(0),
AGEDBAL0 DOUBLE PRECISION DEFAULT(0),
AGEDBAL0_FC DOUBLE PRECISION DEFAULT(0),
AGEDBAL1 DOUBLE PRECISION DEFAULT(0),
AGEDBAL1_FC DOUBLE PRECISION DEFAULT(0),
AGEDBAL2 DOUBLE PRECISION DEFAULT(0),
AGEDBAL2_FC DOUBLE PRECISION DEFAULT(0),
AGEDBAL3 DOUBLE PRECISION DEFAULT(0),
AGEDBAL3_FC DOUBLE PRECISION DEFAULT(0),
BALANCE DOUBLE PRECISION DEFAULT(0), -- working backwards(local currency)
BALANCE_FC DOUBLE PRECISION DEFAULT(0), -- working backwards(in currency of account)
ADJUSTMENT DOUBLE PRECISION DEFAULT(0),
ADJUSTMENT_FC DOUBLE PRECISION DEFAULT(0),
ROUNDING_ADJUSTMENT DOUBLE PRECISION DEFAULT(0),
ROUNDING_ADJUSTMENT_FC DOUBLE PRECISION DEFAULT(0),
EXCHRATE_APPLIED DOUBLE PRECISION DEFAULT(0) -- For current period this will be current exchrates;
-- For prior period it uses closing rates for the period
)
BEGIN
Declare @period_seqno0 integer,
@MinTranSeqno0 integer,
@AGE integer,
@period_seqno1 integer,
@period_seqno2 integer,
@period_seqno3 integer,
@period_seqno_Current integer,
@MinTranSeqnoCurrent integer,
@Ledger char(1),
@GLPeriod_seqno integer

-- If the period parameter being passed through is not age then use the period_seqno being passed through
-- to work out the age.
if @PERIODPARAM_IS_AGE = 'N'
select @AGE = age from period_status where seqno = @period
else
select @AGE = @PERIOD

Set @Ledger = 'D'

--retrieve GL periodseqno that gets used to derive the closing rate for the period
select @GLPeriod_seqno = seqno from period_status
where ledger = 'G' and age = @AGE

-- Retrieve period_seqnos for ages.
select @period_seqno_Current = seqno, @MinTranSeqnoCurrent = MinTranSeqno from PERIOD_STATUS
where AGE = 0 and LEDGER = @Ledger
If @AGE = 0
set @MinTranSeqno0 = @MinTranSeqnoCurrent
else
select @MinTranSeqno0 = MinTranSeqno from PERIOD_STATUS
where AGE = (@AGE-1) and LEDGER = @Ledger
select @period_seqno0 =seqno from PERIOD_STATUS
where AGE = @AGE and LEDGER = @Ledger
select @period_seqno1 =seqno from PERIOD_STATUS
where AGE = (@AGE + 1) and LEDGER = @Ledger
select @period_seqno2 = seqno from PERIOD_STATUS
where AGE = (@AGE + 2) and LEDGER = @Ledger
select @period_seqno3 = seqno from PERIOD_STATUS
where AGE = (@AGE + 3) and LEDGER = @Ledger

insert into @TMP_AGEDBALANCES
(accno, accountname, currencyno, currency, CURRENCYNAME, agedbal0_fc, agedbal1_fc, agedbal2_fc, agedbal3_fc, balance_fc,
agedbal0, agedbal1, agedbal2, agedbal3, balance, EXCHRATE_CURRENT, EXCHRATE_APPLIED,
alphacode, accgroup, accgroup2, accgroup_name, accgroup2_name)
select D.accno, D.name, D.currencyno, C.currcode, C.CURRNAME,
AGEDBAL0_FC = ISNULL(AGE0.SUMAGEBAL_FC, 0),
AGEDBAL1_FC = ISNULL(AGE1.SUMAGEBAL_FC, 0),
AGEDBAL2_FC = ISNULL(AGE2.SUMAGEBAL_FC, 0),
AGEDBAL3_FC = ISNULL(AGE3.SUMAGEBAL_FC, 0),
BALANCE_FC = ISNULL(BALANCE.SUMAGEBAL_FC, 0),
AGEDBAL0 = ISNULL(AGE0.SUMAGEBAL_FC, 0)/isnull(CCR1.Closing_sellrate, C.sellrate),
AGEDBAL1 = ISNULL(AGE1.SUMAGEBAL_FC, 0)/isnull(CCR1.Closing_sellrate, C.sellrate),
AGEDBAL2 = ISNULL(AGE2.SUMAGEBAL_FC, 0)/isnull(CCR1.Closing_sellrate, C.sellrate),
AGEDBAL3 = ISNULL(AGE3.SUMAGEBAL_FC, 0)/isnull(CCR1.Closing_sellrate, C.sellrate),
BALANCE = ISNULL(BALANCE.SUMAGEBAL_FC, 0)/isnull(CCR1.Closing_sellrate, C.sellrate),
C.sellrate, isnull(CCR1.Closing_sellrate, C.sellrate),
D.alphacode, D.accgroup, D.accgroup2, AG.groupname, AG2.groupname
FROM DR_ACCS D
left join dr_accgroups AG on AG.accgroup = D.accgroup
left join dr_accgroup2s AG2 on AG2.accgroup = D.accgroup2
left join currencies C on C.currencyno = D.currencyno
   left join currency_closing_rates CCR1 on CCR1.Currencyno = D.currencyno and CCR1.period_seqno = @GLPeriod_seqno
LEFT JOIN (
SELECT A.ACCNO, SUM(T.AMOUNT - (isnull(SUBQ_CURRENT.allocamount, 0)- isnull(SUBQ_DIFF.allocamount, 0))) SUMAGEBAL_FC
FROM DR_ACCS A
LEFT JOIN DR_TRANS T ON A.ACCNO = T.ACCNO
left join
(select trans_SEQNO, ISNULL(SUM(amount), 0) as allocamount
from dr_allocations
group by trans_seqno) as SUBQ_CURRENT ON SUBQ_CURRENT.TRANS_SEQNO = T.SEQNO
left join
(select trans_SEQNO, ISNULL(SUM(amount), 0) as allocamount
from dr_allocations
where PERIOD_SEQNO > @period_seqno0
group by trans_seqno) as SUBQ_DIFF ON SUBQ_DIFF.TRANS_SEQNO = T.SEQNO
LEFT JOIN PERIOD_STATUS PS ON T.PERIOD_SEQNO=PS.SEQNO
WHERE PS.AGE = @AGE
GROUP BY A.ACCNO, PS.AGE
) AGE0 ON D.ACCNO = AGE0.ACCNO
LEFT JOIN (
SELECT A.ACCNO, SUM(T.AMOUNT - (isnull(SUBQ_CURRENT.allocamount, 0)- isnull(SUBQ_DIFF.allocamount, 0))) SUMAGEBAL_FC
FROM DR_ACCS A
LEFT JOIN DR_TRANS T ON A.ACCNO = T.ACCNO
left join
(select trans_SEQNO, ISNULL(SUM(amount), 0) as allocamount
from dr_allocations
group by trans_seqno) as SUBQ_CURRENT ON SUBQ_CURRENT.TRANS_SEQNO = T.SEQNO
left join
(select trans_SEQNO, ISNULL(SUM(amount), 0) as allocamount
from dr_allocations
where PERIOD_SEQNO > @period_seqno0
group by trans_seqno) as SUBQ_DIFF ON SUBQ_DIFF.TRANS_SEQNO = T.SEQNO
LEFT JOIN PERIOD_STATUS PS ON T.PERIOD_SEQNO=PS.SEQNO
WHERE PS.AGE = @AGE + 1
GROUP BY A.ACCNO, PS.AGE
) AGE1 ON D.ACCNO = AGE1.ACCNO
LEFT JOIN (
SELECT A.ACCNO, SUM(T.AMOUNT - (isnull(SUBQ_CURRENT.allocamount, 0)- isnull(SUBQ_DIFF.allocamount, 0))) SUMAGEBAL_FC
FROM DR_ACCS A
LEFT JOIN DR_TRANS T ON A.ACCNO = T.ACCNO
left join
(select trans_SEQNO, ISNULL(SUM(amount), 0) as allocamount
from dr_allocations
group by trans_seqno) as SUBQ_CURRENT ON SUBQ_CURRENT.TRANS_SEQNO = T.SEQNO
left join
(select trans_SEQNO, ISNULL(SUM(amount), 0) as allocamount
from dr_allocations
where PERIOD_SEQNO > @period_seqno0
group by trans_seqno) as SUBQ_DIFF ON SUBQ_DIFF.TRANS_SEQNO = T.SEQNO
LEFT JOIN PERIOD_STATUS PS ON T.PERIOD_SEQNO=PS.SEQNO
WHERE PS.AGE = @AGE + 2
GROUP BY A.ACCNO, PS.AGE
) AGE2 ON D.ACCNO = AGE2.ACCNO
LEFT JOIN (
SELECT A.ACCNO, SUM(T.AMOUNT - (isnull(SUBQ_CURRENT.allocamount, 0)- isnull(SUBQ_DIFF.allocamount, 0))) SUMAGEBAL_FC
FROM DR_ACCS A
LEFT JOIN DR_TRANS T ON A.ACCNO = T.ACCNO
left join
(select trans_SEQNO, ISNULL(SUM(amount), 0) as allocamount
from dr_allocations
group by trans_seqno) as SUBQ_CURRENT ON SUBQ_CURRENT.TRANS_SEQNO = T.SEQNO
left join
(select trans_SEQNO, ISNULL(SUM(amount), 0) as allocamount
from dr_allocations
where PERIOD_SEQNO > @period_seqno0
group by trans_seqno) as SUBQ_DIFF ON SUBQ_DIFF.TRANS_SEQNO = T.SEQNO
LEFT JOIN PERIOD_STATUS PS ON T.PERIOD_SEQNO=PS.SEQNO
WHERE PS.AGE >= @AGE + 3
GROUP BY A.ACCNO
) AGE3 ON D.ACCNO = AGE3.ACCNO
  LEFT JOIN (
select A.accno, (isnull(T1.amount, 0) - isnull(T2.amount, 0)) as SUMAGEBAL_FC
from dr_accs A
left join
(select accno, sum(amount) as amount from dr_trans group by accno) as T1 on T1.accno = A.accno
left join
(select accno, sum(amount) as amount from dr_trans where period_seqno > @period_seqno0 and seqno >= @MinTranSeqno0 group by accno ) as T2 on T2.accno = A.accno

) BALANCE ON D.ACCNO = BALANCE.ACCNO
where D.head_accno = -1 -- exclude child/branch accounts

Update @TMP_AGEDBALANCES
set
ADJUSTMENT = (BALANCE - (AGEDBAL0+AGEDBAL1+AGEDBAL2+AGEDBAL3)),
ADJUSTMENT_FC = (BALANCE_FC - (AGEDBAL0_FC+AGEDBAL1_FC+AGEDBAL2_FC+AGEDBAL3_FC))

-- Any imbalances go in agedbal3
Update @TMP_AGEDBALANCES
set
AGEDBAL3 = AGEDBAL3 + (BALANCE - (AGEDBAL0+AGEDBAL1+AGEDBAL2+AGEDBAL3)),
AGEDBAL3_FC = AGEDBAL3_FC + (BALANCE_FC - (AGEDBAL0_FC+AGEDBAL1_FC+AGEDBAL2_FC+AGEDBAL3_FC))

-- Round to 2dp
Update @TMP_AGEDBALANCES
Set AGEDBAL0 = ROUND(AGEDBAL0, 2),
AGEDBAL0_FC = ROUND(AGEDBAL0_FC, 2),
AGEDBAL1 = ROUND(AGEDBAL1, 2),
AGEDBAL1_FC = ROUND(AGEDBAL1_FC, 2),
AGEDBAL2 = ROUND(AGEDBAL2, 2),
AGEDBAL2_FC = ROUND(AGEDBAL2_FC, 2),
AGEDBAL3 = ROUND(AGEDBAL3, 2),
AGEDBAL3_FC = ROUND(AGEDBAL3_FC, 2),
BALANCE = ROUND(BALANCE, 2),
BALANCE_FC = ROUND(BALANCE_FC, 2)

-- Check for rounding adjustments
Update @TMP_AGEDBALANCES
set ROUNDING_ADJUSTMENT = round(BALANCE - (AGEDBAL0 + AGEDBAL1 + AGEDBAL2 + AGEDBAL3), 2),
ROUNDING_ADJUSTMENT_FC = round(BALANCE_FC - (AGEDBAL0_FC + AGEDBAL1_FC + AGEDBAL2_FC + AGEDBAL3_FC), 2)

  RETURN
END


Procedure: FN_DR_UNREALISED_FOREX_VARIANCES
NameFN_DR_UNREALISED_FOREX_VARIANCES
Note
Code-- =============================================
-- description: Calculates the unrealised forex gains/losses as at any period.
-- Takes in age/period_seqno as a parameter.
-- Child/branch accounts are excluded.
-- Balances are calculated working backwards from the current balance.
-- Indexes on Dr_allocations period_seqno and trans_seqno are required for this query to run efficiently.
-- =============================================
CREATE FUNCTION [dbo].[FN_DR_UNREALISED_FOREX_VARIANCES]
(
@PERIOD INT = 0,
@PERIODPARAM_IS_AGE CHAR(1) = 'Y' -- If 'N', then it is assumed that the param passed is periodSeqno
)
RETURNS
  @TMP_AGEDBALANCES
  TABLE (
ACCOUNTNAME VARCHAR(100),
ACCNO INTEGER NOT NULL,
CURRNAME VARCHAR(30),
CURRENCY VARCHAR(3),
CURRENCYNO INTEGER,
BRANCHNO INTEGER,
TRANSDATE DATETIME,
REF1 VARCHAR(100),
REF2 VARCHAR(100),
REF3 VARCHAR(100),
INVNO VARCHAR(100),
SEQNO INTEGER,
PERIOD_SEQNO INTEGER,
AGE INTEGER,
AMOUNT DOUBLE PRECISION NOT NULL DEFAULT(0),
EXCHRATE DOUBLE PRECISION NOT NULL DEFAULT(0),
EXCHRATE_ATENDOFPERIOD DOUBLE PRECISION DEFAULT(0),
UNALLOCATED_BAL DOUBLE PRECISION DEFAULT(0), -- WORKING BACKWARDS
VARIANCE DOUBLE PRECISION DEFAULT(0)
)
BEGIN
Declare @GLPeriod_seqno0 integer,
@period_seqno0 integer,
@MinTranSeqno0 integer,
@AGE integer,
@period_seqno1 integer,
@period_seqno2 integer,
@period_seqno3 integer,
@period_seqno_Current integer,
@MinTranSeqnoCurrent integer,
@Ledger char(1)

-- If the period parameter being passed through is not age then use the period_seqno being passed through
-- to work out the age.
if @PERIODPARAM_IS_AGE = 'N'
select @AGE = age from period_status where seqno = @period
else
select @AGE = @PERIOD

Set @Ledger = 'D'

-- Retrieve period_seqnos for ages.
SELECT @PERIOD_SEQNO_CURRENT = SEQNO, @MINTRANSEQNOCURRENT = MINTRANSEQNO
FROM PERIOD_STATUS
WHERE AGE = 0 AND LEDGER = @Ledger

SELECT @PERIOD_SEQNO0 =SEQNO, @MINTRANSEQNO0 = MINTRANSEQNO
FROM PERIOD_STATUS
WHERE AGE = @AGE AND LEDGER = @Ledger

SELECT @PERIOD_SEQNO1 =SEQNO
FROM PERIOD_STATUS
WHERE AGE = (@AGE + 1) AND LEDGER = @Ledger

SELECT @PERIOD_SEQNO2 = SEQNO
FROM PERIOD_STATUS
WHERE AGE = (@AGE + 2) AND LEDGER = @Ledger

SELECT @PERIOD_SEQNO3 = SEQNO
FROM PERIOD_STATUS
WHERE AGE = (@AGE + 3) AND LEDGER = @Ledger

SELECT @GLPeriod_seqno0 = SEQNO
FROM PERIOD_STATUS
WHERE AGE = @AGE AND LEDGER = 'G'

INSERT INTO @TMP_AGEDBALANCES (ACCNO, ACCOUNTNAME, CURRNAME, CURRENCY, CURRENCYNO, TRANSDATE,
REF1, REF2, REF3, INVNO, AMOUNT, EXCHRATE, SEQNO, PERIOD_SEQNO, AGE,
BRANCHNO, EXCHRATE_ATENDOFPERIOD, UNALLOCATED_BAL)
SELECT A.ACCNO, A.NAME, C.CURRNAME, C.CURRCODE, A.CURRENCYNO, T.TRANSDATE, T.REF1,
T.REF2, T.REF3, T.INVNO, ISNULL(T.AMOUNT, 0), T.EXCHRATE, ISNULL(T.SEQNO, 0),
T.PERIOD_SEQNO, PS.AGE, T.BRANCHNO, ISNULL(CCR.CLOSING_SELLRATE, C.SELLRATE),
ISNULL(ROUND((T.AMOUNT - (ISNULL(SUBQBAL_CURRENT.ALLOCAMOUNT, 0)-ISNULL(SUBQBAL_DIFF.ALLOCAMOUNT, 0))), 2), 0) -- UNALLOCATED AMOUNT
FROM DR_ACCS A
LEFT JOIN DR_TRANS T ON A.ACCNO= T.ACCNO
LEFT JOIN CURRENCY_CLOSING_RATES CCR ON CCR.CURRENCYNO = T.CURRENCYNO AND CCR.PERIOD_SEQNO = @GLPeriod_seqno0
LEFT JOIN CURRENCIES C ON C.CURRENCYNO = T.CURRENCYNO
LEFT JOIN -- ALLOCATIONS AS AT CURRENT PERIOD
(SELECT TRANS_SEQNO, SUM(AMOUNT) AS ALLOCAMOUNT
FROM DR_ALLOCATIONS
WHERE PERIOD_SEQNO <= @PERIOD_SEQNO_CURRENT
GROUP BY TRANS_SEQNO ) AS SUBQBAL_CURRENT ON T.SEQNO = SUBQBAL_CURRENT.TRANS_SEQNO
LEFT JOIN -- ALLOCATIONS BETWEEN CURRENT PERIOD AND THE RETROSPECTIVE PERIOD
(SELECT TRANS_SEQNO, SUM(AMOUNT) AS ALLOCAMOUNT
FROM DR_ALLOCATIONS
WHERE PERIOD_SEQNO <= @PERIOD_SEQNO_CURRENT AND PERIOD_SEQNO > @PERIOD_SEQNO0 AND TRANS_SEQNO >= @MINTRANSEQNO0
GROUP BY TRANS_SEQNO ) AS SUBQBAL_DIFF ON T.SEQNO = SUBQBAL_DIFF.TRANS_SEQNO
LEFT JOIN PERIOD_STATUS PS ON T.PERIOD_SEQNO = PS.SEQNO
WHERE T.PERIOD_SEQNO < = @PERIOD_SEQNO0
AND A.CURRENCYNO > 0 -- ONLY FOREIGN CURRENCY ACCOUNTS
AND A.HEAD_ACCNO = -1 -- EXCLUDE CHILD/BRANCH ACCOUNTS

-- CALCULATE THE FOREX VARIANCE BASED ON UNALLOCATED AMOUNT TAKING INTO CONSIDERATION THE EXCHRATE ON
-- THE TRANSACTION AND THE NEAR TERM EXCHRATE FOR THAT PERIOD.
UPDATE @TMP_AGEDBALANCES
SET VARIANCE = -(UNALLOCATED_BAL * (EXCHRATE_ATENDOFPERIOD-EXCHRATE))/(EXCHRATE_ATENDOFPERIOD*EXCHRATE)

Delete from @TMP_AGEDBALANCES where UNALLOCATED_BAL = 0

  RETURN
END


Procedure: FN_END_DATETIME_FOR_DISPLAY
NameFN_END_DATETIME_FOR_DISPLAY
Note
CodeCREATE FUNCTION [dbo].[FN_END_DATETIME_FOR_DISPLAY](@EVENTTYPE INT, @OPTIONS INT, @END_DATETIME DATETIME, @ACTUALFINISH DATETIME)
RETURNS DATETIME
AS
BEGIN
RETURN(
SELECT
CASE
WHEN (@EVENTTYPE=0 AND (@OPTIONS & 1)=1) THEN @END_DATETIME - 1
WHEN (@EVENTTYPE=1 AND (@OPTIONS & 1)=1) THEN @ACTUALFINISH-1
WHEN (@EVENTTYPE=1 AND (@OPTIONS & 1)<>1) THEN @END_DATETIME
ELSE @END_DATETIME
END
)
END


Procedure: fn_GetAge
Namefn_GetAge
Note
CodeCREATE FUNCTION[dbo].[fn_GetAge](@FNPERIODSEQNO INT)
RETURNS INT
AS
BEGIN
RETURN
(SELECT AGE FROM PERIOD_STATUS WHERE SEQNO = @fnPeriodSeqno)
END


Procedure: FN_GetControlAccBalance
NameFN_GetControlAccBalance
Note
Code-- =============================================
-- description: Returns a GL Control Account's Balance as at the input GL Period
-- =============================================
CREATE FUNCTION [dbo].[FN_GetControlAccBalance](@GLAccNO Int, @GLPeriodSeqno Int)
RETURNS float
AS
BEGIN

RETURN(SELECT SUM(GLTRANS.AMOUNT) SUM_GLTRANS_AMOUNT
FROM GL_CONTROL GL_CONTROL
INNER JOIN GLTRANS ON
(GLTRANS.ACCNO = @GLAccNO)
INNER JOIN GLACCS ON
(GLACCS.ACCNO = GLTRANS.ACCNO)
WHERE GLTRANS.PERIOD_SEQNO <= @GLPeriodSeqno)

END


Procedure: FN_GetCrControlAccBalance
NameFN_GetCrControlAccBalance
Note
Code-- =============================================
-- description: Returns a Creditor's GL Control Account Balance as at the input GL Period
-- =============================================
CREATE FUNCTION [dbo].[FN_GetCrControlAccBalance](@GLPeriodSeqno Int)
RETURNS float
AS
BEGIN
DECLARE @CrControlAccNo Int
DECLARE @CrControlAccBal Float
SELECT @CrControlAccNo = CREDITORS FROM GL_CONTROL

SELECT @CrControlAccBal = dbo.FN_GetControlAccBalance(@CrControlAccNo, @GLPeriodSeqno)
RETURN @CrControlAccBal

END


Procedure: FN_GetCrControlFxVariance
NameFN_GetCrControlFxVariance
Note
CodeCREATE FUNCTION [dbo].[FN_GetCrControlFxVariance](@GLPeriodSeqno Int)
RETURNS float
AS
BEGIN
DECLARE @CrFxVar float

  SELECT @CrFxVar = SUM(GLTRANS.AMOUNT)
  FROM GL_CONTROL
  INNER JOIN GLTRANS ON
  (GLTRANS.ACCNO = GL_CONTROL.CREDITORS)
  INNER JOIN GLACCS ON
  (GLACCS.ACCNO = GLTRANS.ACCNO)
  WHERE GLTRANS.PERIOD_SEQNO <= @GLPeriodSeqno
  AND( GLTRANS.AMOUNT <> 0 )
  AND ( GLTRANS.SOURCE = 'x')
  AND ( GLTRANS.DETAILS NOT LIKE 'XRV%')
  AND (GLTRANS.TRANSTYPE = 'XCR')
  RETURN @CrFxVar

END


Procedure: FN_GetCrFxMyGrateExcep
NameFN_GetCrFxMyGrateExcep
Note
CodeCREATE FUNCTION [dbo].[FN_GetCrFxMyGrateExcep]()
RETURNS float
AS
BEGIN

DECLARE @CrFxMyGrate float

SELECT @CrFxMyGrate = SUM(CR_ALLOCATIONS.AMOUNT/CR_TRANS.EXCHRATE)
  FROM CR_ALLOCATIONS CR_ALLOCATIONS
  INNER JOIN CR_TRANS CR_TRANS ON
  (CR_TRANS.SEQNO = CR_ALLOCATIONS.TRANS_SEQNO)
  WHERE ( CR_ALLOCATIONS.TAKENUP = 'Y' )
  AND ( CR_ALLOCATIONS.CURRENCY <> 0 )
  AND ( CR_ALLOCATIONS.ALLOCNO NOT IN
  (SELECT SOURCE_SEQ FROM GLTRANS INNER JOIN GL_CONTROL ON GLTRANS.ACCNO=GL_CONTROL.CREDITORS
  WHERE SOURCE = 'X' AND SOURCE_SEQ IS NOT null))

  RETURN @CrFxMyGrate

END


Procedure: FN_GetDrControlAccBalance
NameFN_GetDrControlAccBalance
Note
Code-- =============================================
-- description: Returns a Debtors's GL Control Account Balance as at the input GL Period
-- =============================================
CREATE FUNCTION [dbo].[FN_GetDrControlAccBalance](@GLPeriodSeqno Int)
RETURNS float
AS
BEGIN
DECLARE @DrControlAccNo Int
DECLARE @DrControlAccBal Float
SELECT @DrControlAccNo = DEBTORS FROM GL_CONTROL

SELECT @DrControlAccBal = dbo.FN_GetControlAccBalance(@DrControlAccNo, @GLPeriodSeqno)
RETURN @DrControlAccBal

END


Procedure: FN_GetDrControlFxVariance
NameFN_GetDrControlFxVariance
Note
CodeCREATE FUNCTION [dbo].[FN_GetDrControlFxVariance](@GLPeriodSeqno Int)
RETURNS float
AS
BEGIN
DECLARE @DrFxVar float

  SELECT @DrFxVar = SUM(GLTRANS.AMOUNT)
  FROM GL_CONTROL
  INNER JOIN GLTRANS ON
  (GLTRANS.ACCNO = GL_CONTROL.DEBTORS)
  INNER JOIN GLACCS ON
  (GLACCS.ACCNO = GLTRANS.ACCNO)
  WHERE GLTRANS.PERIOD_SEQNO <= @GLPeriodSeqno
  AND( GLTRANS.AMOUNT <> 0 )
  AND ( GLTRANS.SOURCE = 'x')
  AND ( GLTRANS.DETAILS NOT LIKE 'XRV%')
  AND (GLTRANS.TRANSTYPE = 'XDR')
  RETURN @DrFxVar

END


Procedure: FN_GetDrFxMyGrateExcep
NameFN_GetDrFxMyGrateExcep
Note
CodeCREATE FUNCTION [dbo].[FN_GetDrFxMyGrateExcep]()
RETURNS float
AS
BEGIN
DECLARE @DrFxMyGrate float

    SELECT @DrFxMyGrate = SUM(DR_ALLOCATIONS.AMOUNT/DR_TRANS.EXCHRATE)
    FROM DR_ALLOCATIONS
    INNER JOIN DR_TRANS ON
    (DR_TRANS.SEQNO = DR_ALLOCATIONS.TRANS_SEQNO)
    WHERE ( DR_ALLOCATIONS.TAKENUP = 'Y')
    AND ( DR_ALLOCATIONS.CURRENCY <> 0 )
    AND ( DR_ALLOCATIONS.ALLOCNO NOT IN
    (SELECT SOURCE_SEQ FROM GLTRANS INNER JOIN GL_CONTROL ON GLTRANS.ACCNO=GL_CONTROL.DEBTORS
    WHERE SOURCE = 'X' AND SOURCE_SEQ IS NOT null))

    RETURN @DrFxMyGrate
END


Procedure: FN_GetStkControlAccBalance
NameFN_GetStkControlAccBalance
Note
Code-- =============================================
-- description: Returns a Debtors's GL Control Account Balance as at the input GL Period
-- =============================================
CREATE FUNCTION [dbo].[FN_GetStkControlAccBalance](@GLPeriodSeqno Int)
RETURNS float
AS
BEGIN
DECLARE @StkControlAccNo Int, @StkControlAccBal Float

SELECT @StkControlAccNo = STOCKBAL FROM GL_CONTROL

SELECT @StkControlAccBal = dbo.FN_GetControlAccBalance(@StkControlAccNo, @GLPeriodSeqno)

RETURN @StkControlAccBal
END


Procedure: FN_GetWIPControlAccBalance
NameFN_GetWIPControlAccBalance
Note
Code-- =============================================
-- description: Returns a WIP GL Control Account Balance as at the input GL Period
-- =============================================
CREATE FUNCTION [dbo].[FN_GetWIPControlAccBalance](@GLPeriodSeqno Int)
RETURNS float
AS
BEGIN
DECLARE @ControlAccNo Int
DECLARE @ControlAccBal Float
SELECT @ControlAccNo = WIP FROM GL_CONTROL

SELECT @ControlAccBal = dbo.FN_GetControlAccBalance(@ControlAccNo, @GLPeriodSeqno)
RETURN @ControlAccBal

END


Procedure: FN_GetWIPValue
NameFN_GetWIPValue
Note
CodeCREATE FUNCTION [dbo].[FN_GetWIPValue](@GLPeriodSeqno Int)
RETURNS float
AS
BEGIN
DECLARE @WIPVALUE float

SELECT @WIPVALUE = ROUND(SUM(LINECOST), 0)
FROM JOB_TRANSACTIONS
WHERE WIP_IN_PERIOD_SEQNO <= @GLPeriodSeqno
AND (WIP_OUT_PERIOD_SEQNO > @GLPeriodSeqno OR WIP_OUT_PERIOD_SEQNO = -1)
AND PROGRESSINVOICE = 'N'

  RETURN @WIPVALUE
END


Procedure: FN_GET_AUSTRALIA_STATECODES
NameFN_GET_AUSTRALIA_STATECODES
Note
CodeCREATE FUNCTION [dbo].[FN_GET_AUSTRALIA_STATECODES]()
RETURNS
@STATECODES TABLE
(
CODE VARCHAR(3)
)
AS
BEGIN
INSERT INTO @STATECODES(CODE) VALUES(NULL)
INSERT INTO @STATECODES(CODE) VALUES('ACT')
INSERT INTO @STATECODES(CODE) VALUES('NSW')
INSERT INTO @STATECODES(CODE) VALUES('VIC')
INSERT INTO @STATECODES(CODE) VALUES('QLD')
INSERT INTO @STATECODES(CODE) VALUES('SA')
INSERT INTO @STATECODES(CODE) VALUES('WA')
INSERT INTO @STATECODES(CODE) VALUES('TAS')
INSERT INTO @STATECODES(CODE) VALUES('NT')

RETURN
END


Procedure: FN_GET_COMPUTER_PROFILE_ID
NameFN_GET_COMPUTER_PROFILE_ID
Note
CodeCREATE FUNCTION [dbo].[FN_GET_COMPUTER_PROFILE_ID] (@COMPUTER_SEQNO INT)
RETURNS INT
AS
BEGIN
    DECLARE @COMPUTER_PROFILE_ID INT = - 1

    IF @COMPUTER_SEQNO = - 1
        SELECT @COMPUTER_SEQNO = [dbo].FN_GET_COMPUTER_SEQNO()

    SELECT @COMPUTER_PROFILE_ID = COMPUTERPROFILEID
    FROM COMPUTER
    WHERE SEQNO = @COMPUTER_SEQNO

    RETURN @COMPUTER_PROFILE_ID
END


Procedure: FN_GET_CREDITORSLEDGER_IMBALANCEREASONS
NameFN_GET_CREDITORSLEDGER_IMBALANCEREASONS
Note
CodeCREATE FUNCTION [dbo].[FN_GET_CREDITORSLEDGER_IMBALANCEREASONS]
(
@period int = 0,
@periodparam_is_age char(1) = 'Y', -- if 'N', then it is assumed that the param passed is periodseqno
@VerificationID varchar(10) = 'ALL'
)
returns
@TMP_TABLE table
(
reason_category varchar(100) default '',
DataVerificationID varchar(20) default '',
invno varchar(20) default '',
accno integer default '',
accname varchar(100) default '',
transaction_type varchar(100) default '',
transaction_date datetime,
period varchar(100) default '',
age integer default (0),
gl_source varchar(5) default '',
batchno integer default (0),
details varchar(200) default '',
amount double precision default(0),
glpostrun_description varchar(200) default '',
glpostrun_initials varchar(5) default '',
glpostrun_number integer default(0),
deposit_status varchar(50) default '',
Currencyno integer default(0),
CurrencyName varchar(50),
source_seq integer default(0)-- used in data verification script
)
as
begin
declare @age integer

if @periodparam_is_age = 'N'
select @age = age from period_status where seqno = @period
else
select @age = @period

--unposted transactions in local currency converted at closing rates for prior periods
if @VerificationID = 'ALL' or @VerificationID = 'CB001'
begin
insert into @tmp_table
(reason_category, DataVerificationID, accno, accname, invno, transaction_type, transaction_date, period, age, amount)
select 'Unposted Transactions', 'CB001', t.accno, t.name, t.invno,
case t.transtype
when 1 then 'invoice/credit'
when 4 then 'payment/receipt'
when 5 then 'adjustment'
end,
t.transdate, period_status.period_shortname, period_status.age,
case t.age
when 0 then sum(amount/c.sellrate)
else sum(amount/ccr.closing_sellrate)
end as amount
from cr_trans t
inner join period_status period_status on (period_status.seqno = t.period_seqno)
left join period_status ps1 on period_status.age=ps1.age and ps1.ledger='G'
left join currencies c on c.currencyno = t.currencyno
left join currency_closing_rates ccr on ccr.currencyno = t.currencyno and ccr.period_seqno = ps1.seqno
where ( t.glposted <> 'Y' )
and ( t.amount <> 0 )
and ( period_status.age >= @age )
group by t.transdate, t.invno, t.accno,
t.name, t.transtype, t.transdate,
t.age, period_status.age, period_status.period_shortname
order by t.transtype
end

-- direct postings into the control account(excluding sources banking batches, payment processing , forex variations and creditors ledger)
if @VerificationID = 'ALL' or @VerificationID = 'CB002'
begin
insert into @tmp_table
(reason_category, DataVerificationID, invno, details, gl_source, transaction_date, period, age, batchno, amount)
select 'Direct Postings', 'CB002', gltrans.invno, gltrans.details, gltrans.[source], gltrans.transdate,
period_status.period_shortname, period_status.age,
gltrans.batchno, gltrans.amount
from gl_control gl_control
inner join gltrans gltrans on (gltrans.accno = gl_control.Creditors)
left outer join period_status period_status on (period_status.seqno = gltrans.period_seqno)
where ( gltrans.source not in ('c', 'C', 'b', 'x') )
and ( gltrans.amount <> 0 )
and ( gltrans.initials <> 'IMP' )
and ( period_status.age >= @age )
and ( gltrans.initials not like 'XRV%' )
end

--erroneous payments and adjustments
if @VerificationID = 'ALL' or @VerificationID = 'CB003'
begin
insert into @tmp_table
(reason_category, DataVerificationID, accno, accname, invno, transaction_type, transaction_date, period, age, amount)
select 'Erroneous Payments and Adjustments', 'CB003', t.accno, t.name, t.invno,
case t.transtype
when 1 then 'invoice/credit'
when 4 then 'payment/receipt'
when 5 then 'adjustment' end,
t.transdate,
period_status.period_shortname, t.age,
case t.age when 0 then amount/c.sellrate else amount/ccr.closing_sellrate end as amount
from Cr_trans t
inner join gl_control gl_control on (gl_control.Creditors = t.glcode)
left outer join period_status period_status on (period_status.seqno = t.period_seqno)
left join period_status ps1 on period_status.age=ps1.age and ps1.ledger='G'
left join currencies c on c.currencyno = t.currencyno
left join currency_closing_rates ccr on ccr.currencyno = t.currencyno and ccr.period_seqno = ps1.seqno
where ( t.glposted = 'Y' )
and ( t.transtype in (4, 5) )
and ( period_status.age >= @age )
end

-- forex unrealised gains/losses
if @VerificationID = 'ALL' or @VerificationID = 'CB006'
begin
insert into @tmp_table
(reason_category, DataVerificationID, batchno, transaction_date, period, age, details,
amount, Currencyno, Currencyname)
select 'Unrealised Forex Gains Losses', 'CB006', gltrans.batchno, gltrans.transdate,
period_status.period_shortname, period_status.age, gltrans.details,
gltrans.amount, C.currencyno, C.currname
from gl_control gl_control
inner join gltrans gltrans on (gltrans.accno = gl_control.Creditors)
left outer join period_status period_status on (period_status.seqno = gltrans.period_seqno)
left join currencies C on C.currencyno = gltrans.currencyno
where ( gltrans.amount <> 0 )
and ( period_status.age >= @age )
and [source] = 'x'
and ( gltrans.details like 'XRV - Unrealised%' )
and (gltrans.transtype = 'XCU')
end

--unposted GL postruns
if @VerificationID = 'ALL' or @VerificationID = 'CB004'
begin
insert into @tmp_table
(reason_category, DataVerificationID, transaction_date, glpostrun_description, glpostrun_initials,
glpostrun_number, amount)
SELECT 'Suspended GL Postruns', 'CB004', pr.transdate, pr.[description], pr.initials, pr.seqno, sum(L.amount)
FROM GL_SJPOSTRUN PR
left join gl_sjhdr H on pr.seqno = H.postrunseqno
left join gl_sjlines L on H.seqno = L.hdr_seqno
WHERE CREDITORSLEDGER = 'Y' AND pr.HDRTYPE = 1
and accno = (select creditors from GL_control)
group by pr.seqno, pr.transdate, pr.[description], pr.initials
end
--Realised Forex gains/losses
if @VerificationID = 'ALL' or @VerificationID = 'CB005'
begin
insert into @tmp_table
(reason_category, DataVerificationID, transaction_date, period, age,
details, amount, batchno)
SELECT 'Realised Forex Gains/losses', 'CB005', TRANSDATE, PS.period_shortname, PS.age,
DETAILS, amount, batchno
FROM GL_CONTROL GL_CONTROL
INNER JOIN GLTRANS GLTRANS ON (GLTRANS.ACCNO = GL_CONTROL.CREDITORS)
LEFT OUTER JOIN PERIOD_STATUS PS ON (PS.SEQNO = GLTRANS.PERIOD_SEQNO)
WHERE ( GLTRANS.SOURCE = 'x' )
AND ( GLTRANS.AMOUNT <> 0 )
AND ( PS.AGE >= @age )
AND ( GLTRANS.DETAILS NOT LIKE 'XRV%' )
AND (GLTRANS.TRANSTYPE = 'XCR')
end

return
end


Procedure: FN_GET_DEBTORSLEDGER_IMBALANCEREASONS
NameFN_GET_DEBTORSLEDGER_IMBALANCEREASONS
Note
CodeCREATE function [dbo].[FN_GET_DEBTORSLEDGER_IMBALANCEREASONS]
(
@period int = 0,
@periodparam_is_age char(1) = 'Y', -- if 'N', then it is assumed that the param passed is periodseqno
@VerificationID varchar(10) = 'ALL'
)
returns
@TMP_TABLE table
(
reason_category varchar(100) default '',
DataVerificationID varchar(20) default '',
invno varchar(20) default '',
accno integer default '',
accname varchar(100) default '',
transaction_type varchar(100) default '',
transaction_date datetime,
period varchar(100) default '',
age integer default (0),
gl_source varchar(5) default '',
batchno integer default (0),
details varchar(200) default '',
amount double precision default(0),
glpostrun_description varchar(200) default '',
glpostrun_initials varchar(5) default '',
glpostrun_number integer default(0),
deposit_status varchar(50) default '',
Currencyno integer default(0),
CurrencyName varchar(50),
source_seq integer default(0)-- used in data verification script
)
as
begin
declare @age integer

if @periodparam_is_age = 'N'
select @age = age from period_status where seqno = @period
else
select @age = @period

--unposted transactions in local currency converted at closing rates for prior periods
if @VerificationID = 'ALL' or @VerificationID = 'DB001'
begin
insert into @tmp_table
(reason_category, DataVerificationID, deposit_status, accno, accname, invno, transaction_type,
transaction_date, period, age, amount, source_seq)
select 'Unposted Transactions', 'DB001',
case deposit_status
when 0 then ''
else 'Deposits (Unjournalized)'
end,
t.accno, t.name, t.invno,
case t.transtype
when 1 then 'invoice/credit'
when 4 then 'payment/receipt'
when 5 then 'adjustment'
end,
t.transdate, period_status.period_shortname, period_status.age,
case t.age
when 0 then sum(amount/c.sellrate)
else sum(amount/ccr.closing_sellrate)
end as amount,
t.seqno
from dr_trans t
inner join period_status period_status on (period_status.seqno = t.period_seqno)
left join period_status ps1 on period_status.age=ps1.age and ps1.ledger='G'
left join currencies c on c.currencyno = t.currencyno
left join currency_closing_rates ccr on ccr.currencyno = t.currencyno and ccr.period_seqno = ps1.seqno
where ( t.glposted <> 'Y' )
and ( t.amount <> 0 )
and ( t.deposit_status <> 2 )
and ( period_status.age >= @age )
group by t.transdate, t.invno, t.accno,
t.name, t.transtype, t.transdate,
t.age, period_status.age, period_status.period_shortname, deposit_status, t.seqno
order by t.transtype
end

-- direct postings into the control account(excluding sources banking batches, cashbook entry ,
-- forex variations and debtors ledger)
if @VerificationID = 'ALL' or @VerificationID = 'DB003'
begin
insert into @tmp_table
(reason_category, DataVerificationID, invno, details, gl_source, transaction_date, period, age, batchno, amount, source_seq)
select 'Direct Postings', 'DB003', gltrans.invno, gltrans.details, gltrans.[source], gltrans.transdate,
period_status.period_shortname, period_status.age,
gltrans.batchno, gltrans.amount, gltrans.seqno
from gl_control gl_control
inner join gltrans gltrans on
(gltrans.accno = gl_control.debtors)
left outer join period_status period_status on
(period_status.seqno = gltrans.period_seqno)
where ( gltrans.source not in ('b', 'B', 'd', 'x') )
and ( gltrans.amount <> 0 )
and ( gltrans.initials <> 'IMP' )
and ( period_status.age >= @age )
and ( gltrans.initials not like 'XRV%' )
               and (gltrans.INVNO <>'BANK-BATCH') /* These are direct postings from the Batch receipting screen that have a source 'R' but have been GL transactions */
end

--erroneous payments and adjustments
if @VerificationID = 'ALL' or @VerificationID = 'DB004'
begin
insert into @tmp_table
(reason_category, DataVerificationID, accno, accname, invno, transaction_type, transaction_date,
period, age, amount, source_seq)
select 'Erroneous Payments and Adjustments', 'DB004', t.accno, t.name, t.invno,
case t.transtype
when 1 then 'invoice/credit'
when 4 then 'payment/receipt'
when 5 then 'adjustment'
end,
t.transdate,
period_status.period_shortname, t.age,
case t.age
when 0 then amount/c.sellrate
else amount/ccr.closing_sellrate
end as amount,
t.seqno
from dr_trans t
inner join gl_control gl_control on (gl_control.debtors = t.glcode)
left join period_status period_status on (period_status.seqno = t.period_seqno)
left join period_status ps1 on period_status.age=ps1.age and ps1.ledger='G'
left join currencies c on c.currencyno = t.currencyno
left join currency_closing_rates ccr on ccr.currencyno = t.currencyno and ccr.period_seqno = ps1.seqno
where ( t.glposted = 'Y' )
and ( t.transtype in (4, 5) )
and ( period_status.age >= @age )
end

-- forex gains/losses
if @VerificationID = 'ALL' or @VerificationID = 'DB006'
begin
insert into @tmp_table
(reason_category, DataVerificationID, batchno, transaction_date,
period, age, details, amount, source_seq, Currencyno, Currencyname)
select 'Unrealised Forex Gains Losses', 'DB006', gltrans.batchno, gltrans.transdate,
period_status.period_shortname, period_status.age, gltrans.details,
gltrans.amount, gltrans.seqno, C.currencyno, C.currname
from gl_control gl_control
inner join gltrans gltrans on (gltrans.accno = gl_control.debtors)
left join period_status period_status on (period_status.seqno = gltrans.period_seqno)
left join currencies C on C.currencyno = gltrans.currencyno
where ( gltrans.amount <> 0 )
and ( period_status.age >= @age )
and [source] = 'x'
and ( gltrans.details like 'XRV - Unrealised%' )
and (gltrans.transtype = 'XDU')
end

-- unallocated deposits
if @VerificationID = 'ALL' or @VerificationID = 'DB002'
begin
insert into @tmp_table
(reason_category, DataVerificationID, transaction_date, period, age, accname, accno, amount, source_seq)
select 'Unallocated Deposits', 'DB002', t.transdate,
period_status.period_shortname, period_status.age,
t.name, t.accno,
case t.age when 0 then amount/c.sellrate else amount/ccr.closing_sellrate end as amount,
T.seqno
from dr_trans t
inner join period_status period_status on (period_status.seqno = t.period_seqno)
left join period_status ps1 on period_status.age=ps1.age and ps1.ledger='g'
left join currencies c on c.currencyno = t.currencyno
left join currency_closing_rates ccr on ccr.currencyno = t.currencyno and ccr.period_seqno = ps1.seqno
where ( t.glposted = 'Y' )
and ( t.amount <> 0 )
and ( t.deposit_status = 1 )
and (Period_status.age >= @age)
end

--unposted GL postruns
if @VerificationID = 'ALL' or @VerificationID = 'DB005'
begin
insert into @tmp_table
(reason_category, DataVerificationID, transaction_date, glpostrun_description, glpostrun_initials,
glpostrun_number, amount, source_seq)
SELECT 'Suspended GL Postruns', 'DB005', pr.transdate, pr.[description], pr.initials, pr.seqno,
sum(L.amount), pr.seqno
FROM GL_SJPOSTRUN PR
left join gl_sjhdr H on pr.seqno = H.postrunseqno
left join gl_sjlines L on H.seqno = L.hdr_seqno
WHERE DEBTORSLEDGER = 'Y' AND pr.HDRTYPE = 1
and accno = (select debtors from GL_control)
group by pr.seqno, pr.transdate, pr.[description], pr.initials
end

--Realised Forex gains/losses
if @VerificationID = 'ALL' or @VerificationID = 'DB007'
begin
insert into @tmp_table
(reason_category, DataVerificationID, transaction_date, period, age,
details, amount, batchno)
SELECT 'Realised Forex Gains/losses', 'DB007', TRANSDATE, PS.period_shortname, PS.age,
DETAILS, amount, batchno
FROM GL_CONTROL GL_CONTROL
INNER JOIN GLTRANS GLTRANS ON (GLTRANS.ACCNO = GL_CONTROL.DEBTORS)
LEFT OUTER JOIN PERIOD_STATUS PS ON (PS.SEQNO = GLTRANS.PERIOD_SEQNO)
WHERE ( GLTRANS.SOURCE = 'x' )
AND ( GLTRANS.AMOUNT <> 0 )
AND ( PS.AGE >= @age )
AND ( GLTRANS.DETAILS NOT LIKE 'XRV%' )
AND (GLTRANS.TRANSTYPE = 'XDR')
end

return
end


Procedure: FN_GET_GLAGE
NameFN_GET_GLAGE
Note
CodeCREATE FUNCTION [dbo].[FN_GET_GLAGE] (@FNPERIODSEQNO INT, @FNSOURCE CHAR(1), @TRANSTYPE VARCHAR(3))
RETURNS INT
AS
BEGIN
RETURN
CASE WHEN (@FNSOURCE = 'e') or (@FNSOURCE = 'r' AND @TRANSTYPE = 'EYO') THEN -1 ELSE (SELECT AGE FROM PERIOD_STATUS WHERE SEQNO = @fnPeriodSeqno) END
END


Procedure: FN_GET_MANREP_DAYS
NameFN_GET_MANREP_DAYS
Note
CodeCREATE FUNCTION [dbo].[FN_GET_MANREP_DAYS]
  ( @STARTDATE datetime,
    @ENDDATE datetime )
RETURNS INT WITH SCHEMABINDING
AS
BEGIN
/* Function to return working days by MANREP_DAYPLAN */
  DECLARE @WORKDAYS INT

  SELECT @WORKDAYS = COUNT(*) FROM dbo.MANREP_DAYPLAN
          WHERE THEDATE BETWEEN @STARTDATE AND @ENDDATE
            AND WORKDAY = 'Y'

  RETURN ISNULL(@WORKDAYS, 0)
END


Procedure: FN_GET_PROFILE_TYPE
NameFN_GET_PROFILE_TYPE
Note
CodeCREATE FUNCTION [dbo].[FN_GET_PROFILE_TYPE] (@FIELDNAME VARCHAR(40))
RETURNS INT
AS
BEGIN
    DECLARE @PROFILETYPE INT;

    SELECT @PROFILETYPE = PROFILETYPE
    FROM PROFILE_FIELDS
    WHERE FIELDNAME = @FIELDNAME

    RETURN @PROFILETYPE
END


Procedure: FN_GET_PROFILE_VALUE
NameFN_GET_PROFILE_VALUE
Note
CodeCREATE FUNCTION [dbo].[FN_GET_PROFILE_VALUE] (@FIELDNAME VARCHAR(40))
RETURNS VARCHAR(200)
AS
BEGIN
    DECLARE @DEFAULTVAL VARCHAR(200), @ACTUALVAL VARCHAR(200), @PROFILETYPE INT, @PROFILEID INT, @COUNT INT,
        @FIELDVALUE VARCHAR(200) = NULL

    /* For this stored procedure to return correct result Profile ID must be
         passed in as a parameter for USER, COMPUTER and SECURITY profile fields. */
    SET @PROFILEID = - 1
    SET @PROFILETYPE = dbo.FN_GET_PROFILE_TYPE(@FIELDNAME);

    IF @PROFILETYPE = 1
        SET @PROFILEID = 1
    ELSE IF @PROFILETYPE = 2
        SET @PROFILEID = dbo.FN_GET_USER_PROFILE_ID(- 1)
    ELSE IF @PROFILETYPE = 3
        SET @PROFILEID = dbo.FN_GET_COMPUTER_PROFILE_ID(- 1)
    ELSE IF @PROFILETYPE = 4
        SET @PROFILEID = dbo.FN_GET_SECURITY_PROFILE_ID(- 1)

    SELECT @DEFAULTVAL = PF.DEFAULTVALUE
    FROM PROFILE_FIELDS PF
    WHERE UPPER(PF.FIELDNAME) = UPPER(@FIELDNAME)

    IF @PROFILETYPE <> 1
    BEGIN
        SELECT @COUNT = COUNT(*)
        FROM PROFILE_VALUES PV
        WHERE UPPER(PV.FIELDNAME) = UPPER(@FIELDNAME)
            AND PV.PROFILEID = @PROFILEID

        IF @COUNT = 0
            SET @PROFILEID = @PROFILETYPE
    END

    IF @PROFILEID <> - 1
    BEGIN
        SELECT @ACTUALVAL = PV.FIELDVALUE
        FROM PROFILE_VALUES PV
        WHERE UPPER(PV.FIELDNAME) = UPPER(@FIELDNAME)
            AND PV.PROFILEID = @PROFILEID
    END

    IF @ACTUALVAL IS NULL
        SET @FIELDVALUE = @DEFAULTVAL
    ELSE
        SET @FIELDVALUE = @ACTUALVAL

    RETURN @FIELDVALUE
END


Procedure: FN_GET_PROFILE_VALUE_INT
NameFN_GET_PROFILE_VALUE_INT
Note
CodeCREATE FUNCTION [dbo].[FN_GET_PROFILE_VALUE_INT] (@FIELDNAME VARCHAR(40))
RETURNS INT
AS
BEGIN
    DECLARE @FIELDVALUE INT
    DECLARE @DEFAULTVAL VARCHAR(200), @ACTUALVAL VARCHAR(200), @PROFILETYPE INT, @PROFILEID INT, @COUNT INT

    /* For this stored procedure to return correct result Profile ID must be
         passed in as a parameter for USER, COMPUTER and SECURITY profile fields. */
    SET @PROFILETYPE = - 1
    SET @PROFILEID = - 1
    SET @PROFILETYPE = dbo.FN_GET_PROFILE_TYPE(@FIELDNAME);

    IF @PROFILETYPE = 1
        SET @PROFILEID = 1
    ELSE IF @PROFILETYPE = 2
        SET @PROFILEID = dbo.FN_GET_USER_PROFILE_ID(- 1)
    ELSE IF @PROFILETYPE = 3
        SET @PROFILEID = dbo.FN_GET_COMPUTER_PROFILE_ID(- 1)
    ELSE IF @PROFILETYPE = 4
        SET @PROFILEID = dbo.FN_GET_SECURITY_PROFILE_ID(- 1)

    SELECT @DEFAULTVAL = PF.DEFAULTVALUE
    FROM PROFILE_FIELDS PF
    WHERE UPPER(PF.FIELDNAME) = UPPER(@FIELDNAME)

    IF @PROFILETYPE <> 1
    BEGIN
        SELECT @COUNT = COUNT(*)
        FROM PROFILE_VALUES PV
        WHERE UPPER(PV.FIELDNAME) = UPPER(@FIELDNAME)
            AND PV.PROFILEID = @PROFILEID

        IF @COUNT = 0
            SET @PROFILEID = @PROFILETYPE
    END

    IF @PROFILEID <> - 1
    BEGIN
        SELECT @ACTUALVAL = PV.FIELDVALUE
        FROM PROFILE_VALUES PV
        WHERE UPPER(PV.FIELDNAME) = UPPER(@FIELDNAME)
            AND PV.PROFILEID = @PROFILEID
    END

    SET @FIELDVALUE = 0

    IF (@ACTUALVAL IS NULL)
        AND (@DEFAULTVAL IS NOT NULL)
        AND (@DEFAULTVAL <> '')
        SET @FIELDVALUE = CAST(@DEFAULTVAL AS INT)
    ELSE IF (@ACTUALVAL IS NOT NULL)
        AND (@ACTUALVAL <> '')
        SET @FIELDVALUE = CAST(@ACTUALVAL AS INT)

    RETURN @FIELDVALUE
END


Procedure: FN_GET_SECURITY_PROFILE_ID
NameFN_GET_SECURITY_PROFILE_ID
Note
CodeCREATE FUNCTION [dbo].[FN_GET_SECURITY_PROFILE_ID] (@STAFFNO INT)
RETURNS INT
AS
BEGIN
    DECLARE @SECURITY_PROFILE_ID INT = -1

    IF @STAFFNO = - 1
        SELECT @STAFFNO = [dbo].FN_GET_STAFF_NO()

    SELECT @SECURITY_PROFILE_ID = SECURITYPROFILEID
    FROM STAFF
    WHERE STAFFNO = @STAFFNO

    RETURN @SECURITY_PROFILE_ID
END


Procedure: FN_GET_USER_PROFILE_ID
NameFN_GET_USER_PROFILE_ID
Note
CodeCREATE FUNCTION [dbo].[FN_GET_USER_PROFILE_ID] (@STAFFNO INT)
RETURNS INT
AS
BEGIN
    DECLARE @USER_PROFILE_ID INT = - 1

    IF @STAFFNO = - 1
        SELECT @STAFFNO = [dbo].FN_GET_STAFF_NO()

    SELECT @USER_PROFILE_ID = USERPROFILEID
    FROM STAFF
    WHERE STAFFNO = @STAFFNO

    RETURN @USER_PROFILE_ID
END


Procedure: FN_MANREP_CALC_BRANCHES
NameFN_MANREP_CALC_BRANCHES
Note
CodeCREATE FUNCTION [dbo].[FN_MANREP_CALC_BRANCHES]
(
@MANREPDATE DATETIME,
@period_seqno integer,
@CurrentPeriod char(1)
)
RETURNS
@Tmp_Branches TABLE
(
Branchno INTEGER NOT NULL,
DayOrderValue DOUBLE PRECISION NOT NULL DEFAULT(0),
DayOrderQty INTEGER NOT NULL DEFAULT(0),
Day_sales DOUBLE PRECISION NOT NULL DEFAULT(0),
Period_sales DOUBLE PRECISION NOT NULL DEFAULT(0),
Year_sales DOUBLE PRECISION NOT NULL DEFAULT(0),
Day_Cost DOUBLE PRECISION NOT NULL DEFAULT(0),
Period_Cost DOUBLE PRECISION NOT NULL DEFAULT(0),
Year_Cost DOUBLE PRECISION NOT NULL DEFAULT(0),
DayOrderValue_EXCLUDEQUOTES DOUBLE PRECISION NOT NULL DEFAULT(0),
DayOrderQty_EXCLUDEQUOTES INTEGER NOT NULL DEFAULT(0),
Day_sales_posttime DOUBLE PRECISION NOT NULL DEFAULT(0),
Period_sales_posttime DOUBLE PRECISION NOT NULL DEFAULT(0),
Year_sales_posttime DOUBLE PRECISION NOT NULL DEFAULT(0),
Day_Cost_posttime DOUBLE PRECISION NOT NULL DEFAULT(0),
Period_Cost_posttime DOUBLE PRECISION NOT NULL DEFAULT(0),
Year_Cost_posttime DOUBLE PRECISION NOT NULL DEFAULT(0),
Avg_DebtorDays DOUBLE PRECISION NOT NULL DEFAULT(0),
Avg_CreditorDays DOUBLE PRECISION NOT NULL DEFAULT(0),
PD_Budget_Branch DOUBLE PRECISION NOT NULL DEFAULT(0) )
AS
BEGIN
Declare
@Period_StartDate datetime,
@Period_EndDate datetime,
@Period_YearStart datetime,
@Period_YearEnd datetime,
@Period_Name varchar(50),
@Period_Parent_seqno integer,
@sql_str varchar(max),
@sql_and varchar(max),
@CurrentDate datetime,
@Day_sales float,
@Period_sales float,
@Year_sales float,
@Day_Cost float,
@Period_Cost float,
@Year_Cost float,
@Range_enddate datetime,
@MinTranSeqno int

 insert into @Tmp_Branches (Branchno)
 select branchno from branches


set @currentdate = @MANREPDATE
set @Range_enddate = dateadd(day, 1, @CurrentDate)

-- Get Period Info
 SELECT @Period_StartDate=Period.StartDate, @Period_EndDate=Period.EndDate,
    @Period_YearStart=Period_Year.StartDate, @Period_YearEnd=Period_Year.EndDate,
    @Period_Name=Period.PERIOD_NAME,
@Period_Parent_seqno=Period.PARENT_PERIOD_SEQNO
 FROM MANREP_PERIOD Period
 LEFT JOIN MANREP_PERIOD Period_Year ON Period_Year.Period_SeqNo = Period.Parent_Period_SeqNo
 WHERE (Period.Period_SeqNo=@period_seqno)

 -- Get Branch Budget
 UPDATE T SET
   PD_Budget_Branch = SUBQ.PD_Budget_Branch
 FROM
   @Tmp_Branches T INNER JOIN
   (SELECT BB.BUDGETVALUE AS PD_Budget_Branch, BB.BRANCHNO
FROM MANREP_BUDGET B
LEFT JOIN MANREP_BRANCH_BUDGET BB ON (B.BUDGET_SEQNO=BB.BUDGET_SEQNO)
WHERE (B.PERIOD_SEQNO=@period_seqno)
GROUP BY BB.BRANCHNO, BB.BUDGETVALUE
   )
   AS SUBQ
   ON T.Branchno = SUBQ.branchno

 -- Get Orders for day
UPDATE T SET
   DayOrderValue = SUBQ.Totvalue,
   DayOrderQty = SUBQ.TotQty
 FROM
   @Tmp_Branches T INNER JOIN
   (SELECT branchno, ISNULL(SUM(SUBTOTAL / EXCHRATE), 0) TotValue, Count(*) TotQty FROM SALESORD_HDR
WHERE (ORDERDATE=@currentdate)
AND NOT ((STATUS=2) AND (PROCESSFINALISATION = 1)) -- fully processed and deleted
AND NOT ((STATUS= 6) AND (PROCESSFINALISATION = 3)) -- lost quote
GROUP BY BRANCHNO
   )
AS SUBQ
ON T.Branchno = SUBQ.branchno

UPDATE T SET
   DayOrderValue_EXCLUDEQUOTES = SUBQ.Totvalue,
   DayOrderQty_EXCLUDEQUOTES = SUBQ.TotQty
 FROM
   @Tmp_Branches T INNER JOIN
   (SELECT branchno, ISNULL(SUM(SUBTOTAL / EXCHRATE), 0) TotValue, Count(*) TotQty FROM SALESORD_HDR
WHERE (ORDERDATE=@currentdate)
AND (STATUS <> 3) -- not a quotation
AND NOT ((STATUS=2) AND (PROCESSFINALISATION = 1)) -- fully processed and deleted
AND NOT ((STATUS= 6) AND (PROCESSFINALISATION = 3)) -- lost quote
GROUP BY BRANCHNO
    )
AS SUBQ
ON T.Branchno = SUBQ.branchno

-- Get Average Debtor Days
UPDATE T SET
   Avg_DebtorDays = SUBQ.total
 FROM
   @Tmp_Branches T INNER JOIN
   (SELECT BRANCHNO, sum( cast(GetDate() - transdate as integer)) / count(*) total FROM DR_TRANS WITH(NOLOCK)
WHERE (Dr_trans.TRANSTYPE=1)
AND (TRANSDATE <@CurrentDate) and (Allocated = '0')
group by BRANCHNO
    )
AS SUBQ
ON T.Branchno = SUBQ.branchno

-- Get Average Creditor Days
UPDATE T SET
   Avg_CreditorDays = SUBQ.total
 FROM
   @Tmp_Branches T INNER JOIN
   (SELECT BRANCHNO, sum( cast(GetDate() - transdate as integer)) / count(*) total FROM CR_TRANS WITH(NOLOCK)
WHERE (CR_TRANS.TRANSTYPE=1)
AND (TRANSDATE <@CurrentDate) and (Allocated = '0')
group by BRANCHNO
   )
AS SUBQ
ON T.Branchno = SUBQ.branchno
-- Get Year sales
UPDATE T SET
Year_sales_posttime = SUBQ.Totvalue
FROM
@Tmp_Branches T INNER JOIN
(SELECT BRANCHNO, SUM(SUBTOTAL/EXCHRATE) Totvalue FROM DR_TRANS
left join period_status on dr_trans.period_seqno = period_status.seqno
WHERE (TRANSTYPE=1)
AND (POSTTIME between @Period_yearstart and @range_enddate)
group by DR_TRANS.BRANCHNO
)
AS SUBQ
ON T.Branchno = SUBQ.branchno
UPDATE T SET
Year_sales = SUBQ.Totvalue
FROM
@Tmp_Branches T INNER JOIN
(SELECT BRANCHNO, SUM(SUBTOTAL/EXCHRATE) Totvalue FROM DR_TRANS
left join period_status on dr_trans.period_seqno = period_status.seqno
WHERE (TRANSTYPE=1)
AND (TRANSDATE between @Period_yearstart and @CurrentDate)
group by DR_TRANS.BRANCHNO
)
AS SUBQ
ON T.Branchno = SUBQ.branchno

-- Get Year cost
UPDATE T SET
Year_Cost_posttime = SUBQ.Totvalue
FROM
@Tmp_Branches T INNER JOIN
(SELECT DR_TRANS.BRANCHNO, SUM(DR_INVLINES.QUANTITY*DR_INVLINES.UNITCOST) Totvalue
FROM DR_TRANS
LEFT JOIN DR_INVLINES ON DR_InvLines.Hdr_Seqno = DR_Trans.SeqNo
LEFT JOIN period_status ON dr_trans.period_seqno = period_status.SeqNo
WHERE (Dr_trans.TRANSTYPE=1)
AND (DR_TRANS.POSTTIME between @Period_YearStart and @Range_enddate)
group by DR_TRANS.BRANCHNO
)
AS SUBQ
ON T.Branchno = SUBQ.branchno
UPDATE T SET
Year_Cost = SUBQ.Totvalue
FROM
@Tmp_Branches T INNER JOIN
(SELECT DR_TRANS.BRANCHNO, SUM(DR_INVLINES.QUANTITY*DR_INVLINES.UNITCOST) Totvalue
FROM DR_TRANS
LEFT JOIN DR_INVLINES ON DR_InvLines.Hdr_Seqno = DR_Trans.SeqNo
LEFT JOIN period_status ON dr_trans.period_seqno = period_status.SeqNo
WHERE (Dr_trans.TRANSTYPE=1)
AND (DR_TRANS.TRANSDATE between @Period_YearStart and @CurrentDate)
group by DR_TRANS.BRANCHNO
)
AS SUBQ
ON T.Branchno = SUBQ.branchno

 IF @CurrentPeriod = 'Y'
 begin
SELECT @MinTranSeqno=MINTRANSEQNO
FROM PERIOD_STATUS PS
WHERE LEDGER ='D' AND PS.AGE = (SELECT ANALYSIS_AGE_LIMIT
FROM LEDGER_PERIODS LP
WHERE LP.SEQNO=1)
   SET @MinTranSeqno=ISNULL(@MinTranSeqNo, 0)
---- Get Day sales
UPDATE T SET
Day_sales_posttime = SUBQ.Totvalue
FROM
@Tmp_Branches T INNER JOIN
(SELECT BRANCHNO, SUM(SUBTOTAL/EXCHRATE) Totvalue FROM DR_TRANS
left join period_status on dr_trans.period_seqno = period_status.seqno
WHERE (TRANSTYPE=1)
AND DR_TRANS.SEQNO >= @MinTranSeqno
AND (POSTTIME between @CurrentDate and @Range_enddate)
group by branchno
)
AS SUBQ
ON T.Branchno = SUBQ.branchno
UPDATE T SET
Day_sales = SUBQ.Totvalue
FROM
@Tmp_Branches T INNER JOIN
(SELECT BRANCHNO, SUM(SUBTOTAL/EXCHRATE) Totvalue FROM DR_TRANS
left join period_status on dr_trans.period_seqno = period_status.seqno
WHERE (TRANSTYPE=1)
AND (Period_status.AGE=0)
AND (TRANSDATE = @CurrentDate )
group by branchno
)
AS SUBQ
ON T.Branchno = SUBQ.branchno
-- Get Period sales
UPDATE T SET
Period_sales_posttime = SUBQ.Totvalue
FROM
@Tmp_Branches T INNER JOIN
(SELECT BRANCHNO, SUM(SUBTOTAL/EXCHRATE) Totvalue FROM DR_TRANS
left join period_status on dr_trans.period_seqno = period_status.seqno
WHERE (TRANSTYPE=1)
AND DR_TRANS.SEQNO >= @MinTranSeqno
AND (POSTTIME between @Period_StartDate and @range_enddate)
group by DR_TRANS.BRANCHNO
)
AS SUBQ
ON T.Branchno = SUBQ.branchno
UPDATE T SET
Period_sales = SUBQ.Totvalue
FROM
@Tmp_Branches T INNER JOIN
(SELECT BRANCHNO, SUM(SUBTOTAL/EXCHRATE) Totvalue FROM DR_TRANS
left join period_status on dr_trans.period_seqno = period_status.seqno
WHERE (TRANSTYPE=1)
AND (Period_status.AGE=0)
AND (TRANSDATE between @Period_StartDate and @CurrentDate)
group by DR_TRANS.BRANCHNO
)
AS SUBQ
ON T.Branchno = SUBQ.branchno
-- Get Day cost
UPDATE T SET
Day_Cost_posttime = SUBQ.Totvalue
FROM
@Tmp_Branches T INNER JOIN
(SELECT DR_TRANS.BRANCHNO, SUM(DR_INVLINES.QUANTITY*DR_INVLINES.UNITCOST) Totvalue
FROM DR_TRANS
LEFT JOIN DR_INVLINES ON DR_InvLines.Hdr_Seqno = DR_Trans.SeqNo
LEFT JOIN period_status ON dr_trans.period_seqno = period_status.SeqNo
WHERE (Dr_trans.TRANSTYPE=1)
AND DR_TRANS.SEQNO >= @MinTranSeqno
AND (DR_TRANS.POSTTIME between @CurrentDate and @Range_enddate)
group by DR_TRANS.BRANCHNO
)
AS SUBQ
ON T.Branchno = SUBQ.branchno
UPDATE T SET
Day_Cost = SUBQ.Totvalue
FROM
@Tmp_Branches T INNER JOIN
(SELECT DR_TRANS.BRANCHNO, SUM(DR_INVLINES.QUANTITY*DR_INVLINES.UNITCOST) Totvalue
FROM DR_TRANS
LEFT JOIN DR_INVLINES ON DR_InvLines.Hdr_Seqno = DR_Trans.SeqNo
LEFT JOIN period_status ON dr_trans.period_seqno = period_status.SeqNo
WHERE (Dr_trans.TRANSTYPE=1)
AND (Period_status.AGE=0)
AND (DR_TRANS.TRANSDATE = @CurrentDate )
group by DR_TRANS.BRANCHNO
)
AS SUBQ
ON T.Branchno = SUBQ.branchno
-- Get Period cost
UPDATE T SET
Period_cost_posttime = SUBQ.Totvalue
FROM
@Tmp_Branches T INNER JOIN
(SELECT DR_TRANS.BRANCHNO, SUM(DR_INVLINES.QUANTITY*DR_INVLINES.UNITCOST) Totvalue
FROM DR_TRANS
LEFT JOIN DR_INVLINES ON DR_InvLines.Hdr_Seqno = DR_Trans.SeqNo
LEFT JOIN period_status ON dr_trans.period_seqno = period_status.SeqNo
WHERE (Dr_trans.TRANSTYPE=1)
AND DR_TRANS.SEQNO >= @MinTranSeqno
AND (DR_TRANS.POSTTIME between @Period_StartDate and @Range_enddate)
group by DR_TRANS.BRANCHNO
)
AS SUBQ
ON T.Branchno = SUBQ.branchno
UPDATE T SET
Period_cost = SUBQ.Totvalue
FROM
@Tmp_Branches T INNER JOIN
(SELECT DR_TRANS.BRANCHNO, SUM(DR_INVLINES.QUANTITY*DR_INVLINES.UNITCOST) Totvalue
FROM DR_TRANS
LEFT JOIN DR_INVLINES ON DR_InvLines.Hdr_Seqno = DR_Trans.SeqNo
LEFT JOIN period_status ON dr_trans.period_seqno = period_status.SeqNo
WHERE (Dr_trans.TRANSTYPE=1)
AND (Period_status.AGE=0)
AND (DR_TRANS.TRANSDATE between @Period_StartDate and @CurrentDate)
group by DR_TRANS.BRANCHNO
)
AS SUBQ
ON T.Branchno = SUBQ.branchno
end
else
begin
-- Get Day Sales
UPDATE T SET
Day_sales_posttime = SUBQ.Totvalue
FROM
@Tmp_Branches T INNER JOIN
(SELECT BRANCHNO, SUM(SUBTOTAL/EXCHRATE) Totvalue FROM DR_TRANS
left join period_status on dr_trans.period_seqno = period_status.seqno
WHERE (TRANSTYPE=1)
AND (POSTTIME between @CurrentDate and @Range_enddate)
group by branchno
)
AS SUBQ
ON T.Branchno = SUBQ.branchno
UPDATE T SET
Day_sales = SUBQ.Totvalue
FROM
@Tmp_Branches T INNER JOIN
(SELECT BRANCHNO, SUM(SUBTOTAL/EXCHRATE) Totvalue FROM DR_TRANS
left join period_status on dr_trans.period_seqno = period_status.seqno
WHERE (TRANSTYPE=1)
AND (TRANSDATE = @CurrentDate )
group by branchno
)
AS SUBQ
ON T.Branchno = SUBQ.branchno
-- Get Period sales
UPDATE T SET
Period_sales_posttime = SUBQ.Totvalue
FROM
@Tmp_Branches T INNER JOIN
(SELECT BRANCHNO, SUM(SUBTOTAL/EXCHRATE) Totvalue FROM DR_TRANS
left join period_status on dr_trans.period_seqno = period_status.seqno
WHERE (TRANSTYPE=1)
AND (POSTTIME between @Period_StartDate and @range_enddate)
group by DR_TRANS.BRANCHNO
)
AS SUBQ
ON T.Branchno = SUBQ.branchno
UPDATE T SET
Period_sales = SUBQ.Totvalue
FROM
@Tmp_Branches T INNER JOIN
(SELECT BRANCHNO, SUM(SUBTOTAL/EXCHRATE) Totvalue FROM DR_TRANS
left join period_status on dr_trans.period_seqno = period_status.seqno
WHERE (TRANSTYPE=1)
AND (TRANSDATE between @Period_StartDate and @CurrentDate)
group by DR_TRANS.BRANCHNO
)
AS SUBQ
ON T.Branchno = SUBQ.branchno
-- Get Day cost
UPDATE T SET
Day_Cost_posttime = SUBQ.Totvalue
FROM
@Tmp_Branches T INNER JOIN
(SELECT DR_TRANS.BRANCHNO, SUM(DR_INVLINES.QUANTITY*DR_INVLINES.UNITCOST) Totvalue
FROM DR_TRANS
LEFT JOIN DR_INVLINES ON DR_InvLines.Hdr_Seqno = DR_Trans.SeqNo
LEFT JOIN period_status ON dr_trans.period_seqno = period_status.SeqNo
WHERE (Dr_trans.TRANSTYPE=1)
AND (DR_TRANS.POSTTIME between @CurrentDate and @Range_enddate)
group by DR_TRANS.BRANCHNO
)
AS SUBQ
ON T.Branchno = SUBQ.branchno
UPDATE T SET
Day_Cost = SUBQ.Totvalue
FROM
@Tmp_Branches T INNER JOIN
(SELECT DR_TRANS.BRANCHNO, SUM(DR_INVLINES.QUANTITY*DR_INVLINES.UNITCOST) Totvalue
FROM DR_TRANS
LEFT JOIN DR_INVLINES ON DR_InvLines.Hdr_Seqno = DR_Trans.SeqNo
LEFT JOIN period_status ON dr_trans.period_seqno = period_status.SeqNo
WHERE (Dr_trans.TRANSTYPE=1)
AND (DR_TRANS.TRANSDATE = @CurrentDate )
group by DR_TRANS.BRANCHNO
)
AS SUBQ
ON T.Branchno = SUBQ.branchno
-- Get Period cost
UPDATE T SET
Period_cost_posttime = SUBQ.Totvalue
FROM
@Tmp_Branches T INNER JOIN
(SELECT DR_TRANS.BRANCHNO, SUM(DR_INVLINES.QUANTITY*DR_INVLINES.UNITCOST) Totvalue
FROM DR_TRANS
LEFT JOIN DR_INVLINES ON DR_InvLines.Hdr_Seqno = DR_Trans.SeqNo
LEFT JOIN period_status ON dr_trans.period_seqno = period_status.SeqNo
WHERE (Dr_trans.TRANSTYPE=1)
AND (DR_TRANS.POSTTIME between @Period_StartDate and @Range_enddate)
group by DR_TRANS.BRANCHNO
)
AS SUBQ
ON T.Branchno = SUBQ.branchno
UPDATE T SET
Period_cost = SUBQ.Totvalue
FROM
@Tmp_Branches T INNER JOIN
(SELECT DR_TRANS.BRANCHNO, SUM(DR_INVLINES.QUANTITY*DR_INVLINES.UNITCOST) Totvalue
FROM DR_TRANS
LEFT JOIN DR_INVLINES ON DR_InvLines.Hdr_Seqno = DR_Trans.SeqNo
LEFT JOIN period_status ON dr_trans.period_seqno = period_status.SeqNo
WHERE (Dr_trans.TRANSTYPE=1)
AND (DR_TRANS.TRANSDATE between @Period_StartDate and @CurrentDate)
group by DR_TRANS.BRANCHNO
)
AS SUBQ
ON T.Branchno = SUBQ.branchno
end
RETURN
END


Procedure: FN_MANREP_CALC_SALESPERSONS
NameFN_MANREP_CALC_SALESPERSONS
Note
CodeCREATE FUNCTION [dbo].[FN_MANREP_CALC_SALESPERSONS]
(
@MANREPDATE DATETIME,
@period_seqno integer,
@CurrentPeriod char(1)
)
RETURNS
@Tmp_Table TABLE
(
SalesNo INTEGER NOT NULL,
DayOrderValue DOUBLE PRECISION NOT NULL DEFAULT(0),
DayOrderQty INTEGER NOT NULL DEFAULT(0),
Day_sales DOUBLE PRECISION NOT NULL DEFAULT(0),
Period_sales DOUBLE PRECISION NOT NULL DEFAULT(0),
Year_sales DOUBLE PRECISION NOT NULL DEFAULT(0),
Day_Cost DOUBLE PRECISION NOT NULL DEFAULT(0),
Period_Cost DOUBLE PRECISION NOT NULL DEFAULT(0),
Year_Cost DOUBLE PRECISION NOT NULL DEFAULT(0),
DayOrderValue_EXCLUDEQUOTES DOUBLE PRECISION NOT NULL DEFAULT(0),
DayOrderQty_EXCLUDEQUOTES INTEGER NOT NULL DEFAULT(0),
Day_sales_posttime DOUBLE PRECISION NOT NULL DEFAULT(0),
Period_sales_posttime DOUBLE PRECISION NOT NULL DEFAULT(0),
Year_sales_posttime DOUBLE PRECISION NOT NULL DEFAULT(0),
Day_Cost_posttime DOUBLE PRECISION NOT NULL DEFAULT(0),
Period_Cost_posttime DOUBLE PRECISION NOT NULL DEFAULT(0),
Year_Cost_posttime DOUBLE PRECISION NOT NULL DEFAULT(0),
Avg_DebtorDays DOUBLE PRECISION NOT NULL DEFAULT(0),
Avg_CreditorDays DOUBLE PRECISION NOT NULL DEFAULT(0) )
AS
BEGIN
Declare
@Period_StartDate datetime,
@Period_EndDate datetime,
@Period_YearStart datetime,
@Period_YearEnd datetime,
@Period_Name varchar(50),
@Period_Parent_seqno integer,
@sql_str varchar(max),
@sql_and varchar(max),
@CurrentDate datetime,
@Day_sales float,
@Period_sales float,
@Year_sales float,
@Day_Cost float,
@Period_Cost float,
@Year_Cost float,
@Range_enddate datetime,
@MinTranSeqno int

 insert into @Tmp_Table (salesno)
 select staffno from staff


set @currentdate = @MANREPDATE
set @Range_enddate = dateadd(day, 1, @CurrentDate)

-- Get Period Info
 SELECT @Period_StartDate=Period.StartDate, @Period_EndDate=Period.EndDate,
    @Period_YearStart=Period_Year.StartDate, @Period_YearEnd=Period_Year.EndDate,
    @Period_Name=Period.PERIOD_NAME,
@Period_Parent_seqno=Period.PARENT_PERIOD_SEQNO
 FROM MANREP_PERIOD Period
 LEFT JOIN MANREP_PERIOD Period_Year ON Period_Year.Period_SeqNo = Period.Parent_Period_SeqNo
 WHERE (Period.Period_SeqNo=@period_seqno)

 -- Get Orders for day
UPDATE T SET
   DayOrderValue = SUBQ.Totvalue,
   DayOrderQty = SUBQ.TotQty
 FROM
   @Tmp_Table T INNER JOIN
   (SELECT salesno, ISNULL(SUM(SUBTOTAL / EXCHRATE), 0) TotValue, Count(*) TotQty FROM SALESORD_HDR
WHERE (ORDERDATE=@currentdate)
AND NOT ((STATUS=2) AND (PROCESSFINALISATION = 1)) -- fully processed and deleted
AND NOT ((STATUS= 6) AND (PROCESSFINALISATION = 3)) -- lost quote
GROUP BY SALESNO
   )
AS SUBQ
ON T.salesno = SUBQ.salesno

 UPDATE T SET
   DayOrderValue_EXCLUDEQUOTES = SUBQ.Totvalue,
   DayOrderQty_EXCLUDEQUOTES = SUBQ.TotQty
 FROM
   @tmp_table T INNER JOIN
   (SELECT salesno, ISNULL(SUM(SUBTOTAL / EXCHRATE), 0) TotValue, Count(*) TotQty FROM SALESORD_HDR
WHERE (ORDERDATE=@currentdate)
AND (STATUS <> 3) -- not a quotation
AND NOT ((STATUS=2) AND (PROCESSFINALISATION = 1)) -- fully processed and deleted
AND NOT ((STATUS= 6) AND (PROCESSFINALISATION = 3)) -- lost quote
GROUP BY salesno
    )
AS SUBQ
ON T.salesno = SUBQ.salesno

-- Get Average Debtor Days
UPDATE T SET
   Avg_DebtorDays = SUBQ.total
 FROM
   @tmp_table T INNER JOIN
   (SELECT salesno, sum( cast(GetDate() - transdate as integer)) / count(*) total FROM DR_TRANS
WHERE (Dr_trans.TRANSTYPE=1)
AND (TRANSDATE <@CurrentDate) and (Allocated = '0')
group by salesno
    )
AS SUBQ
ON T.salesno = SUBQ.salesno

-- Get Average Creditor Days
UPDATE T SET
   Avg_CreditorDays = SUBQ.total
 FROM
   @tmp_table T INNER JOIN
   (SELECT salesno, sum( cast(GetDate() - transdate as integer)) / count(*) total FROM CR_TRANS
WHERE (CR_TRANS.TRANSTYPE=1)
AND (TRANSDATE <@CurrentDate) and (Allocated = '0')
group by salesno
   )
AS SUBQ
ON T.salesno = SUBQ.salesno
-- Get Year sales
UPDATE T SET
Year_sales_posttime = SUBQ.Totvalue
FROM
@tmp_table T INNER JOIN
(SELECT salesno, SUM(SUBTOTAL/EXCHRATE) Totvalue FROM DR_TRANS
left join period_status on dr_trans.period_seqno = period_status.seqno
WHERE (TRANSTYPE=1)
AND (POSTTIME between @Period_yearstart and @range_enddate)
group by DR_TRANS.salesno
)
AS SUBQ
ON T.salesno = SUBQ.salesno
UPDATE T SET
Year_sales = SUBQ.Totvalue
FROM
@tmp_table T INNER JOIN
(SELECT salesno, SUM(SUBTOTAL/EXCHRATE) Totvalue FROM DR_TRANS
left join period_status on dr_trans.period_seqno = period_status.seqno
WHERE (TRANSTYPE=1)
AND (TRANSDATE between @Period_yearstart and @CurrentDate)
group by DR_TRANS.salesno
)
AS SUBQ
ON T.salesno = SUBQ.salesno

-- Get Year cost
UPDATE T SET
Year_Cost_posttime = SUBQ.Totvalue
FROM
@tmp_table T INNER JOIN
(SELECT DR_TRANS.salesno, SUM(DR_INVLINES.QUANTITY*DR_INVLINES.UNITCOST) Totvalue
FROM DR_TRANS
LEFT JOIN DR_INVLINES ON DR_InvLines.Hdr_Seqno = DR_Trans.SeqNo
LEFT JOIN period_status ON dr_trans.period_seqno = period_status.SeqNo
WHERE (Dr_trans.TRANSTYPE=1)
AND (DR_TRANS.POSTTIME between @Period_YearStart and @Range_enddate)
group by DR_TRANS.salesno
)
AS SUBQ
ON T.salesno = SUBQ.salesno
UPDATE T SET
Year_Cost = SUBQ.Totvalue
FROM
@tmp_table T INNER JOIN
(SELECT DR_TRANS.salesno, SUM(DR_INVLINES.QUANTITY*DR_INVLINES.UNITCOST) Totvalue
FROM DR_TRANS
LEFT JOIN DR_INVLINES ON DR_InvLines.Hdr_Seqno = DR_Trans.SeqNo
LEFT JOIN period_status ON dr_trans.period_seqno = period_status.SeqNo
WHERE (Dr_trans.TRANSTYPE=1)
AND (DR_TRANS.TRANSDATE between @Period_YearStart and @CurrentDate)
group by DR_TRANS.salesno
)
AS SUBQ
ON T.salesno = SUBQ.salesno

 IF @CurrentPeriod = 'Y'
 Begin
SELECT @MinTranSeqno=MINTRANSEQNO
FROM PERIOD_STATUS PS
WHERE LEDGER ='D' AND PS.AGE = (SELECT ANALYSIS_AGE_LIMIT
FROM LEDGER_PERIODS LP
WHERE LP.SEQNO=1)
   SET @MinTranSeqno=ISNULL(@MinTranSeqNo, 0)
---- Get Day sales
UPDATE T SET
Day_sales_posttime = SUBQ.Totvalue
FROM
@tmp_table T INNER JOIN
(SELECT salesno, SUM(SUBTOTAL/EXCHRATE) Totvalue FROM DR_TRANS
left join period_status on dr_trans.period_seqno = period_status.seqno
WHERE (TRANSTYPE=1)
AND DR_TRANS.SEQNO >= @MinTranSeqno
AND (POSTTIME between @CurrentDate and @Range_enddate)
group by salesno
)
AS SUBQ
ON T.salesno = SUBQ.salesno
UPDATE T SET
Day_sales = SUBQ.Totvalue
FROM
@tmp_table T INNER JOIN
(SELECT salesno, SUM(SUBTOTAL/EXCHRATE) Totvalue FROM DR_TRANS
left join period_status on dr_trans.period_seqno = period_status.seqno
WHERE (TRANSTYPE=1)
AND (Period_status.AGE=0)
AND (TRANSDATE = @CurrentDate )
group by salesno
)
AS SUBQ
ON T.salesno = SUBQ.salesno
-- Get Period sales
UPDATE T SET
Period_sales_posttime = SUBQ.Totvalue
FROM
@tmp_table T INNER JOIN
(SELECT salesno, SUM(SUBTOTAL/EXCHRATE) Totvalue FROM DR_TRANS
left join period_status on dr_trans.period_seqno = period_status.seqno
WHERE (TRANSTYPE=1)
AND DR_TRANS.SEQNO >= @MinTranSeqno
AND (POSTTIME between @Period_StartDate and @range_enddate)
group by DR_TRANS.salesno
)
AS SUBQ
ON T.salesno = SUBQ.salesno
UPDATE T SET
Period_sales = SUBQ.Totvalue
FROM
@tmp_table T INNER JOIN
(SELECT salesno, SUM(SUBTOTAL/EXCHRATE) Totvalue FROM DR_TRANS
left join period_status on dr_trans.period_seqno = period_status.seqno
WHERE (TRANSTYPE=1)
AND (Period_status.AGE=0)
AND (TRANSDATE between @Period_StartDate and @CurrentDate)
group by DR_TRANS.salesno
)
AS SUBQ
ON T.salesno = SUBQ.salesno
-- Get Day cost
UPDATE T SET
Day_Cost_posttime = SUBQ.Totvalue
FROM
@tmp_table T INNER JOIN
(SELECT DR_TRANS.salesno, SUM(DR_INVLINES.QUANTITY*DR_INVLINES.UNITCOST) Totvalue
FROM DR_TRANS
LEFT JOIN DR_INVLINES ON DR_InvLines.Hdr_Seqno = DR_Trans.SeqNo
LEFT JOIN period_status ON dr_trans.period_seqno = period_status.SeqNo
WHERE (Dr_trans.TRANSTYPE=1)
AND DR_TRANS.SEQNO >= @MinTranSeqno
AND (DR_TRANS.POSTTIME between @CurrentDate and @Range_enddate)
group by DR_TRANS.salesno
)
AS SUBQ
ON T.salesno = SUBQ.salesno
UPDATE T SET
Day_Cost = SUBQ.Totvalue
FROM
@tmp_table T INNER JOIN
(SELECT DR_TRANS.salesno, SUM(DR_INVLINES.QUANTITY*DR_INVLINES.UNITCOST) Totvalue
FROM DR_TRANS
LEFT JOIN DR_INVLINES ON DR_InvLines.Hdr_Seqno = DR_Trans.SeqNo
LEFT JOIN period_status ON dr_trans.period_seqno = period_status.SeqNo
WHERE (Dr_trans.TRANSTYPE=1)
AND (Period_status.AGE=0)
AND (DR_TRANS.TRANSDATE = @CurrentDate )
group by DR_TRANS.salesno
)
AS SUBQ
ON T.salesno = SUBQ.salesno
-- Get Period cost
UPDATE T SET
Period_cost_posttime = SUBQ.Totvalue
FROM
@tmp_table T INNER JOIN
(SELECT DR_TRANS.salesno, SUM(DR_INVLINES.QUANTITY*DR_INVLINES.UNITCOST) Totvalue
FROM DR_TRANS
LEFT JOIN DR_INVLINES ON DR_InvLines.Hdr_Seqno = DR_Trans.SeqNo
LEFT JOIN period_status ON dr_trans.period_seqno = period_status.SeqNo
WHERE (Dr_trans.TRANSTYPE=1)
AND DR_TRANS.SEQNO >= @MinTranSeqno
AND (DR_TRANS.POSTTIME between @Period_StartDate and @Range_enddate)
group by DR_TRANS.salesno
)
AS SUBQ
ON T.salesno = SUBQ.salesno
UPDATE T SET
Period_cost = SUBQ.Totvalue
FROM
@tmp_table T INNER JOIN
(SELECT DR_TRANS.salesno, SUM(DR_INVLINES.QUANTITY*DR_INVLINES.UNITCOST) Totvalue
FROM DR_TRANS
LEFT JOIN DR_INVLINES ON DR_InvLines.Hdr_Seqno = DR_Trans.SeqNo
LEFT JOIN period_status ON dr_trans.period_seqno = period_status.SeqNo
WHERE (Dr_trans.TRANSTYPE=1)
AND (Period_status.AGE=0)
AND (DR_TRANS.TRANSDATE between @Period_StartDate and @CurrentDate)
group by DR_TRANS.salesno
)
AS SUBQ
ON T.salesno = SUBQ.salesno
end
else
begin
-- Get Day Sales
UPDATE T SET
Day_sales_posttime = SUBQ.Totvalue
FROM
@tmp_table T INNER JOIN
(SELECT salesno, SUM(SUBTOTAL/EXCHRATE) Totvalue FROM DR_TRANS
left join period_status on dr_trans.period_seqno = period_status.seqno
WHERE (TRANSTYPE=1)
AND (POSTTIME between @CurrentDate and @Range_enddate)
group by salesno
)
AS SUBQ
ON T.salesno = SUBQ.salesno
UPDATE T SET
Day_sales = SUBQ.Totvalue
FROM
@tmp_table T INNER JOIN
(SELECT salesno, SUM(SUBTOTAL/EXCHRATE) Totvalue FROM DR_TRANS
left join period_status on dr_trans.period_seqno = period_status.seqno
WHERE (TRANSTYPE=1)
AND (TRANSDATE = @CurrentDate )
group by salesno
)
AS SUBQ
ON T.salesno = SUBQ.salesno
-- Get Period sales
UPDATE T SET
Period_sales_posttime = SUBQ.Totvalue
FROM
@tmp_table T INNER JOIN
(SELECT salesno, SUM(SUBTOTAL/EXCHRATE) Totvalue FROM DR_TRANS
left join period_status on dr_trans.period_seqno = period_status.seqno
WHERE (TRANSTYPE=1)
AND (POSTTIME between @Period_StartDate and @range_enddate)
group by DR_TRANS.salesno
)
AS SUBQ
ON T.salesno = SUBQ.salesno
UPDATE T SET
Period_sales = SUBQ.Totvalue
FROM
@tmp_table T INNER JOIN
(SELECT salesno, SUM(SUBTOTAL/EXCHRATE) Totvalue FROM DR_TRANS
left join period_status on dr_trans.period_seqno = period_status.seqno
WHERE (TRANSTYPE=1)
AND (TRANSDATE between @Period_StartDate and @CurrentDate)
group by DR_TRANS.salesno
)
AS SUBQ
ON T.salesno = SUBQ.salesno
-- Get Day cost
UPDATE T SET
Day_Cost_posttime = SUBQ.Totvalue
FROM
@tmp_table T INNER JOIN
(SELECT DR_TRANS.salesno, SUM(DR_INVLINES.QUANTITY*DR_INVLINES.UNITCOST) Totvalue
FROM DR_TRANS
LEFT JOIN DR_INVLINES ON DR_InvLines.Hdr_Seqno = DR_Trans.SeqNo
LEFT JOIN period_status ON dr_trans.period_seqno = period_status.SeqNo
WHERE (Dr_trans.TRANSTYPE=1)
AND (DR_TRANS.POSTTIME between @CurrentDate and @Range_enddate)
group by DR_TRANS.salesno
)
AS SUBQ
ON T.salesno = SUBQ.salesno
UPDATE T SET
Day_Cost = SUBQ.Totvalue
FROM
@tmp_table T INNER JOIN
(SELECT DR_TRANS.salesno, SUM(DR_INVLINES.QUANTITY*DR_INVLINES.UNITCOST) Totvalue
FROM DR_TRANS
LEFT JOIN DR_INVLINES ON DR_InvLines.Hdr_Seqno = DR_Trans.SeqNo
LEFT JOIN period_status ON dr_trans.period_seqno = period_status.SeqNo
WHERE (Dr_trans.TRANSTYPE=1)
AND (DR_TRANS.TRANSDATE = @CurrentDate )
group by DR_TRANS.salesno
)
AS SUBQ
ON T.salesno = SUBQ.salesno
-- Get Period cost
UPDATE T SET
Period_cost_posttime = SUBQ.Totvalue
FROM
@tmp_table T INNER JOIN
(SELECT DR_TRANS.salesno, SUM(DR_INVLINES.QUANTITY*DR_INVLINES.UNITCOST) Totvalue
FROM DR_TRANS
LEFT JOIN DR_INVLINES ON DR_InvLines.Hdr_Seqno = DR_Trans.SeqNo
LEFT JOIN period_status ON dr_trans.period_seqno = period_status.SeqNo
WHERE (Dr_trans.TRANSTYPE=1)
AND (DR_TRANS.POSTTIME between @Period_StartDate and @Range_enddate)
group by DR_TRANS.salesno
)
AS SUBQ
ON T.salesno = SUBQ.salesno
UPDATE T SET
Period_cost = SUBQ.Totvalue
FROM
@tmp_table T INNER JOIN
(SELECT DR_TRANS.salesno, SUM(DR_INVLINES.QUANTITY*DR_INVLINES.UNITCOST) Totvalue
FROM DR_TRANS
LEFT JOIN DR_INVLINES ON DR_InvLines.Hdr_Seqno = DR_Trans.SeqNo
LEFT JOIN period_status ON dr_trans.period_seqno = period_status.SeqNo
WHERE (Dr_trans.TRANSTYPE=1)
AND (DR_TRANS.TRANSDATE between @Period_StartDate and @CurrentDate)
group by DR_TRANS.salesno
)
AS SUBQ
ON T.salesno = SUBQ.salesno
end
RETURN
END


Procedure: FN_RESTRICTED_ITEM
NameFN_RESTRICTED_ITEM
Note
Code-- =============================================================
-- Create date: 06-06-2012
-- Description: Function [dbo].[FN_RESTRICTED_ITEM] is a replacement for
-- the existing stock restriction functionality in
-- EXO Business. This function works in conjunction
-- with profile CUSTOM_STOCK_RESTRICTION. Without
-- any changes to this function, the result will be
-- the same as existing stock restriction
-- functionality.
-- Parameters: StockCode, Accno, HeadAccno, LocNo, BranchNo,
-- SalesNo and StaffNo
-- =============================================================
CREATE FUNCTION [FN_RESTRICTED_ITEM](@STOCKCODE VARCHAR(23),
                                     @ACCNO INT,
                                     @HEADACCNO INT = -1,
                                     @LOCNO INT = -1,
                                     @BRANCHNO INT = -1,
                                     @SALESNO INT = -1,
                                     @STAFFNO INT = -1 )
RETURNS CHAR(1)
AS
BEGIN
DECLARE @RESTRICTED_ITEM CHAR(1),
@ALLOW_RESTRICTED_STOCK CHAR(1)

SELECT @ALLOW_RESTRICTED_STOCK = ALLOW_RESTRICTED_STOCK
FROM DR_ACCS
WHERE ACCNO = @ACCNO

SELECT @RESTRICTED_ITEM = STOCK_ITEMS.RESTRICTED_ITEM
FROM STOCK_ITEMS
WHERE STOCKCODE = @STOCKCODE

RETURN
(SELECT
CASE
WHEN @ACCNO = -1 THEN @RESTRICTED_ITEM
WHEN @ALLOW_RESTRICTED_STOCK = 'N' AND @RESTRICTED_ITEM = 'Y' THEN 'Y'
ELSE 'N'
END)
END


Procedure: FN_SHOW_AS_PERCENT
NameFN_SHOW_AS_PERCENT
Note
Code-- ============================================================
-- Create date: 13-03-2012
-- Description: Returns text value in Percentage Formatting
-- calling this function
-- IT ACCEPTS PERCENTAGE VALUE AS A PARAMETER WHERE
-- IT RETURNS TEXT IN PERCENTAGE FORMAT
-- ============================================================
CREATE FUNCTION [dbo].[FN_SHOW_AS_PERCENT] (@PERCENT DECIMAL)
RETURNS VARCHAR(10)
AS
BEGIN
DECLARE @PERCENT_STR VARCHAR(10)
SET @PERCENT_STR = CONVERT(VARCHAR(10), CONVERT(DECIMAL(5, 2), @PERCENT)) + '%'
RETURN @PERCENT_STR
END


Procedure: FN_STOCK_REQUIREMENT
NameFN_STOCK_REQUIREMENT
Note
Code-- =============================================
-- AUTHOR: MASHA BATRA
-- CREATE DATE: DECEMBER 2, 2010
-- DESCRIPTION: COMPUTES THE STOCK LEVELS, SALES IN PAST 12 MONTHS AND REORDER VALUES FOR
-- ALL STOCK ITEMS AND LOCATIONS FOR EITHER ONE OR ALL SUPPLIERS.
-- TAKES IN SUPPLIERNO, MAX FWD DAYS PROFILES FOR SO, PO AND WO AND USER WORKS ORDER FLAG
-- Added EXCLUDEDFROMFREESTOCK as distinct from NOSALELOCATION and this affects the free stock figures (eg for WIP locations)
-- =============================================
CREATE FUNCTION [dbo].[FN_STOCK_REQUIREMENT]
(
@SUPPLIERNO INTEGER = -1,
@MAXFWDDAYS INT,
@PO_MAXFWDDAYS INT,
@WO_MAXFWDDAYS INT,
@USEWORKSORDS CHAR(1)
)
RETURNS
  @TMP_STOCK_LEVELS
  TABLE (
STOCKCODE VARCHAR(23),
LOCNO INTEGER NOT NULL,
[DESCRIPTION] VARCHAR(256),
ACCNO INTEGER,
STOCKGROUP INTEGER,
ISINLOC DOUBLE PRECISION NOT NULL DEFAULT(0),
ISFREE DOUBLE PRECISION NOT NULL DEFAULT(0),
ISCOMMITTED DOUBLE PRECISION NOT NULL DEFAULT(0),
ISINCOMING DOUBLE PRECISION NOT NULL DEFAULT(0),
ONBACKORDER DOUBLE PRECISION NOT NULL DEFAULT(0),
ISNOTFORSALE DOUBLE PRECISION NOT NULL DEFAULT(0),
RELEASED DOUBLE PRECISION NOT NULL DEFAULT(0),
PICKED DOUBLE PRECISION NOT NULL DEFAULT(0),
NOSALELOCATION CHAR(1) NOT NULL DEFAULT('N'),
EXCLUDEDFROMFREESTOCK CHAR(1) NOT NULL DEFAULT('N'),
CORRECTED DOUBLE PRECISION NOT NULL DEFAULT(0),
SUPPLIED DOUBLE PRECISION NOT NULL DEFAULT(0),
UNCOSTED DOUBLE PRECISION NOT NULL DEFAULT(0),
MINSTOCK DOUBLE PRECISION NOT NULL DEFAULT(0),
MAXSTOCK DOUBLE PRECISION NOT NULL DEFAULT(0),
BINCODE VARCHAR(12),
WOUT DOUBLE PRECISION NOT NULL DEFAULT(0),
WIN DOUBLE PRECISION NOT NULL DEFAULT(0),
SO DOUBLE PRECISION NOT NULL DEFAULT(0),
PO DOUBLE PRECISION NOT NULL DEFAULT(0),
M0_SALES DOUBLE PRECISION NOT NULL DEFAULT(0),
M1_SALES DOUBLE PRECISION NOT NULL DEFAULT(0),
M2_SALES DOUBLE PRECISION NOT NULL DEFAULT(0),
M3_SALES DOUBLE PRECISION NOT NULL DEFAULT(0),
M4_SALES DOUBLE PRECISION NOT NULL DEFAULT(0),
M5_SALES DOUBLE PRECISION NOT NULL DEFAULT(0),
M6_SALES DOUBLE PRECISION NOT NULL DEFAULT(0),
M7_SALES DOUBLE PRECISION NOT NULL DEFAULT(0),
M8_SALES DOUBLE PRECISION NOT NULL DEFAULT(0),
M9_SALES DOUBLE PRECISION NOT NULL DEFAULT(0),
M10_SALES DOUBLE PRECISION NOT NULL DEFAULT(0),
M11_SALES DOUBLE PRECISION NOT NULL DEFAULT(0),
M12_SALES DOUBLE PRECISION NOT NULL DEFAULT(0),
CALCREORD DOUBLE PRECISION NOT NULL DEFAULT(0),
ACTUALREORD DOUBLE PRECISION NOT NULL DEFAULT(0)
)
AS

BEGIN
  -- PREPOPULATE WITH STUFF WHICH DOESNT REQUIRE AGGREGATION
  IF (@SUPPLIERNO < 0)
  BEGIN
INSERT INTO @TMP_STOCK_LEVELS (STOCKCODE, LOCNO, [DESCRIPTION], ACCNO, STOCKGROUP,
ISINLOC, MINSTOCK, MAXSTOCK, BINCODE, NOSALELOCATION, EXCLUDEDFROMFREESTOCK,
M0_SALES, M1_SALES, M2_SALES, M3_SALES, M4_SALES, M5_SALES, M6_SALES, M7_SALES,
M8_SALES, M9_SALES, M10_SALES, M11_SALES, M12_SALES)
SELECT S.STOCKCODE, L.LOCNO, S.[DESCRIPTION], S.SUPPLIERNO, S.STOCKGROUP,
ISNULL(I.QTY, 0), ISNULL(I.MINSTOCK, 0), ISNULL(I.MAXSTOCK, 0), I.BINCODE, L.EXCLUDE_FROMSALES, L.EXCLUDE_FROMFREE_STOCK,
ISNULL(M0.SALES, 0) AS M0_SALES, ISNULL(M1.SALES, 0) AS M1_SALES, ISNULL(M2.SALES, 0) AS M2_SALES,
ISNULL(M3.SALES, 0) AS M3_SALES, ISNULL(M4.SALES, 0) AS M4_SALES, ISNULL(M5.SALES, 0) AS M5_SALES,
ISNULL(M6.SALES, 0) AS M6_SALES, ISNULL(M7.SALES, 0) AS M7_SALES, ISNULL(M8.SALES, 0) AS M8_SALES,
ISNULL(M9.SALES, 0) AS M9_SALES, ISNULL(M10.SALES, 0) AS M10_SALES, ISNULL(M11.SALES, 0) AS M11_SALES,
ISNULL(M12.SALES, 0) AS M12_SALES
FROM STOCK_ITEMS S RIGHT JOIN STOCK_LOC_INFO I ON S.STOCKCODE = I.STOCKCODE
INNER JOIN STOCK_LOCATIONS L ON I.LOCATION = L.LOCNO AND L.ISACTIVE = 'Y'
LEFT OUTER JOIN
(SELECT S.STOCKCODE, S.LOCATION, SUM(S.QUANTITY) * -1 SALES FROM STOCK_TRANS S
JOIN PERIOD_STATUS PS ON S.PERIOD_SEQNO=PS.SEQNO
WHERE PS.LEDGER='S' AND PS.AGE=0 AND S.TRANSTYPE = 0
GROUP BY S.STOCKCODE, S.LOCATION, PS.AGE) M0
ON S.STOCKCODE=M0.STOCKCODE AND L.LOCNO=M0.LOCATION
LEFT OUTER JOIN
(SELECT S.STOCKCODE, S.LOCATION, SUM(S.QUANTITY) * -1 SALES FROM STOCK_TRANS S
JOIN PERIOD_STATUS PS ON S.PERIOD_SEQNO=PS.SEQNO
WHERE PS.LEDGER='S' AND PS.AGE=1 AND S.TRANSTYPE = 0
GROUP BY S.STOCKCODE, S.LOCATION, PS.AGE) M1
ON S.STOCKCODE=M1.STOCKCODE AND L.LOCNO=M1.LOCATION
LEFT OUTER JOIN
(SELECT S.STOCKCODE, S.LOCATION, SUM(S.QUANTITY) * -1 SALES FROM STOCK_TRANS S
JOIN PERIOD_STATUS PS ON S.PERIOD_SEQNO=PS.SEQNO
WHERE PS.LEDGER='S' AND PS.AGE=2 AND S.TRANSTYPE = 0
GROUP BY S.STOCKCODE, S.LOCATION, PS.AGE) M2
ON S.STOCKCODE=M2.STOCKCODE AND L.LOCNO=M2.LOCATION
LEFT OUTER JOIN
(SELECT S.STOCKCODE, S.LOCATION, SUM(S.QUANTITY) * -1 SALES FROM STOCK_TRANS S
JOIN PERIOD_STATUS PS ON S.PERIOD_SEQNO=PS.SEQNO
WHERE PS.LEDGER='S' AND PS.AGE=3 AND S.TRANSTYPE = 0
GROUP BY S.STOCKCODE, S.LOCATION, PS.AGE) M3
ON S.STOCKCODE=M3.STOCKCODE AND L.LOCNO=M3.LOCATION
LEFT OUTER JOIN
(SELECT S.STOCKCODE, S.LOCATION, SUM(S.QUANTITY) * -1 SALES FROM STOCK_TRANS S
JOIN PERIOD_STATUS PS ON S.PERIOD_SEQNO=PS.SEQNO
WHERE PS.LEDGER='S' AND PS.AGE=4 AND S.TRANSTYPE = 0
GROUP BY S.STOCKCODE, S.LOCATION, PS.AGE) M4
ON S.STOCKCODE=M4.STOCKCODE AND L.LOCNO=M4.LOCATION
LEFT OUTER JOIN
(SELECT S.STOCKCODE, S.LOCATION, SUM(S.QUANTITY) * -1 SALES FROM STOCK_TRANS S
JOIN PERIOD_STATUS PS ON S.PERIOD_SEQNO=PS.SEQNO
WHERE PS.LEDGER='S' AND PS.AGE=5 AND S.TRANSTYPE = 0
GROUP BY S.STOCKCODE, S.LOCATION, PS.AGE) M5
ON S.STOCKCODE=M5.STOCKCODE AND L.LOCNO=M5.LOCATION
LEFT OUTER JOIN
(SELECT S.STOCKCODE, S.LOCATION, SUM(S.QUANTITY) * -1 SALES FROM STOCK_TRANS S
JOIN PERIOD_STATUS PS ON S.PERIOD_SEQNO=PS.SEQNO
WHERE PS.LEDGER='S' AND PS.AGE=6 AND S.TRANSTYPE = 0
GROUP BY S.STOCKCODE, S.LOCATION, PS.AGE) M6
ON S.STOCKCODE=M6.STOCKCODE AND L.LOCNO=M6.LOCATION
LEFT OUTER JOIN
(SELECT S.STOCKCODE, S.LOCATION, SUM(S.QUANTITY) * -1 SALES FROM STOCK_TRANS S
JOIN PERIOD_STATUS PS ON S.PERIOD_SEQNO=PS.SEQNO
WHERE PS.LEDGER='S' AND PS.AGE=7 AND S.TRANSTYPE = 0
GROUP BY S.STOCKCODE, S.LOCATION, PS.AGE) M7
ON S.STOCKCODE=M7.STOCKCODE AND L.LOCNO=M7.LOCATION
LEFT OUTER JOIN
(SELECT S.STOCKCODE, S.LOCATION, SUM(S.QUANTITY) * -1 SALES FROM STOCK_TRANS S
JOIN PERIOD_STATUS PS ON S.PERIOD_SEQNO=PS.SEQNO
WHERE PS.LEDGER='S' AND PS.AGE=8 AND S.TRANSTYPE = 0
GROUP BY S.STOCKCODE, S.LOCATION, PS.AGE) M8
ON S.STOCKCODE=M8.STOCKCODE AND L.LOCNO=M8.LOCATION
LEFT OUTER JOIN
(SELECT S.STOCKCODE, S.LOCATION, SUM(S.QUANTITY) * -1 SALES FROM STOCK_TRANS S
JOIN PERIOD_STATUS PS ON S.PERIOD_SEQNO=PS.SEQNO
WHERE PS.LEDGER='S' AND PS.AGE=9 AND S.TRANSTYPE = 0
GROUP BY S.STOCKCODE, S.LOCATION, PS.AGE) M9
ON S.STOCKCODE=M9.STOCKCODE AND L.LOCNO=M9.LOCATION
LEFT OUTER JOIN
(SELECT S.STOCKCODE, S.LOCATION, SUM(S.QUANTITY) * -1 SALES FROM STOCK_TRANS S
JOIN PERIOD_STATUS PS ON S.PERIOD_SEQNO=PS.SEQNO
WHERE PS.LEDGER='S' AND PS.AGE=10 AND S.TRANSTYPE = 0
GROUP BY S.STOCKCODE, S.LOCATION, PS.AGE) M10
ON S.STOCKCODE=M10.STOCKCODE AND L.LOCNO=M10.LOCATION
LEFT OUTER JOIN
(SELECT S.STOCKCODE, S.LOCATION, SUM(S.QUANTITY) * -1 SALES FROM STOCK_TRANS S
JOIN PERIOD_STATUS PS ON S.PERIOD_SEQNO=PS.SEQNO
WHERE PS.LEDGER='S' AND PS.AGE=11 AND S.TRANSTYPE = 0
GROUP BY S.STOCKCODE, S.LOCATION, PS.AGE) M11
ON S.STOCKCODE=M11.STOCKCODE AND L.LOCNO=M11.LOCATION
LEFT OUTER JOIN
(SELECT S.STOCKCODE, S.LOCATION, SUM(S.QUANTITY) * -1 SALES FROM STOCK_TRANS S
JOIN PERIOD_STATUS PS ON S.PERIOD_SEQNO=PS.SEQNO
WHERE PS.LEDGER='S' AND PS.AGE=12 AND S.TRANSTYPE = 0
GROUP BY S.STOCKCODE, S.LOCATION, PS.AGE) M12
ON S.STOCKCODE=M12.STOCKCODE AND L.LOCNO=M12.LOCATION
WHERE (S.ISACTIVE = 'Y')
AND (S.STATUS<>'L')
  END
  ELSE
  BEGIN
INSERT INTO @TMP_STOCK_LEVELS (STOCKCODE, LOCNO, [DESCRIPTION], ACCNO, STOCKGROUP,
ISINLOC, MINSTOCK, MAXSTOCK, BINCODE, NOSALELOCATION, EXCLUDEDFROMFREESTOCK
, M0_SALES, M1_SALES , M2_SALES , M3_SALES , M4_SALES , M5_SALES , M6_SALES , M7_SALES ,
M8_SALES , M9_SALES , M10_SALES , M11_SALES , M12_SALES )
SELECT S.STOCKCODE, L.LOCNO, S.[DESCRIPTION], S.SUPPLIERNO, S.STOCKGROUP,
ISNULL(I.QTY, 0), ISNULL(I.MINSTOCK, 0), ISNULL(I.MAXSTOCK, 0), I.BINCODE, L.EXCLUDE_FROMSALES, L.EXCLUDE_FROMFREE_STOCK,
ISNULL(M0.SALES, 0) AS M0_SALES, ISNULL(M1.SALES, 0) AS M1_SALES, ISNULL(M2.SALES, 0) AS M2_SALES,
ISNULL(M3.SALES, 0) AS M3_SALES, ISNULL(M4.SALES, 0) AS M4_SALES, ISNULL(M5.SALES, 0) AS M5_SALES,
ISNULL(M6.SALES, 0) AS M6_SALES, ISNULL(M7.SALES, 0) AS M7_SALES, ISNULL(M8.SALES, 0) AS M8_SALES,
ISNULL(M9.SALES, 0) AS M9_SALES, ISNULL(M10.SALES, 0) AS M10_SALES, ISNULL(M11.SALES, 0) AS M11_SALES,
ISNULL(M12.SALES, 0) AS M12_SALES
FROM STOCK_ITEMS S RIGHT JOIN STOCK_LOC_INFO I ON S.STOCKCODE = I.STOCKCODE
INNER JOIN STOCK_LOCATIONS L ON I.LOCATION = L.LOCNO AND L.ISACTIVE = 'Y'
LEFT OUTER JOIN
(SELECT S.STOCKCODE, S.LOCATION, SUM(S.QUANTITY) * -1 SALES FROM STOCK_TRANS S
JOIN PERIOD_STATUS PS ON S.PERIOD_SEQNO=PS.SEQNO
WHERE PS.LEDGER='S' AND PS.AGE=0 AND S.TRANSTYPE = 0
GROUP BY S.STOCKCODE, S.LOCATION, PS.AGE) M0
ON S.STOCKCODE=M0.STOCKCODE AND L.LOCNO=M0.LOCATION
LEFT OUTER JOIN
(SELECT S.STOCKCODE, S.LOCATION, SUM(S.QUANTITY) * -1 SALES FROM STOCK_TRANS S
JOIN PERIOD_STATUS PS ON S.PERIOD_SEQNO=PS.SEQNO
WHERE PS.LEDGER='S' AND PS.AGE=1 AND S.TRANSTYPE = 0
GROUP BY S.STOCKCODE, S.LOCATION, PS.AGE) M1
ON S.STOCKCODE=M1.STOCKCODE AND L.LOCNO=M1.LOCATION
LEFT OUTER JOIN
(SELECT S.STOCKCODE, S.LOCATION, SUM(S.QUANTITY) * -1 SALES FROM STOCK_TRANS S
JOIN PERIOD_STATUS PS ON S.PERIOD_SEQNO=PS.SEQNO
WHERE PS.LEDGER='S' AND PS.AGE=2 AND S.TRANSTYPE = 0
GROUP BY S.STOCKCODE, S.LOCATION, PS.AGE) M2
ON S.STOCKCODE=M2.STOCKCODE AND L.LOCNO=M2.LOCATION
LEFT OUTER JOIN
(SELECT S.STOCKCODE, S.LOCATION, SUM(S.QUANTITY) * -1 SALES FROM STOCK_TRANS S
JOIN PERIOD_STATUS PS ON S.PERIOD_SEQNO=PS.SEQNO
WHERE PS.LEDGER='S' AND PS.AGE=3 AND S.TRANSTYPE = 0
GROUP BY S.STOCKCODE, S.LOCATION, PS.AGE) M3
ON S.STOCKCODE=M3.STOCKCODE AND L.LOCNO=M3.LOCATION
LEFT OUTER JOIN
(SELECT S.STOCKCODE, S.LOCATION, SUM(S.QUANTITY) * -1 SALES FROM STOCK_TRANS S
JOIN PERIOD_STATUS PS ON S.PERIOD_SEQNO=PS.SEQNO
WHERE PS.LEDGER='S' AND PS.AGE=4 AND S.TRANSTYPE = 0
GROUP BY S.STOCKCODE, S.LOCATION, PS.AGE) M4
ON S.STOCKCODE=M4.STOCKCODE AND L.LOCNO=M4.LOCATION
LEFT OUTER JOIN
(SELECT S.STOCKCODE, S.LOCATION, SUM(S.QUANTITY) * -1 SALES FROM STOCK_TRANS S
JOIN PERIOD_STATUS PS ON S.PERIOD_SEQNO=PS.SEQNO
WHERE PS.LEDGER='S' AND PS.AGE=5 AND S.TRANSTYPE = 0
GROUP BY S.STOCKCODE, S.LOCATION, PS.AGE) M5
ON S.STOCKCODE=M5.STOCKCODE AND L.LOCNO=M5.LOCATION
LEFT OUTER JOIN
(SELECT S.STOCKCODE, S.LOCATION, SUM(S.QUANTITY) * -1 SALES FROM STOCK_TRANS S
JOIN PERIOD_STATUS PS ON S.PERIOD_SEQNO=PS.SEQNO
WHERE PS.LEDGER='S' AND PS.AGE=6 AND S.TRANSTYPE = 0
GROUP BY S.STOCKCODE, S.LOCATION, PS.AGE) M6
ON S.STOCKCODE=M6.STOCKCODE AND L.LOCNO=M6.LOCATION
LEFT OUTER JOIN
(SELECT S.STOCKCODE, S.LOCATION, SUM(S.QUANTITY) * -1 SALES FROM STOCK_TRANS S
JOIN PERIOD_STATUS PS ON S.PERIOD_SEQNO=PS.SEQNO
WHERE PS.LEDGER='S' AND PS.AGE=7 AND S.TRANSTYPE = 0
GROUP BY S.STOCKCODE, S.LOCATION, PS.AGE) M7
ON S.STOCKCODE=M7.STOCKCODE AND L.LOCNO=M7.LOCATION
LEFT OUTER JOIN
(SELECT S.STOCKCODE, S.LOCATION, SUM(S.QUANTITY) * -1 SALES FROM STOCK_TRANS S
JOIN PERIOD_STATUS PS ON S.PERIOD_SEQNO=PS.SEQNO
WHERE PS.LEDGER='S' AND PS.AGE=8 AND S.TRANSTYPE = 0
GROUP BY S.STOCKCODE, S.LOCATION, PS.AGE) M8
ON S.STOCKCODE=M8.STOCKCODE AND L.LOCNO=M8.LOCATION
LEFT OUTER JOIN
(SELECT S.STOCKCODE, S.LOCATION, SUM(S.QUANTITY) * -1 SALES FROM STOCK_TRANS S
JOIN PERIOD_STATUS PS ON S.PERIOD_SEQNO=PS.SEQNO
WHERE PS.LEDGER='S' AND PS.AGE=9 AND S.TRANSTYPE = 0
GROUP BY S.STOCKCODE, S.LOCATION, PS.AGE) M9
ON S.STOCKCODE=M9.STOCKCODE AND L.LOCNO=M9.LOCATION
LEFT OUTER JOIN
(SELECT S.STOCKCODE, S.LOCATION, SUM(S.QUANTITY) * -1 SALES FROM STOCK_TRANS S
JOIN PERIOD_STATUS PS ON S.PERIOD_SEQNO=PS.SEQNO
WHERE PS.LEDGER='S' AND PS.AGE=10 AND S.TRANSTYPE = 0
GROUP BY S.STOCKCODE, S.LOCATION, PS.AGE) M10
ON S.STOCKCODE=M10.STOCKCODE AND L.LOCNO=M10.LOCATION
LEFT OUTER JOIN
(SELECT S.STOCKCODE, S.LOCATION, SUM(S.QUANTITY) * -1 SALES FROM STOCK_TRANS S
JOIN PERIOD_STATUS PS ON S.PERIOD_SEQNO=PS.SEQNO
WHERE PS.LEDGER='S' AND PS.AGE=11 AND S.TRANSTYPE = 0
GROUP BY S.STOCKCODE, S.LOCATION, PS.AGE) M11
ON S.STOCKCODE=M11.STOCKCODE AND L.LOCNO=M11.LOCATION
LEFT OUTER JOIN
(SELECT S.STOCKCODE, S.LOCATION, SUM(S.QUANTITY) * -1 SALES FROM STOCK_TRANS S
JOIN PERIOD_STATUS PS ON S.PERIOD_SEQNO=PS.SEQNO
WHERE PS.LEDGER='S' AND PS.AGE=12 AND S.TRANSTYPE = 0
GROUP BY S.STOCKCODE, S.LOCATION, PS.AGE) M12
ON S.STOCKCODE=M12.STOCKCODE AND L.LOCNO=M12.LOCATION
WHERE (S.ISACTIVE = 'Y')
AND (S.STATUS<>'L')
AND S.SUPPLIERNO = @SUPPLIERNO

  END

  -- UPDATE RESULTS WITH AGGREGATED VALUES
  -- WORKS ORDERS
  IF (@USEWORKSORDS = 'Y')
  BEGIN
    UPDATE T SET
            WOUT = SUBQ.QTY
    FROM @TMP_STOCK_LEVELS T INNER JOIN
         (SELECT L.STOCKCODE AS STOCKCODE, H.COMPONENTLOCNO AS LOCNO, ISNULL(SUM(L.QTYREQD-L.QTYUSED), 0) AS QTY
FROM WORKSORD_LINES L, WORKSORD_HDR H
WHERE (L.HDR_SEQNO=H.SEQNO)
AND (H.DUEDATE<=GETDATE()+@WO_MAXFWDDAYS)
AND (H.ORDSTATUS BETWEEN 1 AND 2)
GROUP BY L.STOCKCODE, H.COMPONENTLOCNO) AS SUBQ ON T.LOCNO = SUBQ.LOCNO AND T.STOCKCODE= SUBQ.STOCKCODE

    UPDATE T SET
            WIN = SUBQ.QTY
    FROM @TMP_STOCK_LEVELS T INNER JOIN
         (SELECT PRODCODE AS STOCKCODE, PRODLOCNO AS LOCNO, ISNULL(SUM(PRODQTY-ACTUALQTY), 0) AS QTY
FROM WORKSORD_HDR
WHERE (ORDSTATUS BETWEEN 1 AND 2)
AND (DUEDATE<=GETDATE()+@WO_MAXFWDDAYS)
GROUP BY PRODCODE, PRODLOCNO) AS SUBQ ON T.LOCNO = SUBQ.LOCNO AND T.STOCKCODE = SUBQ.STOCKCODE
  END

  --SALES ORDERS
  UPDATE T SET
    RELEASED = SUBQ.RELEASED,
    PICKED = SUBQ.PICKED,
    CORRECTED = SUBQ.CORRECTED,
    SO = SUBQ.SO,
    ONBACKORDER = SUBQ.ONBACKORDER,
    SUPPLIED = SUBQ.SUPPLIED
  FROM @TMP_STOCK_LEVELS T INNER JOIN
      (SELECT L.LINKED_STOCKCODE AS STOCKCODE,
L.LOCATION AS LOCNO,
RELEASED = ISNULL(SUM((L.RELEASE_QUANT+L.RELEASE_NOW)*L.LINKED_QTY), 0),
PICKED = ISNULL(SUM((L.PICKED_QUANT+L.PICK_NOW)*L.LINKED_QTY), 0),
CORRECTED = ISNULL(SUM(L.CORRECTED_QUANT*L.LINKED_QTY), 0),
SO = ISNULL(SUM(L.UNSUP_QUANT * L.LINKED_QTY), 0),
ONBACKORDER = ISNULL(SUM(L.BKORD_QUANT * L.LINKED_QTY), 0),
SUPPLIED = ISNULL(SUM((L.SUP_QUANT+L.SUPPLY_NOW) * L.LINKED_QTY), 0)
FROM SALESORD_LINES L INNER JOIN SALESORD_HDR H ON L.HDR_SEQNO = H.SEQNO
WHERE ((L.HDR_STATUS<2) OR (L.HDR_STATUS BETWEEN 4 AND 5))
AND (H.DUEDATE<=GETDATE()+@MAXFWDDAYS)
GROUP BY L.LINKED_STOCKCODE, L.LOCATION) AS SUBQ ON T.LOCNO = SUBQ.LOCNO AND T.STOCKCODE= SUBQ.STOCKCODE

  -- PURCHASE ORDERS
  UPDATE T SET
      PO = SUBQ.PO,
      UNCOSTED = SUBQ.UNCOSTED
  FROM
      @TMP_STOCK_LEVELS T INNER JOIN
      ( SELECT L.LINKED_STOCKCODE AS STOCKCODE, L.LOCATION AS LOCNO,
PO = ISNULL(SUM(((L.ORD_QUANT-L.CORRECTION_QUANT)-L.COST_QUANT) * L.LINKED_QTY), 0),
UNCOSTED = ISNULL(SUM((L.SUP_QUANT-L.COST_QUANT) * L.LINKED_QTY), 0)
FROM PURCHORD_LINES L INNER JOIN PURCHORD_HDR H ON (L.HDR_SEQNO=H.SEQNO)
WHERE (H.DUEDATE<=GETDATE()+@PO_MAXFWDDAYS) AND (H.STATUS<2)
GROUP BY L.LINKED_STOCKCODE, L.LOCATION ) AS SUBQ ON T.LOCNO = SUBQ.LOCNO AND T.STOCKCODE= SUBQ.STOCKCODE


  UPDATE
      @TMP_STOCK_LEVELS
  SET
      ISCOMMITTED = SO + WOUT,
      ISINCOMING = PO + WIN,
      ISNOTFORSALE = CASE WHEN NOSALELOCATION /*Exclude from sales*/ = 'Y' THEN ISINLOC + SO - WOUT + PO + WIN ELSE 0 END,
      ISFREE = CASE WHEN EXCLUDEDFROMFREESTOCK /*Exclude from freestock*/ = 'Y' THEN 0 ELSE ISINLOC - SO - WOUT + PO + WIN END


  UPDATE
      @TMP_STOCK_LEVELS
  SET
      CALCREORD = CASE WHEN ISFREE <= MINSTOCK THEN MAXSTOCK - ISFREE ELSE 0 END,
ACTUALREORD = CASE WHEN ISFREE <= MINSTOCK THEN MAXSTOCK - ISFREE ELSE 0 END


  RETURN
END


Procedure: FN_ValidateABN
NameFN_ValidateABN
Note
CodeCREATE FUNCTION [dbo].[FN_ValidateABN] (@TAXREG VARCHAR(30)) RETURNS CHAR
AS
BEGIN
SELECT @TAXREG = REPLACE(@TAXREG, ' ', '')-- Strip out any spaces in ABN
SELECT @TAXREG = REPLACE(@TAXREG, '-', '')-- Strip out any dashes in ABN
DECLARE @IsValid CHAR
DECLARE @CH1 INT
DECLARE @CH2 INT
DECLARE @CH3 INT
DECLARE @CH4 INT
DECLARE @CH5 INT
DECLARE @CH6 INT
DECLARE @CH7 INT
DECLARE @CH8 INT
DECLARE @CH9 INT
DECLARE @CH10 INT
DECLARE @CH11 INT
DECLARE @RESULT INT
DECLARE @CHECKCALC INT
SET @IsValid = 'N'
IF Len(@TAXREG) = 11 AND IsNumeric(@TAXREG) = 1
BEGIN /*Divide the string by character position and apply weighting formula then check result*/
SET @CH1 = ( LEFT(@TAXREG, 1) - 1 ) * 10
SET @CH2 = Substring(@TAXREG, 2, 1) * 1
SET @CH3 = Substring(@TAXREG, 3, 1) * 3
SET @CH4 = Substring(@TAXREG, 4, 1) * 5
SET @CH5 = Substring(@TAXREG, 5, 1) * 7
SET @CH6 = Substring(@TAXREG, 6, 1) * 9
SET @CH7 = Substring(@TAXREG, 7, 1) * 11
SET @CH8 = Substring(@TAXREG, 8, 1) * 13
SET @CH9 = Substring(@TAXREG, 9, 1) * 15
SET @CH10 = Substring(@TAXREG, 10, 1) * 17
SET @CH11 = Substring(@TAXREG, 11, 1) * 19
SET @RESULT = @CH1 + @CH2 + @CH3 + @CH4 + @CH5 + @CH6 + @CH7 + @CH8 + @CH9 + @CH10 + @CH11
SET @CHECKCALC = @RESULT % 89
IF @CHECKCALC = 0
SET @IsValid = 'Y'
END /*Divide the string by character position and apply weighting formula then check result*/

RETURN @IsValid
END


Procedure: FN_ValidateNZBN
NameFN_ValidateNZBN
Note
CodeCREATE FUNCTION [dbo].[FN_ValidateNZBN] (@NZBN VARCHAR(13)) RETURNS CHAR
AS
BEGIN
RETURN 'Y'
END


Procedure: FormatGLAccount
NameFormatGLAccount
Note
CodeCREATE FUNCTION [dbo].[FormatGLAccount]
(
@GLAccount int,
@GLSUBAccount int
)
RETURNS VARCHAR(20)
AS
BEGIN
DECLARE @SubLen int;
DECLARE @GLLen int;
SET @GLLen = dbo.FN_GET_PROFILE_VALUE_INT('GLACCNOSIZE');
SET @SUBLEN = dbo.FN_GET_PROFILE_VALUE_INT('GLSUBACCSIZE');

DECLARE @RESULT VARCHAR(20)
SET @RESULT = RIGHT(REPLICATE('0', @GLLen)+ CAST(@GLAccount AS VARCHAR), @GLLen) + '-' + RIGHT(REPLICATE('0', @SubLen)+ CAST(@GLSUBAccount AS VARCHAR), @SubLen)
RETURN @RESULT
END


Procedure: GEN_ID
NameGEN_ID
Note
CodeCREATE PROCEDURE [dbo].[GEN_ID]
  @TABLENAME VARCHAR(50),
  @FIELDNAME VARCHAR(50),
  @NOSELECT CHAR(1)=NULL,
  @ID INTEGER=NULL OUTPUT
AS
BEGIN
  SET NOCOUNT ON

  UPDATE IDENTIFIERS WITH (ROWLOCK)
  SET
    ID = ID + 1,
    @ID = ID
  WHERE
    TABLENAME = @TABLENAME AND
    FIELDNAME = @FIELDNAME

  IF @@ROWCOUNT=0
  BEGIN
    SELECT @ID = ID
    FROM IDENTIFIERS
    WHERE
      TABLENAME = '_DATAXOFFSET' AND
      FIELDNAME = '_DEFAULT'

    IF @ID IS NULL
       SELECT @ID = 0

    INSERT INTO IDENTIFIERS (TABLENAME, FIELDNAME, ID)
    VALUES (@TABLENAME, @FIELDNAME, @ID + 1)
  END

  IF (@NOSELECT IS NULL OR @NOSELECT='N')
    SELECT @ID 'ID'

  SET NOCOUNT OFF
END


Procedure: GeoDistance
NameGeoDistance
Note
CodeCREATE FUNCTION [dbo].[GeoDistance]
(
@FromLatitude FLOAT, @FromLongitude FLOAT, @ToLatitude FLOAT, @ToLongitude FLOAT
)
RETURNS FLOAT
AS
BEGIN
DECLARE @Result FLOAT;

IF @FromLatitude is null or @FromLongitude is null or @ToLatitude is null or @ToLongitude is null
SET @result = null
ELSE
set @result = geography::Point(@FromLatitude, @FromLongitude, 4326).STDistance(geography::Point(@ToLatitude, @ToLongitude, 4326))

RETURN @Result;

END


Procedure: GetCRRemittanceEmail
NameGetCRRemittanceEmail
Note
CodeCREATE FUNCTION [dbo].[GetCRRemittanceEmail](
@SOURCE CHAR(1),
@ACCNO INT)

RETURNS @EMailDetails TABLE (EMAIL VARCHAR(255), CONTACTSEQNO INT)
AS
BEGIN

DECLARE @EMAIL VARCHAR(255)
DECLARE @CONTACTSEQNO INT
DECLARE @CEMAIL VARCHAR(255)

-- DEFAULT LOGIC. Use email address from the creditor account
SELECT @EMAIL = EMAIL, @CONTACTSEQNO = STATEMENT_CONTACT_SEQNO
FROM CR_ACCS WHERE ACCNO = @ACCNO

IF ISNULL(@CONTACTSEQNO, -1) <> -1 -- use STATEMENT_CONTACT_SEQNO
BEGIN
SELECT @CEMAIL = EMAIL
FROM CONTACTS
WHERE SEQNO = @CONTACTSEQNO

IF ISNULL(@CEMAIL, '') <> ''
SELECT @EMAIL = @CEMAIL
END
ELSE -- use creditor's default contact
BEGIN
SELECT @EMAIL = C.EMAIL, @CONTACTSEQNO = C.SEQNO
FROM CR_CONTACTS D
INNER JOIN CONTACTS C ON D.CONTACT_SEQNO = C.SEQNO
WHERE D.ACCNO = @ACCNO AND D.DEFCONTACT = 'Y'
END

INSERT INTO @EMailDetails
SELECT @EMAIL, @CONTACTSEQNO

RETURN
END


Procedure: GetDRInvoiceEmail
NameGetDRInvoiceEmail
Note
CodeCREATE FUNCTION [dbo].[GetDRInvoiceEmail](
    @SOURCE CHAR(1),
    @ACCNO INT,
    @HDRSEQNO INT)

/*
   @HDRSEQNO is not used by default, but is available for customisation.
   It maps to DR_TRANS.SeqNo and DR_INVLINES.HDR_SEQNO.
   E.g. could get contact email if the CONTACTONTRANS profile is enabled
   If called from MailShot, this will be -1.
*/

    RETURNS @EMailDetails TABLE (EMAIL VARCHAR(255), CONTACTSEQNO INT)
    AS
BEGIN

    DECLARE @EMAIL VARCHAR(255)
    DECLARE @CONTACTSEQNO INT

    -- DEFAULT LOGIC. Use email address from the debtor account
    SELECT @EMAIL = EMAIL, @CONTACTSEQNO = STATEMENT_CONTACT_SEQNO
    FROM DR_ACCS WHERE ACCNO = @ACCNO

    IF @SOURCE = 'M' -- MAILSHOT, use statement email logic
    BEGIN
        INSERT INTO @EMailDetails
        SELECT * FROM GetStatementEmail(@SOURCE, @ACCNO)
    END
    ELSE
    BEGIN
        INSERT INTO @EMailDetails
        SELECT @EMAIL, @CONTACTSEQNO
    END

    RETURN
END


Procedure: GETSOSTATUS_FROM_QTY
NameGETSOSTATUS_FROM_QTY
Note
CodeCREATE PROCEDURE [dbo].[GETSOSTATUS_FROM_QTY]
  @THESO INT,
  @UPDATESO CHAR(1)
AS
  DECLARE @SOCOUNT INT
  DECLARE @CUR_SOSTATUS INT
  DECLARE @SOSTATUS INT
  DECLARE @ORD_QUANT FLOAT
  DECLARE @CORRECTION_QUANT FLOAT
  DECLARE @CORRECTED_QUANT FLOAT
  DECLARE @RELEASE_QUANT FLOAT
  DECLARE @PICKED_QUANT FLOAT
  DECLARE @SUP_QUANT FLOAT
  DECLARE @INV_QUANT FLOAT
  DECLARE @USERELEASEQTY CHAR(1)
  DECLARE @USEPICKQTY CHAR(1)
  DECLARE @LINE_NOTPROCESSED CHAR(1)
  DECLARE @LINE_FULLPROCESSED CHAR(1)
  DECLARE @LINE_PARTIALPROCESSED CHAR(1)
  DECLARE @ISZEROCORRECTED CHAR(1)
  DECLARE @ISZEROORD CHAR(1)
  DECLARE @ISZERORELEASE CHAR(1)
  DECLARE @ISZEROPICK CHAR(1)
  DECLARE @ISZEROSUP CHAR(1)
  DECLARE @ISZEROINV CHAR(1)

BEGIN
  SET NOCOUNT ON

  SELECT @CUR_SOSTATUS=STATUS FROM SALESORD_HDR WHERE SEQNO = @THESO
  SELECT @SOCOUNT=COUNT (*) FROM SALESORD_LINES WHERE HDR_SEQNO = @THESO

  SET @SOSTATUS = 0;

  EXECUTE GET_PROFILE_VALUE @FIELDNAME='RELQTYONSALESORD', @FIELDVALUE=@USERELEASEQTY OUTPUT
  IF (@USERELEASEQTY IS NULL)
    SET @USERELEASEQTY='N'

  EXECUTE GET_PROFILE_VALUE @FIELDNAME='USEPICKQTY', @FIELDVALUE=@USEPICKQTY OUTPUT
  IF (@USEPICKQTY IS NULL)
    SET @USEPICKQTY='N'

  SET @LINE_NOTPROCESSED = 'N'
  SET @LINE_FULLPROCESSED = 'N'
  SET @LINE_PARTIALPROCESSED = 'N'

  IF (@SOCOUNT <> 0) AND ((@CUR_SOSTATUS <> 4) OR (@UPDATESO <> 'Y')) /* STANDING ORDER */
  BEGIN
    DECLARE LINE_CURSOR CURSOR FOR
    SELECT ORD_QUANT, CORRECTION_QUANT , CORRECTED_QUANT, RELEASE_QUANT, PICKED_QUANT, SUP_QUANT, INV_QUANT
    FROM SALESORD_LINES WHERE HDR_SEQNO = @THESO AND LINETYPE <> 4
    OPEN LINE_CURSOR
    FETCH NEXT FROM LINE_CURSOR
    INTO @ORD_QUANT, @CORRECTION_QUANT, @CORRECTED_QUANT , @RELEASE_QUANT, @PICKED_QUANT, @SUP_QUANT, @INV_QUANT
    WHILE @@FETCH_STATUS = 0
    BEGIN
       EXECUTE ISZERO_FLOAT @ORD_QUANT, 'Y', @ISZEROORD OUTPUT
       EXECUTE ISZERO_FLOAT @CORRECTED_QUANT, 'Y', @ISZEROCORRECTED OUTPUT
       EXECUTE ISZERO_FLOAT @RELEASE_QUANT, 'Y', @ISZERORELEASE OUTPUT
       EXECUTE ISZERO_FLOAT @PICKED_QUANT, 'Y', @ISZEROPICK OUTPUT
       EXECUTE ISZERO_FLOAT @SUP_QUANT, 'Y', @ISZEROSUP OUTPUT
       EXECUTE ISZERO_FLOAT @INV_QUANT, 'Y', @ISZEROINV OUTPUT
/* This check is not required as its already well taking care below
       IF (@ISZEROORD='Y') AND (@ISZEROCORRECTED='Y')
       BEGIN
         SET @LINE_NOTPROCESSED = 'Y'
       END
*/
       IF @ISZEROCORRECTED='Y'
       BEGIN
         SET @LINE_FULLPROCESSED = 'Y'
       END
       ELSE IF (@CORRECTED_QUANT < 0)
       BEGIN
         IF (@ISZEROSUP = 'Y') AND (@ISZEROINV = 'Y')
            AND
            (((@ISZERORELEASE = 'Y') AND (@USERELEASEQTY = 'Y')) OR (@USERELEASEQTY <> 'Y'))
            AND
(((@ISZEROPICK = 'Y') AND (@USEPICKQTY = 'Y')) OR (@USEPICKQTY <> 'Y'))
            SET @LINE_NOTPROCESSED = 'Y'
         ELSE IF (@SUP_QUANT <= @CORRECTED_QUANT) AND (@INV_QUANT <= @CORRECTED_QUANT)
            AND
            (((@RELEASE_QUANT <= @CORRECTED_QUANT) AND (@USERELEASEQTY = 'Y')) OR (@USERELEASEQTY <> 'Y'))
            AND
(((@PICKED_QUANT <= @CORRECTED_QUANT) AND (@USEPICKQTY = 'Y')) OR (@USEPICKQTY <> 'Y'))
            SET @LINE_FULLPROCESSED = 'Y'
          ELSE
            SET @LINE_PARTIALPROCESSED = 'Y'
       END
       ELSE
       BEGIN
         IF (@ISZEROSUP = 'Y') AND (@ISZEROINV = 'Y')
            AND
            (((@ISZERORELEASE = 'Y') AND (@USERELEASEQTY = 'Y')) OR (@USERELEASEQTY <> 'Y'))
            AND
(((@ISZEROPICK = 'Y') AND (@USEPICKQTY = 'Y')) OR (@USEPICKQTY <> 'Y'))
            SET @LINE_NOTPROCESSED = 'Y'
         ELSE IF (@SUP_QUANT >= @CORRECTED_QUANT) AND (@INV_QUANT >= @CORRECTED_QUANT)
            AND
            (((@RELEASE_QUANT >= @CORRECTED_QUANT) AND (@USERELEASEQTY = 'Y')) OR (@USERELEASEQTY <> 'Y'))
            AND
(((@PICKED_QUANT >= @CORRECTED_QUANT) AND (@USEPICKQTY = 'Y')) OR (@USEPICKQTY <> 'Y'))
            SET @LINE_FULLPROCESSED = 'Y'
          ELSE
            SET @LINE_PARTIALPROCESSED = 'Y'
       END

      FETCH NEXT FROM LINE_CURSOR
      INTO @ORD_QUANT, @CORRECTION_QUANT , @CORRECTED_QUANT, @RELEASE_QUANT, @PICKED_QUANT, @SUP_QUANT, @INV_QUANT
    END
    CLOSE LINE_CURSOR
    DEALLOCATE LINE_CURSOR
  END

  IF ((@CUR_SOSTATUS = 4) AND (@UPDATESO = 'Y'))
    SET @SOSTATUS = @CUR_SOSTATUS
  ELSE IF (@LINE_NOTPROCESSED = 'N') AND (@LINE_PARTIALPROCESSED = 'N') AND (@LINE_FULLPROCESSED = 'N')
    SET @SOSTATUS = @CUR_SOSTATUS
  ELSE IF (@LINE_NOTPROCESSED = 'Y') AND (@LINE_PARTIALPROCESSED = 'N') AND (@LINE_FULLPROCESSED = 'N')
    SET @SOSTATUS = 0
  ELSE IF (@LINE_NOTPROCESSED = 'N') AND (@LINE_PARTIALPROCESSED = 'N') AND (@LINE_FULLPROCESSED = 'Y')
    SET @SOSTATUS = 2
  ELSE
    SET @SOSTATUS = 1;

  IF (@UPDATESO = 'Y')
  BEGIN
    UPDATE SALESORD_HDR SET STATUS = @SOSTATUS WHERE SEQNO = @THESO
    UPDATE SALESORD_LINES SET HDR_STATUS = @SOSTATUS WHERE HDR_SEQNO = @THESO
  END

  SELECT @SOSTATUS 'SOSTATUS'

  SET NOCOUNT OFF
END


Procedure: GetStatementEmail
NameGetStatementEmail
Note
CodeCREATE FUNCTION [dbo].[GetStatementEmail] (
@SOURCE CHAR(1),
@ACCNO INT
)
RETURNS @EMailDetails TABLE (
EMAIL VARCHAR(255),
CONTACTSEQNO INT
)
AS
BEGIN
DECLARE @EMAIL VARCHAR(255)
DECLARE @CONTACTSEQNO INT
DECLARE @CEMAIL VARCHAR(255)

SET @CONTACTSEQNO = -1

SELECT @EMAIL = C.EMAIL, @CONTACTSEQNO = D.STATEMENT_CONTACT_SEQNO
FROM DR_ACCS D
JOIN CONTACTS C ON C.SEQNO = D.STATEMENT_CONTACT_SEQNO
WHERE ACCNO = @ACCNO

IF ISNULL(@EMAIL, '') = ''
BEGIN
SELECT
@EMAIL = C.EMAIL,
@CONTACTSEQNO = C.SEQNO
FROM DR_CONTACTS D
INNER JOIN CONTACTS C ON D.CONTACT_SEQNO = C.SEQNO
WHERE D.ACCNO = @ACCNO
AND D.DEFCONTACT = 'Y'
END
IF ISNULL(@EMAIL, '') = ''
BEGIN
SELECT @EMAIL = EMAIL
FROM DR_ACCS
WHERE ACCNO = @ACCNO
END

INSERT INTO @EMailDetails
SELECT @EMAIL, @CONTACTSEQNO

RETURN
END


Procedure: GetStockPeriodClosingQty_AveCost
NameGetStockPeriodClosingQty_AveCost
Note
Code-- =============================================
-- description: This function will return the period closing quantity and average cost
-- for the stock item specified (@StkCode) in @StkPeriodSeqno
-- If no stock code is specified, this function returns the period closing quantity
-- and average cost for all stock items
-- =============================================
CREATE FUNCTION [dbo].[GetStockPeriodClosingQty_AveCost]
(
@StkPeriodSeqno int,
@StkCode varchar(23) = ''
)
RETURNS
@ClosingQty_AveCost TABLE
(
StkCode varchar(23),
PeriodClosingAveCost float,
PeriodClosingQty float,
StkTransSeqno int
)
AS
BEGIN
  DECLARE @StkTransSeqno int -- this is the seqno of the last stock transaction for period @StkPeriodSeqno when end of period took place
  DECLARE @Seqno int
  DECLARE @Count int

  select @StkTransSeqno = (select top 1 MINSTOCKSEQNO from period_Status where LEDGER = 'S' AND seqno > @StkPeriodSeqno order by seqno)

  SET @Seqno = @StkTransSeqno

  IF @StkCode = ''
  BEGIN
        INSERT @ClosingQty_AveCost
        SELECT STOCKCODE, PREV_AVECOST, PREV_QUANTITY, SEQNO FROM STOCK_TRANS WHERE SEQNO IN (
              select min(seqno) from stock_trans where SEQNO >@StkTransSeqno AND PERIOD_SEQNO > @StkPeriodSeqno group by stockcode)

        INSERT @ClosingQty_AveCost
        SELECT S.STOCKCODE, S.AVECOST, S.TOTALSTOCK, 0
        FROM STOCK_ITEMS S LEFT JOIN
              (SELECT STOCKCODE, PREV_AVECOST, PREV_QUANTITY, SEQNO FROM STOCK_TRANS WHERE SEQNO IN (
              select min(seqno) from stock_trans where SEQNO >@StkTransSeqno AND PERIOD_SEQNO > @StkPeriodSeqno group by stockcode)) AS ST
        ON S.STOCKCODE = ST.STOCKCODE
        WHERE ST.SEQNO IS NULL
  END
  ELSE
  BEGIN
        IF @StkTransSeqno is not null
              SELECT Top 1 @Seqno = SEQNO FROM STOCK_TRANS WHERE SEQNO > @StkTransSeqno
              AND PERIOD_SEQNO > @StkPeriodSeqno
              AND STOCKCODE = @StkCode
              ORDER BY SEQNO

        IF @Seqno IS NULL
        BEGIN
              INSERT @ClosingQty_AveCost
              SELECT STOCKCODE, AVECOST, TOTALSTOCK, 0 FROM STOCK_ITEMS WHERE STOCKCODE = @StkCode
        END
        ELSE
        BEGIN
              INSERT @ClosingQty_AveCost
              SELECT Top 1 STOCKCODE, PREV_AVECOST, PREV_QUANTITY, SEQNO FROM STOCK_TRANS WHERE SEQNO > @StkTransSeqno
              AND PERIOD_SEQNO > @StkPeriodSeqno
              AND STOCKCODE = @StkCode
              ORDER BY SEQNO
        END
  END

  RETURN
END


Procedure: GetStockPeriodClosingQty_AveCostByLoc
NameGetStockPeriodClosingQty_AveCostByLoc
Note
Code-- =============================================
-- description: This function will return the period closing quantity and average cost
-- for the stock item specified (@StkCode) in @StkPeriodSeqno per location
-- If no stock code is specified, this function returns the period closing quantity
-- and average cost for all stock items per location
-- =============================================
CREATE FUNCTION [dbo].[GetStockPeriodClosingQty_AveCostByLoc]
(
@StkPeriodSeqno int,
@StkCode varchar(23) = ''
)
RETURNS
@ClosingQty_AveCost TABLE
(
StkCode varchar(23),
PeriodClosingAveCost float,
PeriodClosingQty float,
StkTransSeqno int,
Location int
)
AS
BEGIN
  DECLARE @StkTransSeqno int -- this is the seqno of the last stock transaction for period @StkPeriodSeqno when end of period took place
  DECLARE @Seqno int
  DECLARE @Count int

  select @StkTransSeqno = (select top 1 MINSTOCKSEQNO from period_Status where LEDGER = 'S' AND seqno > @StkPeriodSeqno order by seqno)

  SET @Seqno = @StkTransSeqno

  IF @StkCode = ''
  BEGIN
        INSERT @ClosingQty_AveCost
        SELECT STOCKCODE, NEW_AVECOST, NEW_LOC_QTY, SEQNO, LOCATION FROM STOCK_TRANS WHERE SEQNO IN (
              select MAX(seqno) from stock_trans where PERIOD_SEQNO = @StkPeriodSeqno AND SEQNO <= @StkTransSeqno group by stockcode, LOCATION)

        ;with Last_Stk_Trans_For_StkItem_By_Loc(STOCKCODE, SEQNO, LOCATION)
        As
        (
                  SELECT STOCKCODE, SEQNO, LOCATION FROM STOCK_TRANS WHERE SEQNO IN
                  (SELECT MAX(seqno) from stock_trans where PERIOD_SEQNO = @StkPeriodSeqno AND SEQNO <= @StkTransSeqno group by stockcode, LOCATION)
            )
        , Last_AveCost_For_StkItem(STOCKCODE, AVECOST)
        As
        (
                  SELECT STOCK_ITEMS.STOCKCODE, ISNULL(AVECOST_FROM_STK_TRANS.PREV_AVECOST, STOCK_ITEMS.AVECOST)
                  FROM STOCK_ITEMS
                  LEFT JOIN
                  (
                        -- PREV_AVECOST FOR THE NEXT TRANSACTION (IN NEXT PERIOD) IS THE CLOSING AVERAGE COST FOR THIS PERIOD. THIS IS NOT LOCATION SPECIFIC
                        SELECT STOCKCODE, PREV_AVECOST FROM STOCK_TRANS WHERE SEQNO IN
                        (SELECT MIN(SEQNO) FROM STOCK_TRANS WHERE SEQNO > @StkTransSeqno GROUP BY STOCKCODE) -- the first transaction in the next period
                  ) AS AVECOST_FROM_STK_TRANS
                  ON STOCK_ITEMS.STOCKCODE = AVECOST_FROM_STK_TRANS.STOCKCODE
            )
        , Future_TransQty(FUTURE_QTY, STOCKCODE, LOCATION)
        As
        (
                  SELECT SUM(QUANTITY) FUTURE_QTY, STOCKCODE, LOCATION
                  FROM STOCK_TRANS WHERE SEQNO > @STKTRANSSEQNO
                  GROUP BY STOCKCODE, LOCATION
            )

        INSERT @ClosingQty_AveCost
        SELECT SL.STOCKCODE, S.AVECOST, SL.QTY - ISNULL(FUTURE_TRANS.FUTURE_QTY, 0), 0, SL.LOCATION
        FROM STOCK_LOC_INFO AS SL
        LEFT JOIN Last_Stk_Trans_For_StkItem_By_Loc as ST
        ON SL.STOCKCODE = ST.STOCKCODE AND SL.LOCATION = ST.LOCATION
        LEFT JOIN Future_TransQty AS FUTURE_TRANS
        ON SL.STOCKCODE = FUTURE_TRANS.STOCKCODE AND SL.LOCATION = FUTURE_TRANS.LOCATION
        LEFT JOIN Last_AveCost_For_StkItem AS S ON SL.STOCKCODE = S.STOCKCODE
        WHERE ST.SEQNO IS NULL

  END
  ELSE
  BEGIN
        INSERT @ClosingQty_AveCost
        SELECT STOCKCODE, NEW_AVECOST, NEW_LOC_QTY, SEQNO, LOCATION FROM STOCK_TRANS WHERE SEQNO IN (
              select MAX(seqno) from stock_trans where PERIOD_SEQNO = @StkPeriodSeqno AND SEQNO <= @StkTransSeqno AND STOCKCODE = @StkCode
              group by stockcode, LOCATION)

        ;with Last_Stk_Trans_For_StkItem_By_Loc(STOCKCODE, SEQNO, LOCATION)
        As
        (
                  SELECT STOCKCODE, SEQNO, LOCATION FROM STOCK_TRANS WHERE SEQNO IN
                  (SELECT MAX(seqno) from stock_trans where PERIOD_SEQNO = @StkPeriodSeqno AND SEQNO <= @StkTransSeqno group by stockcode, LOCATION)
            )
        , Last_AveCost_For_StkItem(STOCKCODE, AVECOST)
        As
        (
                  SELECT STOCK_ITEMS.STOCKCODE, ISNULL(AVECOST_FROM_STK_TRANS.PREV_AVECOST, STOCK_ITEMS.AVECOST)
                  FROM STOCK_ITEMS
                  LEFT JOIN
                  (
                        -- PREV_AVECOST FOR THE NEXT TRANSACTION (IN NEXT PERIOD) IS THE CLOSING AVERAGE COST FOR THIS PERIOD. THIS IS NOT LOCATION SPECIFIC
                        SELECT STOCKCODE, PREV_AVECOST FROM STOCK_TRANS WHERE SEQNO IN
                        (SELECT MIN(SEQNO) FROM STOCK_TRANS WHERE SEQNO > @StkTransSeqno GROUP BY STOCKCODE) -- the first transaction in the next period
                  ) AS AVECOST_FROM_STK_TRANS
                  ON STOCK_ITEMS.STOCKCODE = AVECOST_FROM_STK_TRANS.STOCKCODE
            )
        , Future_TransQty(FUTURE_QTY, STOCKCODE, LOCATION)
        As
        (
                  SELECT SUM(QUANTITY) FUTURE_QTY, STOCKCODE, LOCATION
                  FROM STOCK_TRANS WHERE SEQNO > @STKTRANSSEQNO
                  GROUP BY STOCKCODE, LOCATION
            )

        INSERT @ClosingQty_AveCost
        SELECT SL.STOCKCODE, S.AVECOST, SL.QTY - ISNULL(FUTURE_TRANS.FUTURE_QTY, 0), 0, SL.LOCATION
        FROM STOCK_LOC_INFO AS SL
        LEFT JOIN Last_Stk_Trans_For_StkItem_By_Loc as ST
        ON SL.STOCKCODE = ST.STOCKCODE AND SL.LOCATION = ST.LOCATION
        LEFT JOIN Future_TransQty AS FUTURE_TRANS
        ON SL.STOCKCODE = FUTURE_TRANS.STOCKCODE AND SL.LOCATION = FUTURE_TRANS.LOCATION
        LEFT JOIN Last_AveCost_For_StkItem AS S ON SL.STOCKCODE = S.STOCKCODE
        WHERE ST.SEQNO IS NULL AND SL.STOCKCODE = @StkCode
  END

  RETURN
END


Procedure: GET_COMPUTER_PROFILE_ID
NameGET_COMPUTER_PROFILE_ID
Note
Code-- ============================================================
-- Description: This procedure returns the Computer Profile ID
-- for the the Computer Seqno passed in as parameter or the
-- user calling this procedure
-- Returns -1 if COMPUTER_PROFILE_ID not found.
-- ============================================================
CREATE PROCEDURE [dbo].[GET_COMPUTER_PROFILE_ID]
@COMPUTER_PROFILE_ID INT OUTPUT,
@COMPUTER_SEQNO INT = -1
AS
BEGIN
SET @COMPUTER_PROFILE_ID = -1

IF @COMPUTER_SEQNO = -1
SELECT @COMPUTER_SEQNO=[dbo].FN_GET_COMPUTER_SEQNO()

SELECT @COMPUTER_PROFILE_ID=COMPUTERPROFILEID
FROM COMPUTER
WHERE SEQNO=@COMPUTER_SEQNO
END


Procedure: GET_COST_PRICE
NameGET_COST_PRICE
Note
CodeCREATE PROCEDURE [dbo].[GET_COST_PRICE]
@STOCKCODE VARCHAR(23),
@ACCNO INTEGER,
@CURRENCYNO INTEGER,
@SUPPPRICEFIELD VARCHAR(20),
@PURCHPRICEFIELD VARCHAR(20),
@TRANSDATE DATETIME,
@ORDREF VARCHAR(20),
@QUANTITY FLOAT,
@COST_PRICE FLOAT=NULL OUTPUT,
@SPECIAL_DISCOUNT FLOAT=NULL OUTPUT
AS
DECLARE @SUPPLIERNO INTEGER,
@STOCKPRICEGROUP INTEGER,
@STDCOST FLOAT,
@AVECOST FLOAT,
@LATESTCOST FLOAT,
@SUPPLIERCOST FLOAT,
@IS_DISCOUNTABLE CHAR(1),
@PRICE_VAR FLOAT,
@DISCOUNT_VAR FLOAT,
@CRLINEDISCS CHAR(1),
@ACTUAL_PRICE_VAR FLOAT,
@FIXED_VAR CHAR(1),
@FIXEDRULES CHAR(1),
@PRICEFIELD VARCHAR(20)

BEGIN
SELECT @SUPPLIERNO=SUPPLIERNO, @STDCOST=STDCOST, @AVECOST=AVECOST, @LATESTCOST=LATESTCOST,
@SUPPLIERCOST=SUPPLIERCOST, @STOCKPRICEGROUP=STOCKPRICEGROUP, @IS_DISCOUNTABLE=IS_DISCOUNTABLE
FROM STOCK_ITEMS
WHERE STOCKCODE=@STOCKCODE

SET @COST_PRICE=0
SET @SPECIAL_DISCOUNT=0

/*
** If account is the main supplier for the stockitem
** use supplier cost
*/
IF @SUPPLIERNO=@ACCNO
SET @COST_PRICE=@SUPPLIERCOST

-- If not the main supplier, then check for Forex account
IF @COST_PRICE=0
BEGIN
IF @CURRENCYNO=0 -- local currency account
BEGIN
SET @PRICEFIELD='LATESTCOST'

IF @SUPPPRICEFIELD<>''
SET @PRICEFIELD=@SUPPPRICEFIELD
ELSE IF @PURCHPRICEFIELD<>''
SET @PRICEFIELD=@PURCHPRICEFIELD

SET @COST_PRICE=
CASE @PRICEFIELD
WHEN 'STDCOST' THEN @STDCOST
WHEN 'AVECOST' THEN @AVECOST
WHEN 'LATESTCOST' THEN @LATESTCOST
WHEN 'SUPPLIERCOST' THEN @SUPPLIERCOST
END
END
ELSE -- For Forex account pickup last unitprice from purchase orders
BEGIN -- for the specific stock item and account
SELECT @COST_PRICE=ISNULL(UNITPRICE, 0)
FROM PURCHORD_LINES
WHERE STOCKCODE=@STOCKCODE
AND ACCNO=@ACCNO
AND SEQNO=( SELECT MAX(SEQNO)
FROM PURCHORD_LINES
WHERE STOCKCODE=@STOCKCODE AND ACCNO=@ACCNO)
END
END -- for (IF @COST_PRICE=0)

SET @ACTUAL_PRICE_VAR=@COST_PRICE
EXECUTE GET_PROFILE_VALUE 'CRLINEDISCS', @CRLINEDISCS OUTPUT

DECLARE @TMP_SPECIAL_PRICES TABLE (
SPECIAL_PRICE FLOAT,
SPECIAL_DISCOUNT FLOAT,
FIXEDRULE CHAR(1))

SET @FIXEDRULES='N'

/*
** Initially insert the cost price returned from the currency IF ELSE condition
** with fixed price marked as N for that record
*/
INSERT INTO @TMP_SPECIAL_PRICES (SPECIAL_PRICE, SPECIAL_DISCOUNT, FIXEDRULE)
VALUES (@COST_PRICE, 0, 'N')

DECLARE SPECIALS_CURSOR CURSOR FOR
SELECT PRICE, ISNULL(DISCOUNT, 0), FIXED
FROM CR_PRICES
WHERE ACCNO=@ACCNO
AND ((STOCKCODE=@STOCKCODE) OR (STOCKPRICEGROUP=@STOCKPRICEGROUP))
AND ((STARTDATE<=@TRANSDATE) AND (STOPDATE>=@TRANSDATE))
AND ISACTIVE<>'N'
AND MINQTY<=@QUANTITY

OPEN SPECIALS_CURSOR
FETCH NEXT FROM SPECIALS_CURSOR
INTO @PRICE_VAR, @DISCOUNT_VAR, @FIXED_VAR

WHILE @@FETCH_STATUS = 0
BEGIN
-- Insert all price rules(Fixed and normal ones)
IF (@FIXED_VAR= 'Y')
SET @FIXEDRULES='Y' -- To flag if fixed price rules exist
IF ((@PRICE_VAR IS NOT NULL) AND (@PRICE_VAR>0)) OR ((@IS_DISCOUNTABLE='Y') AND
(@DISCOUNT_VAR IS NOT NULL) AND (@DISCOUNT_VAR>0))
BEGIN
IF (@PRICE_VAR IS NULL)
SET @PRICE_VAR = @COST_PRICE - (@COST_PRICE * @DISCOUNT_VAR/100)
IF (@DISCOUNT_VAR=0) OR ((@DISCOUNT_VAR>0) AND (@IS_DISCOUNTABLE='Y') AND (@CRLINEDISCS='Y'))
INSERT INTO @TMP_SPECIAL_PRICES (SPECIAL_PRICE, SPECIAL_DISCOUNT, FIXEDRULE)
VALUES (@PRICE_VAR, @DISCOUNT_VAR, @FIXED_VAR)
END
FETCH NEXT FROM SPECIALS_CURSOR
INTO @PRICE_VAR, @DISCOUNT_VAR, @FIXED_VAR
END

CLOSE SPECIALS_CURSOR
DEALLOCATE SPECIALS_CURSOR

IF @FIXEDRULES='Y'
BEGIN
SELECT TOP 1 @COST_PRICE=SPECIAL_PRICE, @SPECIAL_DISCOUNT=SPECIAL_DISCOUNT
FROM @TMP_SPECIAL_PRICES
WHERE FIXEDRULE = 'Y'
ORDER BY SPECIAL_PRICE ASC
END
ELSE
BEGIN
SELECT TOP 1 @COST_PRICE=SPECIAL_PRICE, @SPECIAL_DISCOUNT=SPECIAL_DISCOUNT
FROM @TMP_SPECIAL_PRICES
ORDER BY SPECIAL_PRICE ASC
END

IF @SPECIAL_DISCOUNT>0
SET @COST_PRICE=@ACTUAL_PRICE_VAR

SELECT @COST_PRICE COST_PRICE, @SPECIAL_DISCOUNT DISCOUNT
END


Procedure: GET_GLBATCHNUMBER
NameGET_GLBATCHNUMBER
Note
CodeCREATE PROCEDURE [dbo].[GET_GLBATCHNUMBER] @USERID VARCHAR(30) = "ANON"
AS
BEGIN

  INSERT INTO GLBATCH_NUMBERS (USERID, DATE_ISSUED) VALUES (@USERID, getdate())

  SELECT MAX(BATCHNO) THEBATCHNO FROM GLBATCH_NUMBERS WHERE USERID=@USERID

END


Procedure: GET_GLMOVEMENTS_RECORD
NameGET_GLMOVEMENTS_RECORD
Note
CodeCREATE PROCEDURE [dbo].[GET_GLMOVEMENTS_RECORD]
  @ACCNO INT,
  @SUBACCNO INT,
  @BRANCHNO INT,
  @COMPANYNO INT,
  @PERIOD_SEQNO INT,
  @CALCNEW CHAR(1),
  @SEQNO INT OUTPUT,
  @ISNEW CHAR(1) OUTPUT
AS
  DECLARE @AMOUNT FLOAT
  DECLARE @FCAMOUNT FLOAT
BEGIN
  /* Exonet created procedure from DBUpdate version [6.180] */

  SET NOCOUNT ON

  SET @SEQNO=NULL
  SET @ISNEW='N'
  SELECT @SEQNO=SEQNO FROM GLMOVEMENTS WHERE ACCNO=@ACCNO AND SUBACCNO=@SUBACCNO
    AND BRANCHNO=@BRANCHNO AND COMPANYNO=@COMPANYNO AND PERIOD_SEQNO=@PERIOD_SEQNO

  IF (@SEQNO IS NULL)
  BEGIN
    SET @ISNEW='Y'
    IF (@CALCNEW='Y')
    BEGIN
      SELECT @AMOUNT=SUM(AMOUNT), @FCAMOUNT=SUM(FCAMOUNT) FROM GLTRANS
        WHERE ACCNO=@ACCNO AND SUBACCNO=@SUBACCNO AND BRANCHNO=@BRANCHNO
        AND COMPANYNO=@COMPANYNO AND PERIOD_SEQNO=@PERIOD_SEQNO
      IF (@AMOUNT IS NULL)
        SET @AMOUNT=0
      IF (@FCAMOUNT IS NULL)
        SET @FCAMOUNT=0
    END
    ELSE
    BEGIN
      SET @AMOUNT=0
      SET @FCAMOUNT=0
    END
    INSERT INTO GLMOVEMENTS (ACCNO, SUBACCNO, BRANCHNO, COMPANYNO, PERIOD_SEQNO, AMOUNT, AMOUNT_FC)
      VALUES (@ACCNO, @SUBACCNO, @BRANCHNO, @COMPANYNO, @PERIOD_SEQNO, @AMOUNT, @FCAMOUNT)
    SELECT @SEQNO=SEQNO FROM GLMOVEMENTS WHERE ACCNO=@ACCNO AND SUBACCNO=@SUBACCNO
      AND BRANCHNO=@BRANCHNO AND COMPANYNO=@COMPANYNO AND PERIOD_SEQNO=@PERIOD_SEQNO
  END

  SET NOCOUNT OFF
END


Procedure: GET_INVNUMBER
NameGET_INVNUMBER
Note
Code/****** Object: Stored Procedure [dbo].[GET_INVNUMBER] Script Date: 18/12/2001 12:51:34 ******/

CREATE PROCEDURE GET_INVNUMBER @USERID VARCHAR(30) = "ANON"
AS
BEGIN
  INSERT INTO INV_NUMBERS (USERID) VALUES (@USERID)

  SELECT MAX(INVNO) THEINVNO FROM INV_NUMBERS WHERE USERID=@USERID
END


Procedure: GET_PROFILE_TYPE
NameGET_PROFILE_TYPE
Note
CodeCREATE PROCEDURE [dbo].[GET_PROFILE_TYPE]
@FIELDNAME VARCHAR(40),
@PROFILETYPE INT OUTPUT
AS
BEGIN
/*
This Stored Procedure assumes that the profile always exists and does not cater for
the situation where the profile fieldname does not exist.
Returns -1 if profile not found.
*/
SET @PROFILETYPE = -1

SELECT @PROFILETYPE=PROFILETYPE
FROM PROFILE_FIELDS
WHERE FIELDNAME=@FIELDNAME
END


Procedure: GET_PROFILE_VALUE
NameGET_PROFILE_VALUE
Note
CodeCREATE PROCEDURE [dbo].[GET_PROFILE_VALUE]
@FIELDNAME VARCHAR(40),
@FIELDVALUE VARCHAR(200) = NULL OUTPUT
AS
BEGIN
DECLARE @DEFAULTVAL VARCHAR(200),
@ACTUALVAL VARCHAR(200),
@PROFILETYPE INT,
@PROFILEID INT,
@COUNT INT

/* For this stored procedure to return correct result Profile ID must be
passed in as a parameter for USER, COMPUTER and SECURITY profile fields. */

SET @PROFILETYPE = -1
SET @PROFILEID = -1

IF @PROFILETYPE = -1
EXECUTE GET_PROFILE_TYPE @FIELDNAME=@FIELDNAME, @PROFILETYPE=@PROFILETYPE OUTPUT

IF @PROFILETYPE=1
SET @PROFILEID=1
ELSE IF @PROFILETYPE=2
EXECUTE GET_USER_PROFILE_ID @PROFILEID OUTPUT
ELSE IF @PROFILETYPE=3
EXECUTE GET_COMPUTER_PROFILE_ID @PROFILEID OUTPUT
ELSE IF @PROFILETYPE=4
EXECUTE GET_SECURITY_PROFILE_ID @PROFILEID OUTPUT

SELECT @DEFAULTVAL=PF.DEFAULTVALUE
FROM PROFILE_FIELDS PF
WHERE UPPER(PF.FIELDNAME)=UPPER(@FIELDNAME)

IF @PROFILETYPE<>1
BEGIN
SELECT @COUNT=COUNT(*)
FROM PROFILE_VALUES PV
WHERE UPPER(PV.FIELDNAME)=UPPER(@FIELDNAME)
AND PV.PROFILEID = @PROFILEID

IF @COUNT = 0
SET @PROFILEID = @PROFILETYPE
END

IF @PROFILEID <> -1
BEGIN
SELECT @ACTUALVAL=PV.FIELDVALUE
FROM PROFILE_VALUES PV
WHERE UPPER(PV.FIELDNAME)=UPPER(@FIELDNAME)
AND PV.PROFILEID = @PROFILEID
END

IF @ACTUALVAL IS NULL
SET @FIELDVALUE = @DEFAULTVAL
ELSE
SET @FIELDVALUE = @ACTUALVAL
END


Procedure: GET_PROFILE_VALUE_INT
NameGET_PROFILE_VALUE_INT
Note
CodeCREATE PROCEDURE [dbo].[GET_PROFILE_VALUE_INT]
@FIELDNAME VARCHAR(40),
@FIELDVALUE INTEGER = 0 OUTPUT
AS
BEGIN
DECLARE @DEFAULTVAL VARCHAR(200),
@ACTUALVAL VARCHAR(200),
@PROFILETYPE INT,
@PROFILEID INT,
@COUNT INT

/* For this stored procedure to return correct result Profile ID must be
passed in as a parameter for USER, COMPUTER and SECURITY profile fields. */

SET @PROFILETYPE = -1
SET @PROFILEID = -1

IF @PROFILETYPE = -1
EXECUTE GET_PROFILE_TYPE @FIELDNAME=@FIELDNAME, @PROFILETYPE=@PROFILETYPE OUTPUT

IF @PROFILETYPE=1
SET @PROFILEID=1
ELSE IF @PROFILETYPE=2
EXECUTE GET_USER_PROFILE_ID @PROFILEID OUTPUT
ELSE IF @PROFILETYPE=3
EXECUTE GET_COMPUTER_PROFILE_ID @PROFILEID OUTPUT
ELSE IF @PROFILETYPE=4
EXECUTE GET_SECURITY_PROFILE_ID @PROFILEID OUTPUT

SELECT @DEFAULTVAL=PF.DEFAULTVALUE
FROM PROFILE_FIELDS PF
WHERE UPPER(PF.FIELDNAME)=UPPER(@FIELDNAME)

IF @PROFILETYPE<>1
BEGIN
SELECT @COUNT=COUNT(*)
FROM PROFILE_VALUES PV
WHERE UPPER(PV.FIELDNAME)=UPPER(@FIELDNAME)
AND PV.PROFILEID = @PROFILEID

IF @COUNT = 0
SET @PROFILEID = @PROFILETYPE
END

IF @PROFILEID <> -1
BEGIN
SELECT @ACTUALVAL=PV.FIELDVALUE
FROM PROFILE_VALUES PV
WHERE UPPER(PV.FIELDNAME)=UPPER(@FIELDNAME)
AND PV.PROFILEID = @PROFILEID
END

SET @FIELDVALUE = 0
IF (@ACTUALVAL IS NULL) AND (@DEFAULTVAL IS NOT NULL) AND (@DEFAULTVAL <> '')
SET @FIELDVALUE = CAST(@DEFAULTVAL AS INTEGER)
ELSE IF (@ACTUALVAL IS NOT NULL) AND (@ACTUALVAL <> '')
SET @FIELDVALUE = CAST(@ACTUALVAL AS INTEGER)
END


Procedure: GET_SECURITY_PROFILE_ID
NameGET_SECURITY_PROFILE_ID
Note
Code-- =============================================================
-- Description: This procedure returns the Security Profile ID
-- for the the staff no passed in as parameter or the user
-- calling this procedure
-- Returns -1 if SECURITY_PROFILE_ID not found.
-- =============================================================
CREATE PROCEDURE [dbo].[GET_SECURITY_PROFILE_ID]
@SECURITY_PROFILE_ID INT OUTPUT,
@STAFFNO INT = -1
AS
BEGIN
SET @SECURITY_PROFILE_ID = -1

IF @STAFFNO = -1
SELECT @STAFFNO=[dbo].FN_GET_STAFF_NO()

SELECT @SECURITY_PROFILE_ID=SECURITYPROFILEID
FROM STAFF
WHERE STAFFNO=@STAFFNO
END


Procedure: GET_USER_PROFILE_ID
NameGET_USER_PROFILE_ID
Note
Code-- =========================================================
-- Description: This procedure returns the User Profile ID
-- for the the staff no passed in as parameter or the
-- user calling this procedure
-- Returns -1 if USER_PROFILE_ID not found.
-- =========================================================
CREATE PROCEDURE [dbo].[GET_USER_PROFILE_ID]
@USER_PROFILE_ID INT OUTPUT,
@STAFFNO INT = -1
AS
BEGIN
SET @USER_PROFILE_ID = -1

IF @STAFFNO = -1
SELECT @STAFFNO=[dbo].FN_GET_STAFF_NO()

SELECT @USER_PROFILE_ID=USERPROFILEID
FROM STAFF
WHERE STAFFNO=@STAFFNO
END


Procedure: ISZERO_FLOAT
NameISZERO_FLOAT
Note
CodeCREATE PROCEDURE [dbo].[ISZERO_FLOAT]
  @INVALUE FLOAT,
  @NOSELECT CHAR(1)=NULL,
  @ISZERO CHAR(1)=NULL OUTPUT
AS
  DECLARE @POS_ZERO_EPSILON FLOAT
  DECLARE @NEG_ZERO_EPSILON FLOAT
BEGIN
  SET NOCOUNT ON

  SET @POS_ZERO_EPSILON=0.0001
  SET @NEG_ZERO_EPSILON=-0.0001
  IF ((@INVALUE IS NULL) OR
     ((@INVALUE>=0) AND (@INVALUE<=@POS_ZERO_EPSILON)) OR
     ((@INVALUE<0) AND (@INVALUE>=@NEG_ZERO_EPSILON)))
    SET @ISZERO='Y'
  ELSE
    SET @ISZERO='N'

  IF (@NOSELECT IS NULL OR @NOSELECT='N')
    SELECT @ISZERO 'ISZERO'

  SET NOCOUNT OFF
END


Procedure: PRICE_SELECT_UPDATE
NamePRICE_SELECT_UPDATE
Note
CodeCREATE PROCEDURE [dbo].[PRICE_SELECT_UPDATE]
AS
DECLARE @QUERY VARCHAR(MAX),
@MAXSELLPRICES INT,
@COUNTER INT
IF EXISTS (SELECT NAME FROM SYSOBJECTS WHERE NAME = 'vwPRICE_SELECT')
  BEGIN
  SELECT @QUERY = 'ALTER VIEW vwPRICE_SELECT '
  END
ELSE
  SELECT @QUERY = 'CREATE VIEW vwPRICE_SELECT '
SELECT @QUERY = @QUERY + '
AS
'
SELECT @MAXSELLPRICES = (SELECT MAX(PRICENO) FROM PRICE_NAMES)
SELECT @COUNTER = 1
WHILE @COUNTER <= @MAXSELLPRICES
  BEGIN
  IF EXISTS (SELECT SC.NAME FROM SYSCOLUMNS SC JOIN SYSOBJECTS SO ON SC.ID = SO.ID WHERE SC.NAME LIKE 'SELLPRICE%' AND SO.NAME =
'STOCK_ITEMS' AND SUBSTRING(SC.NAME, 10, LEN(SC.NAME)) = CONVERT(VARCHAR, @COUNTER))
BEGIN
SELECT @QUERY = @QUERY + '(SELECT STOCKCODE, ' + CONVERT(VARCHAR, @COUNTER) + ' AS PRICENO, SELLPRICE' + CONVERT(VARCHAR, @COUNTER) + ' AS SELLPRICE FROM STOCK_ITEMS)
UNION ALL
'
END
SELECT @COUNTER = @COUNTER + 1
CONTINUE
END
SELECT @QUERY = LEFT(@QUERY, LEN(@QUERY ) - 11)
EXECUTE (@QUERY)


Procedure: RECALC_ALL_JOB_TOTALS
NameRECALC_ALL_JOB_TOTALS
Note
CodeCREATE PROCEDURE [dbo].[RECALC_ALL_JOB_TOTALS]
AS
BEGIN
  DECLARE @JOBNO INTEGER

  DECLARE JOB_CURSOR CURSOR
  FOR
  SELECT JOBNO
  FROM JOBCOST_HDR
  OPEN JOB_CURSOR
  FETCH NEXT FROM JOB_CURSOR INTO @JOBNO
  WHILE @@FETCH_STATUS = 0
  BEGIN
    EXECUTE RECALC_JOB_TOTAL @JOBNO, '*', '*';
    FETCH NEXT FROM JOB_CURSOR INTO @JOBNO
  END
  CLOSE JOB_CURSOR
  DEALLOCATE JOB_CURSOR
END


Procedure: RECALC_ALL_STOCK_LEVELS
NameRECALC_ALL_STOCK_LEVELS
Note
CodeCREATE PROCEDURE [dbo].[RECALC_ALL_STOCK_LEVELS]
AS
DECLARE @STOCKCODE VARCHAR(40)
BEGIN
  DECLARE ALL_STOCK_ITEMS_CURSOR CURSOR LOCAL
  FOR SELECT STOCKCODE FROM STOCK_ITEMS

  OPEN ALL_STOCK_ITEMS_CURSOR
  FETCH NEXT FROM ALL_STOCK_ITEMS_CURSOR
  INTO @STOCKCODE
  WHILE @@FETCH_STATUS = 0
  BEGIN
  EXEC RECALC_SINGLE_STOCK_ITEM @STOCKCODE
  FETCH NEXT FROM ALL_STOCK_ITEMS_CURSOR
  INTO @STOCKCODE
  END
  CLOSE ALL_STOCK_ITEMS_CURSOR
  DEALLOCATE ALL_STOCK_ITEMS_CURSOR
END


Procedure: RECALC_JOB_TOTAL
NameRECALC_JOB_TOTAL
Note
CodeCREATE PROCEDURE [dbo].[RECALC_JOB_TOTAL] (
  @JOBNO INTEGER,
  @STATEPARAM VARCHAR(30),
  @TYPEPARAM VARCHAR(1))
AS
BEGIN
  DECLARE @SUM_INVOICED DOUBLE PRECISION,
@SUM_INVOICEDCOST DOUBLE PRECISION,
@SUM_THETIME DOUBLE PRECISION,
@SUM_THETIMECOST DOUBLE PRECISION,
@SUM_MATERIALS DOUBLE PRECISION,
@SUM_MATERIALSCOST DOUBLE PRECISION,
@SUM_WRITEOFFCOST DOUBLE PRECISION,
@SUM_EST_HOURS DOUBLE PRECISION,
@SUM_TOTAL_HOURS DOUBLE PRECISION,
@SUM_ASSET_COST DOUBLE PRECISION,
@SUM_ASSETVALUE DOUBLE PRECISION,
@SUM_QUOTED DOUBLE PRECISION,
@SUM_QUOTECOST DOUBLE PRECISION,
@SUM_LINECHARGE_WRITEOFF DOUBLE PRECISION,
@ADDSUBJOBS CHAR(1)

  SET NOCOUNT ON
  EXECUTE GET_PROFILE_VALUE 'JC_ADDSUBJOBS', @ADDSUBJOBS OUTPUT

  CREATE TABLE #JOBCOST_LINES (
    JOBNO INT,
    MASTER_JOBNO INT,
    COPY_FROM_QUOTE CHAR(1),
    ACTUAL_UNITCOST FLOAT,
    LINETOTAL FLOAT,
    TOTAL_QUANTITY FLOAT)

  CREATE TABLE #JOB_TRANSACTIONS (
    JOBNO INT,
    MASTER_JOBNO INT,
    LINE_STATUS VARCHAR(30),
    LINETOTAL FLOAT,
    LINECOST FLOAT,
    TRANSTYPE VARCHAR(1),
    TOTAL_QUANTITY FLOAT,
    SCHEDULE_SEQNO INT,
    PROGRESSINVOICE CHAR(1),
    LINECHARGE_WRITEOFF FLOAT)

  --QUOTATION LINES--
  IF (@TYPEPARAM IN ('Q', '*'))
  BEGIN
    IF (@ADDSUBJOBS='Y')
    BEGIN
      INSERT INTO #JOBCOST_LINES
      SELECT JOBCOST_LINES.JOBNO, MASTER_JOBNO, COPY_FROM_QUOTE, ACTUAL_UNITCOST, LINETOTAL, TOTAL_QUANTITY
      FROM JOBCOST_LINES
      JOIN JOB_QUOTE_OPTIONS ON (JOB_QUOTE_OPTIONS.JOBNO=JOBCOST_LINES.JOBNO OR JOB_QUOTE_OPTIONS.JOBNO=-1)
AND(JOBCOST_LINES.OPTION_NO=JOB_QUOTE_OPTIONS.OPTION_NO)
AND OPTION_SELECTED='Y'
      WHERE (JOBCOST_LINES.JOBNO = @JOBNO OR JOBCOST_LINES.MASTER_JOBNO = @JOBNO)
    END
    ELSE
    BEGIN
      INSERT INTO #JOBCOST_LINES
      SELECT JOBCOST_LINES.JOBNO, MASTER_JOBNO, COPY_FROM_QUOTE, ACTUAL_UNITCOST, LINETOTAL, TOTAL_QUANTITY
      FROM JOBCOST_LINES
      JOIN JOB_QUOTE_OPTIONS ON (JOB_QUOTE_OPTIONS.JOBNO=JOBCOST_LINES.JOBNO OR JOB_QUOTE_OPTIONS.JOBNO=-1)
AND (JOBCOST_LINES.OPTION_NO=JOB_QUOTE_OPTIONS.OPTION_NO)
AND OPTION_SELECTED='Y'
      WHERE (JOBCOST_LINES.JOBNO=@JOBNO)
    END

    SELECT @SUM_QUOTECOST=SUM(ACTUAL_UNITCOST*TOTAL_QUANTITY), @SUM_QUOTED=SUM(LINETOTAL)
    FROM #JOBCOST_LINES

    SELECT @SUM_EST_HOURS=SUM(TOTAL_QUANTITY)
    FROM #JOBCOST_LINES
    WHERE COPY_FROM_QUOTE = 'T'
  END

  IF (@ADDSUBJOBS='Y')
  BEGIN
    INSERT INTO #JOB_TRANSACTIONS
    SELECT JOBNO, MASTER_JOBNO, LINE_STATUS, LINETOTAL, LINECOST, TRANSTYPE, TOTAL_QUANTITY, SCHEDULE_SEQNO, PROGRESSINVOICE, LINECHARGE_WRITEOFF
    FROM JOB_TRANSACTIONS
    WHERE (JOBNO = @JOBNO OR MASTER_JOBNO = @JOBNO)
  END
  ELSE
  BEGIN
    INSERT INTO #JOB_TRANSACTIONS
    SELECT JOBNO, MASTER_JOBNO, LINE_STATUS, LINETOTAL, LINECOST, TRANSTYPE, TOTAL_QUANTITY, SCHEDULE_SEQNO, PROGRESSINVOICE, LINECHARGE_WRITEOFF
    FROM JOB_TRANSACTIONS
    WHERE (JOBNO = @JOBNO)
  END

  --Cancelled transactions require recalc of other states--
  IF (@STATEPARAM IN ('I', 'A', 'W', 'X', '*'))
  BEGIN
IF (@ADDSUBJOBS='Y')
BEGIN
SELECT @SUM_INVOICED=SUM(ISNULL(SUBTOTAL, 0))
FROM JOB_CONTRACT_BILLINGS
WHERE (JOBNO = @JOBNO OR MASTER_JOBNO = @JOBNO) AND INVOICED = 'Y'
END
ELSE
BEGIN
SELECT @SUM_INVOICED=SUM(ISNULL(SUBTOTAL, 0))
FROM JOB_CONTRACT_BILLINGS
WHERE JOBNO = @JOBNO AND INVOICED = 'Y'
END;
    SELECT @SUM_INVOICEDCOST=SUM(LINECOST)
    FROM #JOB_TRANSACTIONS
    WHERE (LINE_STATUS='I' AND PROGRESSINVOICE='N')

    SELECT @SUM_WRITEOFFCOST=SUM(LINECOST), @SUM_LINECHARGE_WRITEOFF = SUM(LINECHARGE_WRITEOFF)
    FROM #JOB_TRANSACTIONS
    WHERE LINE_STATUS = 'W'

    SELECT @SUM_ASSET_COST=SUM(LINECOST), @SUM_ASSETVALUE=SUM(LINECOST)
    FROM #JOB_TRANSACTIONS
    WHERE (LINE_STATUS='A')
  END

  IF (@TYPEPARAM ='T' OR @TYPEPARAM ='*')
  BEGIN
    SELECT
      @SUM_THETIME=SUM(LINETOTAL),
      @SUM_THETIMECOST=SUM(LINECOST),
      @SUM_TOTAL_HOURS=SUM(TOTAL_QUANTITY)
    FROM #JOB_TRANSACTIONS
    WHERE TRANSTYPE = 'T' AND LINE_STATUS <> 'X' AND PROGRESSINVOICE<>'Y'
  END

  IF (@TYPEPARAM ='C' OR @TYPEPARAM ='*')
  BEGIN
    SELECT
      @SUM_MATERIALS=SUM(LINETOTAL),
      @SUM_MATERIALSCOST=SUM(LINECOST)
    FROM #JOB_TRANSACTIONS
    WHERE TRANSTYPE ='C' AND LINE_STATUS <> 'X' AND PROGRESSINVOICE<>'Y'
  END

  IF (@STATEPARAM IN ('I', 'A', 'W'))
  BEGIN
    UPDATE JOBCOST_HDR
    SET INVOICEDCOST = ISNULL(@SUM_INVOICEDCOST, 0),
INVOICED = ISNULL(@SUM_INVOICED, 0),
ASSET_COST = ISNULL(@SUM_ASSET_COST, 0),
ASSET_VALUE = ISNULL(@SUM_ASSETVALUE, 0),
WRITE_OFF_COST = ISNULL(@SUM_WRITEOFFCOST, 0),
LINECHARGE_WRITEOFF = ISNULL(@SUM_LINECHARGE_WRITEOFF, 0)
    WHERE JOBNO = @JOBNO
  END
  ELSE IF (@TYPEPARAM ='T')
  BEGIN
    UPDATE JOBCOST_HDR
    SET THETIME = ISNULL(@SUM_THETIME, 0),
THETIMECOST = ISNULL(@SUM_THETIMECOST, 0)
    WHERE JOBNO = @JOBNO
  END
  ELSE IF (@TYPEPARAM ='C')
  BEGIN
    UPDATE JOBCOST_HDR
    SET MATERIALS = ISNULL(@SUM_MATERIALS, 0),
        MATERIALSCOST = ISNULL(@SUM_MATERIALSCOST, 0)
    WHERE JOBNO = @JOBNO
  END
  ELSE IF (@TYPEPARAM ='Q')
  BEGIN
    UPDATE JOBCOST_HDR
    SET ESTIMATECOST = ISNULL(@SUM_QUOTECOST, 0),
ESTIMATE = ISNULL(@SUM_QUOTED, 0),
EST_HOURS = ISNULL(@SUM_EST_HOURS, 0)
    WHERE JOBNO = @JOBNO
  END
  ELSE IF (@TYPEPARAM ='*')
  BEGIN
    UPDATE JOBCOST_HDR
    SET INVOICED = ISNULL(@SUM_INVOICED, 0),
INVOICEDCOST = ISNULL(@SUM_INVOICEDCOST, 0),
THETIME= ISNULL(@SUM_THETIME, 0),
THETIMECOST = ISNULL(@SUM_THETIMECOST, 0),
MATERIALS = ISNULL(@SUM_MATERIALS, 0),
MATERIALSCOST = ISNULL(@SUM_MATERIALSCOST, 0),
WRITE_OFF_COST = ISNULL(@SUM_WRITEOFFCOST, 0),
EST_HOURS = ISNULL(@SUM_EST_HOURS, 0),
TOTAL_HOURS = ISNULL(@SUM_TOTAL_HOURS, 0),
ASSET_COST = ISNULL(@SUM_ASSET_COST, 0),
ASSET_VALUE = ISNULL(@SUM_ASSETVALUE, 0), /*Asset Value is at cost*/
ESTIMATECOST = ISNULL(@SUM_QUOTECOST, 0),
ESTIMATE = ISNULL(@SUM_QUOTED, 0),
LINECHARGE_WRITEOFF = ISNULL(@SUM_LINECHARGE_WRITEOFF, 0)
    WHERE JOBNO = @JOBNO
  END

  DROP TABLE #JOB_TRANSACTIONS
  DROP TABLE #JOBCOST_LINES

  SET NOCOUNT OFF
END


Procedure: RECALC_SINGLE_ITEM_LOCATION
NameRECALC_SINGLE_ITEM_LOCATION
Note
CodeCREATE PROCEDURE [dbo].[RECALC_SINGLE_ITEM_LOCATION] @STOCKCODE VARCHAR(40), @LOCATION INTEGER
AS
DECLARE @TOTAL FLOAT,
@STATUS CHAR(1),
@TOTALSTK FLOAT
BEGIN
  SELECT @STATUS=STATUS FROM STOCK_ITEMS WHERE STOCKCODE=@STOCKCODE
  IF (@STATUS='S')
  BEGIN
    SET @TOTAL = 0
    SELECT @TOTAL=ISNULL(SUM(QUANTITY), 0)
    FROM STOCK_TRANS
    WHERE STOCKCODE=@STOCKCODE AND LOCATION=@LOCATION

    UPDATE STOCK_LOC_INFO
    SET QTY=ISNULL(@TOTAL, 0)
    WHERE STOCKCODE=@STOCKCODE AND LOCATION=@LOCATION
  END
  ELSE
  BEGIN /*LOOKUP ITEM*/
    SET @TOTAL = 0
    UPDATE STOCK_LOC_INFO
    SET QTY=ISNULL(@TOTAL, 0)
    WHERE STOCKCODE=@STOCKCODE AND LOCATION=@LOCATION
  END

  SELECT @TOTALSTK=SUM(SLI.QTY)
  FROM STOCK_LOC_INFO SLI
  INNER JOIN STOCK_LOCATIONS L ON SLI.LOCATION = L.LOCNO AND L.IS_WIPLOCATION <> 'Y' -- Exclude WIP locations
  WHERE STOCKCODE=@STOCKCODE

  UPDATE STOCK_ITEMS SET TOTALSTOCK=ISNULL(@TOTALSTK, 0) WHERE STOCKCODE=@STOCKCODE
END


Procedure: RECALC_SINGLE_STOCK_ITEM
NameRECALC_SINGLE_STOCK_ITEM
Note
CodeCREATE PROCEDURE [dbo].[RECALC_SINGLE_STOCK_ITEM] @STOCKCODE VARCHAR(40)
AS
DECLARE @LOCNO INT
BEGIN
  DECLARE STOCK_ITEMS_CURSOR CURSOR LOCAL
  FOR SELECT LOCNO FROM STOCK_LOCATIONS WHERE ISACTIVE= 'Y'

  OPEN STOCK_ITEMS_CURSOR
  FETCH NEXT FROM STOCK_ITEMS_CURSOR
  INTO @LOCNO

  WHILE @@FETCH_STATUS = 0

  BEGIN
  EXEC RECALC_SINGLE_ITEM_LOCATION @STOCKCODE, @LOCNO
  FETCH NEXT FROM STOCK_ITEMS_CURSOR
  INTO @LOCNO
  END
  CLOSE STOCK_ITEMS_CURSOR
  DEALLOCATE STOCK_ITEMS_CURSOR
END


Procedure: RETURN_PROFILE_VALUE
NameRETURN_PROFILE_VALUE
Note
CodeCREATE PROCEDURE [dbo].[RETURN_PROFILE_VALUE] @FIELDNAME VARCHAR(40), @FIELDVALUE VARCHAR(200) = NULL OUTPUT
AS
BEGIN
  EXECUTE GET_PROFILE_VALUE @FIELDNAME, @FIELDVALUE OUTPUT
  SELECT FIELDVALUE=@FIELDVALUE
END


Procedure: RETURN_PROFILE_VALUE_INT
NameRETURN_PROFILE_VALUE_INT
Note
CodeCREATE PROCEDURE [dbo].[RETURN_PROFILE_VALUE_INT] @FIELDNAME VARCHAR(40), @FIELDVALUE INTEGER = 0 OUTPUT
AS
BEGIN
  EXECUTE GET_PROFILE_VALUE_INT @FIELDNAME, @FIELDVALUE OUTPUT
  SELECT FIELDVALUE=@FIELDVALUE
END


Procedure: SALESORD_LINESTATUSES
NameSALESORD_LINESTATUSES
Note
CodeCREATE PROCEDURE [dbo].[SALESORD_LINESTATUSES]
  @ORDERNO INTEGER,
  @UNRELEASED CHAR(1) OUTPUT,
  @BACKORDERED CHAR(1) OUTPUT,
  @UNSUPPLIED CHAR(1) OUTPUT,
  @UNINVOICED CHAR(1) OUTPUT,
  @UNPICKED CHAR(1) OUTPUT
AS
BEGIN
  DECLARE @UNRELEASEDQTY DOUBLE PRECISION
  DECLARE @BACKORDEREDQTY DOUBLE PRECISION
  DECLARE @UNSUPPLIEDQTY DOUBLE PRECISION
  DECLARE @UNINVOICEDQTY DOUBLE PRECISION
  DECLARE @UNPICKEDQTY DOUBLE PRECISION
   DECLARE @ISZERO CHAR(1)
  SET @UNRELEASED = 'N'
  SET @BACKORDERED = 'N'
  SET @UNINVOICED = 'N'
  SET @UNSUPPLIED = 'N'
  SET @UNPICKED = 'N'

  SELECT @UNSUPPLIEDQTY = SUM ((ORD_QUANT-CORRECTION_QUANT)-SUP_QUANT) ,
        @UNPICKEDQTY = SUM ((ORD_QUANT-CORRECTION_QUANT)-PICKED_QUANT),
        @UNINVOICEDQTY = SUM ((ORD_QUANT-CORRECTION_QUANT)-INV_QUANT ),
        @UNRELEASEDQTY = SUM ((ORD_QUANT-CORRECTION_QUANT)-RELEASE_QUANT),
         @BACKORDEREDQTY = SUM (BKORD_QUANT)
  FROM SALESORD_LINES
  WHERE HDR_SEQNO=@ORDERNO


  EXECUTE ISZERO_FLOAT @UNRELEASEDQTY, 'Y', @ISZERO OUTPUT
  IF (@ISZERO='N')
    SET @UNRELEASED = 'Y'
  EXECUTE ISZERO_FLOAT @BACKORDEREDQTY, 'Y', @ISZERO OUTPUT
  IF (@ISZERO='N')
    SET @BACKORDERED = 'Y'
  EXECUTE ISZERO_FLOAT @UNINVOICEDQTY, 'Y', @ISZERO OUTPUT
  IF (@ISZERO='N')
    SET @UNINVOICED = 'Y'
  EXECUTE ISZERO_FLOAT @UNSUPPLIEDQTY, 'Y', @ISZERO OUTPUT
  IF (@ISZERO='N')
    SET @UNSUPPLIED = 'Y'
  EXECUTE ISZERO_FLOAT @UNPICKEDQTY, 'Y', @ISZERO OUTPUT
  IF (@ISZERO='N')
    SET @UNPICKED = 'Y'

  SELECT @UNRELEASED UNRELEASED, @BACKORDERED BACKORDERED, @UNSUPPLIED UNSUPPLIED,
              @UNINVOICED UNINVOICED, @UNPICKED UNPICKED
END


Procedure: SELDEPSCHEDULE
NameSELDEPSCHEDULE
Note
CodeCREATE PROCEDURE [dbo].[SELDEPSCHEDULE]
AS
DECLARE @ASSETNO INT,
  @GRPNO INT ,
  @ASSETNAME VARCHAR(30) ,
  @STARTDATE DATETIME ,
  @STARTVALUE MONEY ,
  @DEPTODATE MONEY ,
  @YEAR1BOOKVAL MONEY ,
  @PURCHASE MONEY,
  @SELLVALUE MONEY ,
  @CAPITALGAIN MONEY ,
  @GAINLOSSSALE MONEY ,
  @DEPRATEACC MONEY ,
  @DEVDESC VARCHAR(2) ,
  @CURRENTYEAR MONEY ,
  @ACCDEP MONEY ,
  @BOOKVAL MONEY

DECLARE @intDevType int, @dblDepValue money, @intAssetStat int, @strDepInSellYr char
DECLARE BASECURSOR CURSOR FOR select AssetNo, AssetStat, DepInSellYr, GrpNo, ASSETNAME, Start_Date,
Start_Value, DepValue, Yr1_BookVal, SellValue, DepRateAcc, DepType from ASSET_REG

CREATE TABLE #tblTempResults (
  ASSETNO INT NULL,
  GRPNO INT NULL,
  ASSETNAME VARCHAR(30) NULL ,
  STARTDATE DATETIME NULL,
  STARTVALUE MONEY NULL,
  DEPTODATE MONEY NULL,
  YEAR1BOOKVAL MONEY NULL,
  PURCHASE MONEY NULL,
  SELLVALUE MONEY NULL,
  CAPITALGAIN MONEY NULL,
  GAINLOSSSALE MONEY NULL,
  DEPRATEACC MONEY NULL,
  DEVDESC VARCHAR(2) NULL,
  CURRENTYEAR MONEY NULL,
  ACCDEP MONEY NULL,
  BOOKVAL MONEY NULL
) ON [PRIMARY]

OPEN BASECURSOR
FETCH NEXT FROM BASECURSOR
into @AssetNo, @intAssetStat, @strDepInSellYr, @GrpNo, @ASSETNAME, @StartDate, @StartValue, @dblDepValue,
@Year1BookVal, @SellValue, @DepRateAcc, @intDevType
WHILE @@FETCH_STATUS = 0
BEGIN
  if (@intAssetStat<>0 and @intAssetStat<>4)
  begin
    If (@year1bookval is null)
    begin
      Set @DepToDate = 0
      if (@SellValue > @StartValue)
          Set @CapitalGain= @SellValue- @StartValue
      else
         Set @CapitalGain=0

      if (@SellValue<>0)
        Set @GainLossSale = @SellValue - @StartValue - @CapitalGain
      else
        Set @GainLossSale=0

      if (@intDevType=0)
         Set @DevDesc="SL"
      else
        Set @DevDesc="DV"

      if (@strDepinsellyr="N")
        Set @CurrentYear = 0
      else
      begin
        Set @CurrentYear=@StartValue-@dblDepValue
        Set @GainLossSale=@GainLossSale+@CurrentYear
      end
      Set @accdep=0
      Set @BookVal=0
    end
    else
    begin
      Set @DepToDate= @startvalue-@year1bookval
      Set @Purchase = 0
      if (@SellValue>@StartValue)
        Set @CapitalGain=@SellValue-@StartValue
      else
        Set @CapitalGain = 0

      if (@SellValue<>0)
      begin
        if (@SellValue<@Year1BookVal)
          Set @GainLossSale= @SellValue- @Year1BookVal
          else if (@SellValue<@StartValue)
               Set @GainLossSale= @SellValue-@Year1BookVal
        else
          Set @GainLossSale= @StartValue- @Year1BookVal
      end
      else Set @GainLossSale=0

      if (@intDevType=0)
        Set @DevDesc="SL"
      else
        Set @DevDesc="DV"
      if (@strDepinsellyr="N")
        Set @CurrentYear = 0
      else begin
        Set @CurrentYear= @StartValue - @dblDepValue
        Set @GainLossSale= @GainLossSale + @CurrentYear
      end
      Set @accdep=0
      Set @BookVal=0
    end
  end
  else
  begin
    if (@Year1BookVal is null)
      Set @Year1BookVal=0

    if (@Year1BookVal<>0)
      Set @DepToDate=@StartValue-@Year1BookVal
    else
      Set @DepToDate=0

    if (@Year1BookVal=0)
      Set @Purchase=@StartValue
    else
      Set @Purchase=0

    if (@Purchase is null)
      Set @Purchase=0

    if (@SellValue>@StartValue)
      Set @CapitalGain=@SellValue-@StartValue
    else
      Set @CapitalGain=0

    if (@SellValue<>0)
    begin
      if (@SellValue<@Year1BookVal)
        Set @GainLossSale=@SellValue-@Year1BookVal
      else
      if (@SellValue<@StartValue)
        Set @GainLossSale=@SellValue-@Year1BookVal
      else
        Set @GainLossSale=@StartValue-@Year1BookVal
    end
    else Set @GainLossSale=0


    if (@intDevType=0)
      Set @DevDesc="SL"
    else
      Set @DevDesc="DV"

    if (@Year1BookVal=0)
      Set @CurrentYear=@StartValue-@dblDepValue
    else
      Set @CurrentYear=@Year1BookVal-@dblDepValue

    Set @accdep= @CurrentYear+ @DepToDate
    Set @BookVal= @StartValue- @AccDep
  end

INSERT INTO #tblTempResults (ASSETNO, GRPNO, ASSETNAME, STARTDATE, STARTVALUE, DEPTODATE, YEAR1BOOKVAL,
  PURCHASE, SELLVALUE, CAPITALGAIN, GAINLOSSSALE, DEPRATEACC, DEVDESC, CURRENTYEAR,
  ACCDEP, BOOKVAL)
VALUES (@ASSETNO, @GRPNO, @ASSETNAME, @STARTDATE, @STARTVALUE, @DEPTODATE, @YEAR1BOOKVAL,
  @PURCHASE, @SELLVALUE, @CAPITALGAIN, @GAINLOSSSALE, @DEPRATEACC, @DEVDESC, @CURRENTYEAR,
  @ACCDEP, @BOOKVAL)

  FETCH NEXT FROM BASECURSOR
  into @AssetNo, @intAssetStat, @strDepInSellYr, @GrpNo, @ASSETNAME, @StartDate, @StartValue, @dblDepValue,
  @Year1BookVal, @SellValue, @DepRateAcc, @intDevType
end
CLOSE BASECURSOR
DEALLOCATE BASECURSOR
SELECT * FROM #tblTempResults
DROP TABLE #tblTempResults


Procedure: SELTAXSCHEDULE
NameSELTAXSCHEDULE
Note
CodeCREATE PROCEDURE [dbo].[SELTAXSCHEDULE]
AS
DECLARE @ASSETNO INT,
  @GRPNO INT ,
  @ASSETNAME VARCHAR(30) ,
  @STARTDATE DATETIME ,
  @STARTVALUE MONEY ,
  @DEPTODATE MONEY ,
  @YEAR1TAXVAL MONEY ,
  @PURCHASE MONEY,
  @SELLVALUE MONEY ,
  @CAPITALGAIN MONEY ,
  @GAINLOSSSALE MONEY ,
  @DEPRATETAX MONEY ,
  @DEVDESC VARCHAR(2) ,
  @CURRENTYEAR MONEY ,
  @ACCTAX MONEY ,
  @TAXVAL MONEY

DECLARE @intDevType int, @dblDepValue money, @intAssetStat int, @strDepInSellYr char
DECLARE BASECURSOR CURSOR FOR select AssetNo, AssetStat, DepInSellYr, GrpNo, ASSETNAME, Start_Date,
Start_Value, DepValue, Yr1_TaxVal, SellValue, DepRateTax, DepType from ASSET_REG

CREATE TABLE #tblTempResults (
  ASSETNO INT NULL,
  GRPNO INT NULL,
  ASSETNAME VARCHAR(30) NULL ,
  STARTDATE DATETIME NULL,
  STARTVALUE MONEY NULL,
  DEPTODATE MONEY NULL,
  YEAR1TAXVAL MONEY NULL,
  PURCHASE MONEY NULL,
  SELLVALUE MONEY NULL,
  CAPITALGAIN MONEY NULL,
  GAINLOSSSALE MONEY NULL,
  DEPRATETAX MONEY NULL,
  DEVDESC VARCHAR(2) NULL,
  CURRENTYEAR MONEY NULL,
  ACCTAX MONEY NULL,
  TAXVAL MONEY NULL
) ON [PRIMARY]

OPEN BASECURSOR
FETCH NEXT FROM BASECURSOR
into @AssetNo, @intAssetStat, @strDepInSellYr, @GrpNo, @ASSETNAME, @StartDate, @StartValue, @dblDepValue,
@Year1TaxVal, @SellValue, @DepRateTax, @intDevType
WHILE @@FETCH_STATUS = 0
BEGIN
  if (@intAssetStat<>0 and @intAssetStat<>4)
  begin
    If (@year1taxval is null)
    begin
      Set @DepToDate = 0
      if (@SellValue > @StartValue)
          Set @CapitalGain= @SellValue- @StartValue
      else
         Set @CapitalGain=0

      if (@SellValue<>0)
        Set @GainLossSale = @SellValue - @StartValue - @CapitalGain
      else
        Set @GainLossSale=0

      if (@intDevType=0)
         Set @DevDesc="SL"
      else
        Set @DevDesc="DV"

      if (@strDepinsellyr="N")
        Set @CurrentYear = 0
      else
      begin
        Set @CurrentYear=@StartValue-@dblDepValue
        Set @GainLossSale=@GainLossSale+@CurrentYear
      end
      Set @acctax=0
      Set @TaxVal=0
    end
    else
    begin
      Set @DepToDate= @startvalue-@year1Taxval
      Set @Purchase = 0
      if (@SellValue>@StartValue)
        Set @CapitalGain=@SellValue-@StartValue
      else
        Set @CapitalGain = 0

      if (@SellValue<>0)
      begin
        if (@SellValue<@Year1TaxVal)
          Set @GainLossSale= @SellValue- @Year1TaxVal
          else if (@SellValue<@StartValue)
               Set @GainLossSale= @SellValue-@Year1taxVal
        else
          Set @GainLossSale= @StartValue- @Year1TaxVal
      end
      else Set @GainLossSale=0

      if (@intDevType=0)
        Set @DevDesc="SL"
      else
        Set @DevDesc="DV"
      if (@strDepinsellyr="N")
        Set @CurrentYear = 0
      else begin
        Set @CurrentYear= @StartValue - @dblDepValue
        Set @GainLossSale= @GainLossSale + @CurrentYear
      end
      Set @accTax=0
      Set @TaxVal=0
    end
  end
  else
  begin
    if (@Year1TaxVal is null)
      Set @Year1TaxVal=0

    if (@Year1TaxVal<>0)
      Set @DepToDate=@StartValue-@Year1TaxVal
    else
      Set @DepToDate=0

    if (@Year1TaxVal=0)
      Set @Purchase=@StartValue
    else
      Set @Purchase=0

    if (@Purchase is null)
      Set @Purchase=0

    if (@SellValue>@StartValue)
      Set @CapitalGain=@SellValue-@StartValue
    else
      Set @CapitalGain=0

    if (@SellValue<>0)
    begin
      if (@SellValue<@Year1TaxVal)
        Set @GainLossSale=@SellValue-@Year1TaxVal
      else
      if (@SellValue<@StartValue)
        Set @GainLossSale=@SellValue-@Year1TaxVal
      else
        Set @GainLossSale=@StartValue-@Year1TaxVal
    end
    else Set @GainLossSale=0


    if (@intDevType=0)
      Set @DevDesc="SL"
    else
      Set @DevDesc="DV"

    if (@Year1TaxVal=0)
      Set @CurrentYear=@StartValue-@dblDepValue
    else
      Set @CurrentYear=@Year1TaxVal-@dblDepValue

    Set @accTax= @CurrentYear+ @DepToDate
    Set @TaxVal= @StartValue- @AccTax
  end

INSERT INTO #tblTempResults (ASSETNO, GRPNO, ASSETNAME, STARTDATE, STARTVALUE, DEPTODATE, YEAR1TAXVAL,
  PURCHASE, SELLVALUE, CAPITALGAIN, GAINLOSSSALE, DEPRATETAX, DEVDESC, CURRENTYEAR,
  ACCTAX, TAXVAL)
VALUES (@ASSETNO, @GRPNO, @ASSETNAME, @STARTDATE, @STARTVALUE, @DEPTODATE, @YEAR1TAXVAL,
  @PURCHASE, @SELLVALUE, @CAPITALGAIN, @GAINLOSSSALE, @DEPRATETAX, @DEVDESC, @CURRENTYEAR,
  @ACCTAX, @TAXVAL)

  FETCH NEXT FROM BASECURSOR
  into @AssetNo, @intAssetStat, @strDepInSellYr, @GrpNo, @ASSETNAME, @StartDate, @StartValue, @dblDepValue,
  @Year1TAxVal, @SellValue, @DepRateTax, @intDevType
end
CLOSE BASECURSOR
DEALLOCATE BASECURSOR
SELECT * FROM #tblTempResults
DROP TABLE #tblTempResults


Procedure: SPECIAL_PRICE
NameSPECIAL_PRICE
Note
CodeCREATE PROCEDURE [dbo].[SPECIAL_PRICE]
  @ACCNO INTEGER,
  @ACCGROUP INTEGER,
  @STOCKCODE VARCHAR(23),
  @PRICEGROUP INTEGER,
  @QTY DOUBLE PRECISION,
  @ATDATE DATETIME,
  @BASE_PRICE FLOAT,
  @IS_DISCOUNTABLE CHAR(1),
  @JOBNO INT=-1,
  @MASTER_JOBNO INT=-1,
  @BEST_INT1 INT=-1,
  @BEST_INT2 INT=-1,
  @BEST_VAR1 VARCHAR(50)='',
  @SPECIAL_PRICE FLOAT OUTPUT,
  @SPECIAL_DISCOUNT FLOAT OUTPUT,
  @POLICY_HDR INTEGER OUTPUT,
  @FREIGHT_FREE CHAR(1) OUTPUT,
  @FIXEDPOLICY CHAR(1) OUTPUT
AS
BEGIN
  DECLARE @TMP_SPECIALS TABLE (
    SPECIAL_PRICE FLOAT,
    SPECIAL_DISCOUNT FLOAT,
    POLICY_HDR INTEGER,
    FREIGHT_FREE CHAR(1),
    FIXED CHAR(1)
  )
  DECLARE @FIXED_POLICY CHAR(1)
  SET @FIXED_POLICY='N'

  DECLARE @PRICE_VAR FLOAT,
    @DISCOUNT_VAR FLOAT,
    @POLICY_HDR_VAR INTEGER,
    @FREIGHT_FREE_VAR CHAR(1),
    @FIXEDPOLICY_VAR CHAR(1)

  DECLARE SPECIALS_CURSOR CURSOR FOR
  SELECT
    D.PRICE, D.DISCOUNT, D.POLICY_HDR, D.FREIGHT_FREE, T.FIXED
  FROM
    DR_PRICES D
  LEFT JOIN DR_PRICE_POLICY_ACC C ON C.POLICY_HDR=D.POLICY_HDR
  LEFT JOIN DR_PRICE_POLICY T ON T.POLICY_HDR = C.POLICY_HDR
  WHERE
    ((D.ACCNO=@ACCNO) OR (D.ACCNO=-1 AND D.POLICY_HDR IS NULL) OR
     (C.ACCNO=@ACCNO OR C.ACCGROUP=@ACCGROUP)) AND
    (D.STOCKCODE=@STOCKCODE OR D.STOCKPRICEGROUP=@PRICEGROUP) AND
    (@ATDATE>=D.STARTDATE) AND (@ATDATE<=D.STOPDATE) AND
    (@QTY >= D.MINQTY) AND (T.IS_ACTIVE <> 'N' OR T.POLICY_HDR IS NULL) AND D.SELL_PRICE_BANDNO = -1
  ORDER BY D.SEQNO DESC
  OPEN SPECIALS_CURSOR
  FETCH NEXT FROM SPECIALS_CURSOR
  INTO @PRICE_VAR, @DISCOUNT_VAR, @POLICY_HDR_VAR, @FREIGHT_FREE_VAR, @FIXEDPOLICY_VAR

  WHILE @@FETCH_STATUS = 0
  BEGIN
    IF ((@PRICE_VAR IS NOT NULL) AND (@PRICE_VAR>0)) OR ((@IS_DISCOUNTABLE='Y') AND
      (@DISCOUNT_VAR IS NOT NULL) AND (@DISCOUNT_VAR>0))
    BEGIN
      IF (@PRICE_VAR IS NULL)
        SET @PRICE_VAR = @BASE_PRICE - (@BASE_PRICE * @DISCOUNT_VAR/100)
      IF (@DISCOUNT_VAR IS NULL) OR ((@DISCOUNT_VAR>0) AND (@IS_DISCOUNTABLE='Y'))
        INSERT INTO @TMP_SPECIALS (
          SPECIAL_PRICE, SPECIAL_DISCOUNT, POLICY_HDR, FREIGHT_FREE, FIXED)
        VALUES (
          @PRICE_VAR, @DISCOUNT_VAR, @POLICY_HDR_VAR, @FREIGHT_FREE_VAR, @FIXEDPOLICY_VAR
        )
    END
    FETCH NEXT FROM SPECIALS_CURSOR
    INTO @PRICE_VAR, @DISCOUNT_VAR, @POLICY_HDR_VAR, @FREIGHT_FREE_VAR, @FIXEDPOLICY_VAR
  END

  CLOSE SPECIALS_CURSOR
  DEALLOCATE SPECIALS_CURSOR
  SELECT @FIXED_POLICY=FIXED FROM @TMP_SPECIALS WHERE FIXED = 'Y'

  IF (@FIXED_POLICY = 'Y')
  BEGIN
    DECLARE SPECIALS_CURSOR2 CURSOR FOR
    SELECT SPECIAL_PRICE, SPECIAL_DISCOUNT, POLICY_HDR, FREIGHT_FREE, FIXED FROM @TMP_SPECIALS WHERE FIXED = 'Y'
  END
  ELSE
  BEGIN
    DECLARE SPECIALS_CURSOR2 CURSOR FOR
    SELECT SPECIAL_PRICE, SPECIAL_DISCOUNT, POLICY_HDR, FREIGHT_FREE, FIXED FROM @TMP_SPECIALS ORDER BY SPECIAL_PRICE ASC
  END

  OPEN SPECIALS_CURSOR2
  FETCH NEXT FROM SPECIALS_CURSOR2
  INTO @SPECIAL_PRICE, @SPECIAL_DISCOUNT, @POLICY_HDR, @FREIGHT_FREE, @FIXEDPOLICY
  CLOSE SPECIALS_CURSOR2
  DEALLOCATE SPECIALS_CURSOR2
END


Procedure: SP_BEST_PRICE_SELECT
NameSP_BEST_PRICE_SELECT
Note
CodeCREATE PROCEDURE [dbo].[SP_BEST_PRICE_SELECT]
AS
BEGIN
SET NOCOUNT ON

DELETE
FROM BEST_PRICE_VALUES

DECLARE @ACCNO INT, @PRICENO INT, @STOCKCODE VARCHAR(23), @DSTOCKCODE VARCHAR(23), @BEST_PRICE FLOAT,
@DISCOUNT_AMOUNT FLOAT, @IS_SPECIAL_PRICE CHAR(1), @POLICY_HDR INT, @FREIGHT_FREE CHAR(1),
@FIXEDPOLICY CHAR(1), @DATE DATETIME

SELECT @DATE = GETDATE()

--POPULATE BEST_PRICE_VALUES WITH VIEW LIKE DATA FROM BEST_PRICE STORED PROC
DECLARE ACCNO_STOCKCODE_CURSOR CURSOR
FOR
SELECT A.ACCNO, A.PRICENO, S.STOCKCODE AS STOCKCODE, D.STOCKCODE AS DSTOCKCODE
FROM STOCK_ITEMS S
CROSS JOIN DR_ACCS A
LEFT JOIN DR_PRICES D ON S.STOCKCODE = D.STOCKCODE

OPEN ACCNO_STOCKCODE_CURSOR

FETCH NEXT
FROM ACCNO_STOCKCODE_CURSOR
INTO @ACCNO, @PRICENO, @STOCKCODE, @DSTOCKCODE

WHILE @@FETCH_STATUS = 0
BEGIN
EXEC BEST_PRICE @STOCKCODE, @ACCNO, 1, @DATE, 'S', - 1, - 1, - 1, - 1, '', @BEST_PRICE OUTPUT,
@DISCOUNT_AMOUNT OUTPUT, @IS_SPECIAL_PRICE OUTPUT, @POLICY_HDR OUTPUT, @FREIGHT_FREE OUTPUT,
@FIXEDPOLICY OUTPUT

INSERT INTO BEST_PRICE_VALUES (STOCKCODE, CUSTOMER, PRICE, DISCOUNTEDPRICE, DISCOUNT, IS_SPECIAL_PRICE
)
VALUES (
@STOCKCODE, @ACCNO, @BEST_PRICE,
isnull(@BEST_PRICE, 0) - isnull(@DISCOUNT_AMOUNT, 0),
@DISCOUNT_AMOUNT, @IS_SPECIAL_PRICE
)

FETCH NEXT
FROM ACCNO_STOCKCODE_CURSOR
INTO @ACCNO, @PRICENO, @STOCKCODE, @DSTOCKCODE
END

CLOSE ACCNO_STOCKCODE_CURSOR

DEALLOCATE ACCNO_STOCKCODE_CURSOR
END


Procedure: sp_CreateMenu
Namesp_CreateMenu
Note
CodeCreate PROCEDURE [dbo].[sp_CreateMenu](
@hdrseqno int,
@caption varchar(100))
As
begin

declare @parentid int
declare @count int
select @count=count(parentid) from menu_lines where caption = @caption and hdrseqno=@hdrseqno and appid=1 and procid=0


if @count=1

Begin

select @parentid=parentid from menu_lines where caption = @caption and hdrseqno=@hdrseqno and appid=1 and procid=0

-- Update workspace coordinates
update menu_lines set lineclasscoordinates = '20, 15, 815, 510'
where lineclass=0 and appid=1 and hdrseqno = @hdrseqno

-- Move Reports button to bottom left corner
update menu_lines set lineclasscoordinates='20, 350, 100, 23',
lineclassproperties='|FName=clTahoma|FSize=8|FColor=clBlack|FStyle=;;;|Flat=N|Arrow=Y|GlyphPos=Left|Align=None|Anchors=Left+Bottom|II0=0|II1=0|II2=0|Hottrack=N|Border=N|Color=clBtnFace|Transparent=Y|WordWrap=N|HFName=clTahoma|HFSize=8|HFColor=clBlack|HFStyle=;;;|TextPos=Center|ILN=SmallButton'
where caption = 'reports' and hdrseqno=@hdrseqno and parentid = @parentid

-- Adding a new panel
declare @newparentid int

insert into menu_lines (hdrseqno, appid, caption, procparams, lineclass, lineclasscoordinates, lineclassproperties, parentid, menuimage, menuimage1, menuimage2)
values (@hdrseqno, 1, '', '', 3, '0, 0, 815, 510', '|Color=clBtnFace|EndColor=clBtnFace|Gradient=Horizontal|Align=None|Transparent=Y|Anchors=Top',
@parentid, 0x20, 0x20, 0x20)

SELECT @newparentid=@@IDENTITY

-- Move buttons to panel
update Menu_lines set parentid = @newparentid
where parentid = @parentid and seqno <> @newparentid and lineclass <> 6 and caption <> 'reports'

-- Move EXO Logo and dock to bottom right corner
if @caption = 'Stock Valuation Report'
begin
update menu_lines set lineclasscoordinates = '690, 285, 104, 81'
where lineclassproperties like '%Source=ExoLogo%' and parentid = @parentid
end
else if @caption ='maintain debtors' or @caption = 'maintain creditors'
begin
-- Move panel 15 pix to the right and reduce height to 350
update menu_lines set lineclasscoordinates = '15, 0, 815, 290'
where seqno = @newparentid

update menu_lines set lineclasscoordinates = '690, 285, 104, 81'
where lineclassproperties like '%Source=ExoLogo%' and parentid = @parentid
end
else
begin
-- Move panel 15 pix to the right and reduce height to 350
update menu_lines set lineclasscoordinates = '15, 0, 815, 510'
where seqno = @newparentid

update menu_lines set lineclasscoordinates = '690, 285, 104, 81'
where lineclassproperties like '%Source=ExoLogo%' and parentid = @parentid
end

-- Add M-Powered buttons
declare @mpower varchar (200)
declare @mpowercomponent varchar (200)

if @caption='maintain debtors'
begin
select @mpower='M-Powered'+char(13)+'Services '
select @mpowercomponent='M-Powered Details'
end

if @caption='maintain creditors'
begin
select @mpower='M-Powered'+char(13)+'Service '+char(13)+'Center '
select @mpowercomponent='M-Powered Service Center'
end

if len(@mpower) > 0
begin

declare @proccount int
select @proccount=Max(procid)+10 from menu_lines where hdrseqno=@hdrseqno


insert into menu_lines (hdrseqno, appid, caption, procparams, lineclass, lineclasscoordinates, lineclassproperties, sortorder, parentid, menuimage, menuimage1, menuimage2)
values (@hdrseqno, 1, @mpower, '', 14, '565, 290, 120, 50', '|FName=clTahoma|FSize=8|FColor=clBlue|FStyle=;;;|Color=clBtnFace|Transparent=Y|Hottrack=N|WordWrap=N|Border=N|Align=None|Anchors=Right+Bottom|HFName=clTahoma|HFSize=8|HFColor=clRed|HFStyle=;;;|TextPos=Right|II0=0|II1=None|II2=None|ILN=Private',
500, @parentid, 0x424D662A000000000000360000002800000036000000320000000100200000000000302A000000000000000000000000000000000000CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700BBC7D000B6C5D100B9C5D100BCC6CF00C1C8CE00C6CACC00CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700BCC7CF008FB9DC0071A3E5006D98E5006F99E500739CE40078A1E20085A8DE0096B2D900A9BDD400BDC7CE00C9CACA00CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CBCBC900CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700B2C1CF0087AFDC006A99E5005185EC004076F2003D72F3003E74F2003F74F1004377EF004B7CEC005985E7006E93E1008BA9D900AABCD100C2C6C900CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700C9C8C600CAC9C700CAC9C700C9C8C600CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700ADBED00097AED70083A0DD006E93E4005383ED004377F3004273F3003F71F2003C6EF200386AF2003467F1003266F1003A6EEE005180E7007A9EDD00A8BAD100CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700C9C8C600CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700B6C1CD00A1B3D4008AA6DC007198E5005789EE00477BF3004577F3004174F3003D6FF200386AF2003365F1002E5FF000295CF0002D60EF004977E7007EA0DB00B5BFCC00CAC9C700CAC9C700CAC9C700C9C8C600CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700BEC5CA00A6B8D3008DA9DC00759AE5005789F0004B7FF4004678F3004174F3003C6EF2003668F1003163F1002B5CF0002656EF002351EE002455ED004878E70090AFD700C4C6C800CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700C9C8C600CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700C2C4C900A3B2D2008FA6D9007A9EE00074A2E600609FF000599DF300569BF2005498F2004B86EE004681EE004177EB003A69E9003767EA003061EC002A5BEF002352EE00204CED001D48EB002454EA006291E100B3C2CE00CAC9C700CAC9C700CAC9C700C9C9C700CAC9C700CAC9C700CAC9C700C9C9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700ADB7D00083A0DD005F99F0006AAEF6006FBBFA0070C1FC006EBFFC006CBEFC0068BCFC0065BAFC0060B8FB005CB4FB0057B0FB0052ACFB004DA7FB004393F4003B86F0003270E8002A5EE400234EE6001E48E9001940EA00173EE900396DE7009EB4D400CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700ACB7D0006693E70068A7F40074C0FB0077C4FC0078C5FC0078C5FC0076C4FC0074C3FC0071C1FC006DBFFC0069BDFC0065BBFC0060B7FB005BB3FB0055AEFB0050AAFB004AA5FA0045A0FA003F9CFA003997FA003387F4002E72EB00285AE2001F46E4001336E6002353E60088ADD900CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700809DDD006097F00074C0FB0079C5FC007CC7FC007DC8FC007EC8FC007EC8FC007CC7FC0079C6FC0076C4FC0071C1FC006ABDFC0063B9FC005EB6FC0058B1FB0053ACFB004EA7FB0048A3FB00439DFA003E98FA003893FA00338EF900338EF900338EF9002E7DF1002A62E5002045DE001943E10077A1D400C9C7C500CAC8C600CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C70087A2DB006193EB006CACF5007BC2FA0081CAFC0084CBFC0085CCFC0084CBFC0082CAFC007FC8FC007BC6FC0072C2FC005FB8FC004EADFB0047A7FB0043A2FA003F9CFA003B96FA00378FFA003389F9002D7AF4002465E1001F5DDA001E5CD9001F60EC002364ED00215AE600215AE6001F45D9001B3CD300648AC900C0BEBC00C8C6C400CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700ACB7D00089A3DB0074A0EA0080BCF70089CCFB008ACEFC0087CDFC0084CBFC007FC8FC007BB6DD00D19B5F00D29D6300D19B5E00CF985900CE955500CD925000CB8F4B00CA8C4600C9894100C8863D00C6833800C5803400C37D2F00C27A2A00C1772500BF752100A367360072546700343BAC004768CA00B5B3B100C5C3C200CAC8C600CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CBC9C700CBC9C700A4B2D2007FA1E4007EB2F4008BCDFB0088CDFC0082CAFC007CB7DD00D9AB7900DBB28500DEBA9200DCB78E00DAB38900D7B08400D5AC8000D2A87A00CFA37500CC9F7000C89A6A00C4956400C0905E00BC8C5900BA885400B47B4200B4732F00BC722000BC6C13006B4A66003A56C300B1AFAD00C6C4C200CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CACAC800CACAC800CAC9C700CAC9C700ACB7D10086A9E60080BAF70085CCFC0073A9D800D9AB7900E5C9AB00F9F8F800F7F7F700F5F5F500F2F2F200EFEFEF00ECEBEB00E7E7E700E3E1E200DDDBDC00D7D5D500CFCDCE00C7C5C600C0BEBF00BAB7B800B2ADAA00A78B7300AD703200BA6A10007F504A003A54C000B7B6B400C9C8C600CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C9005496EC005081E9003B57C000D9AB7900E6CCAE00FAFAFA00F9F8F800F7F7F700F5F5F500F3F2F200F0EFEF00ECEBEB00E8E7E700E3E2E200DDDCDC00D7D5D500CFCECE00C7C5C600C0BEBF00BAB7B800B3B0B000A99E9600A76D3400B9670B00584E84004E63C600C4C2C000CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700AEBFD0002E67E7002558DF004682D700D9AB7900E7CEB100FBFBFB00FAFAFA00F9F8F800F7F7F700F5F5F500F3F2F200F0EFEF00ECEBEB00E8E7E700E3E2E200DDDCDD00D7D6D500D0CECF00C7C6C700C0BEBF00BAB7B800B3B0B000A99A8F00B2671800A46223001E58E9005D74CE00CAC8C600CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C7007095DB002A5ADE003D95F9004D8DDA00D9AB7900E9D0B300FCFCFC00E9D0AC00CD923E00CB8E3E00ECDCC900F6F5F500E7D6C500BF7D3C00BF824900E4DED900E3E2E200C29A7C00A9643500A45F3300AF866F00C0BEBF00BAB7B800B3B0B000AA764400B76305003C67C8002869EB008C9BCE00CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CBCAC800CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700C4C5CA00355FDD004191F4004BA4FA00599BDB00D9AB7900EAD2B600FCFCFC00EEDBBD00C2750000BF700000DEBB8C00F7F7F700DEBE9900B35D0000AF580000CC9F7500E8E8E800C7A080009E4500009A400000A4603300C8C7C700C0BFBF00BAB7B800AD907800B863060058649A002D82F8002C67E600BABECB00CAC9C700CAC9C700CBCAC800CAC9C700CAC9C700CAC9C700CBCAC800CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CBCAC800CAC9C700859BD600407CEA0053ABFA005AB1FA0064A7DC00D9AB7900EBD3B800FDFDFD00F9F4ED00C57B0000C2760000D9AD6D00F9F8F800D8AF7C00B7630000B45E0000B4620F00E9E3DD00D8C2AE00A34A00009F4500009B410000D1CFD000C9C7C800C1BFBF00B1968100B864060057639A002C81F8002F78EE006582D600CAC9C700CAC9C700CAC9C700CBCAC800CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700668ADE00529EF40061B7FB0068BCFC006FAFDD00D9AB7900ECD5BB00FEFEFE00FDFDFD00CE902000C57C0000D1983F00FAFAFA00D0984E00BB680000B8630000B55F0000D1A57700EDECEC00A8500000A44B0000A0460000D1C4BC00D1D0D000C9C7C800B69C8600B864060057639A002C81F8003592F9003469E200CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C7006B8FE00066BBFC006DBFFC0074C2FC0079B4DD00D9AB7900ECD7BD00FEFEFE00FEFEFE00DAAB4F00C8820000C9851000FBFBFB00CF943F00BE6E0000C37B1F00B8640000B9690F00EDE7E100B9722D00A9510000A54C0000CBAF9800D9D8D700D2D0D100BEA48E00B864060057639A002C81F8003592F900307BEE009AACD300CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C7007497E20072C1FC0079C5FC007FC8FC0082BADD00D9AB7900EDD8C000FEFEFE00FEFEFE00E6C47F00CC870000C9830000F9F4EC00C4790000C1740000CD923E00D29F5D00B9650000D5AA7900CA935A00AE570000AA520000C5987100DFDEDE00DAD8D800C5AC9600B864060057639A002C81F8003592F900348CF5007189D500CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C70082A1E1007BC3FB0083CAFC0088CDFC008BBEDD00D9AB7900EED9C100FFFFFF00FEFEFE00F0DCAF00CF8D0000CC880000F0DEBD00C77F0000C47A0000D0963E00EEDECA00BC6B0000BD6F0F00D9B38900B35D0000AF580000BA783A00E5E4E400E0DFDF00CCB49E00B864060057639A002C81F8003592F9003694F9005A7BDB00CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700A4B8DA007EBAF7008CCFFC0091D1FC0093C2DD00D9AB7900EED9C100FFFFFF00FFFFFF00F9F1DE00D2930000CF8E0000DFB55F00CA840000C7800000E0BB7D00FAFAFA00CD933E00BD6C0000D09D5C00B7620000B45D0000B86B1D00EAE9E900E5E4E400D2BBA500B864060057639A002C81F8003592F9003590F7005A7BDB00CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700C4CBCF0080AFF30094D2FC0099D5FC009AC5DD00D9AB7900EED9C100FFFFFF00FFFFFF00FFFFFF00D79F1000D2940000D8A43000CD8A0000CA850000E2BF7E00FBFBFB00ECD9BC00C0720000C47F1F00BB680000B8630000B55F0000EAE4DF00EAEAE900D8C1AC00B864060057639A002C81F8003592F900307BEE006C87D700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C7009FB7E20096CAF900A0D8FC00A0C8DD00D9AB7900EED9C100FFFFFF00FFFFFF00FFFFFF00E1B54000D59A0000D3950000D0900000CD8B0000EDD8AD00FCFCFC00FBFBFB00D0983F00C0730000BE6E0000BB690000B8640000E3CDB400EEEEEE00DDC8B200B864060057639A002C81F8003592F9002B6AE70098A9D400CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700B5BED30096C0F600A6DBFC00A6CBDD00D9AB7900EED9C100FFFFFF00FFFFFF00FFFFFF00E9C77000D79C0000D69A0000D3960000D1910000F2E1BE00FCFCFC00FCFCFC00EEDBBD00C3790000C1740000BE6F0000BC6A0000D7AD7900F2F1F100E1CDB800B864060057639A002C81F8003181F200335EDE00CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700AABEE100A5D1F900ABD9F400D4A06700E4C49F00FFFFFF00FFFFFF00FFFFFF00F0DA9F00D79C0000D79C0000D69B0000D4970000FBF7EE00FDFDFD00FCFCFC00FCFCFC00D49D3F00C47A0000C1750000BF700000D29F5C00F4F4F300E5D2BD00B864060057639A002C81F800295AE0007DA7DC00CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700B1C5E500AAD3F900C5A57B00DCB38400FAF3EB00FFFFFF00FFFFFF00FFFFFF00FFFFFF00FFFFFF00FFFFFF00FEFEFE00FEFEFE00FEFEFE00FDFDFD00FCFCFC00FCFCFC00FCFBFB00FAFAFA00F9F9F900F8F8F800F6F6F600E7D5C100B8640600564F8A002251DF00204EE100B5C4D100CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700ADC6EE00B4B9BC00D7A77300E4C39D00FEFDFB00FFFFFF00FFFFFF00FFFFFF00FFFFFF00FFFFFF00FFFFFF00FEFEFE00FEFEFE00FEFEFE00FDFDFD00FCFCFC00FCFCFC00FCFCFC00FAFAFA00FAF9F900F8F8F800EAD8C500B86406006B7896005381E900538FE700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C7009AB9EE00BF9D7A00D6A56E00E6C9A600FBF6EF00FFFFFF00FFFFFF00FFFFFF00FFFFFF00FFFFFF00FFFFFF00FEFEFE00FEFEFE00FEFEFE00FDFDFD00FDFCFC00FCFCFC00FCFCFC00FAFAFA00FAFAF900ECDCC900B8640600889D9D0083CBFC007FB6F6007FA3E500AEB9D200CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700C5C6CB0099B7E200BE9B7800D4A16800DBAF7E00E5C6A200EEDAC200F7ECDF00F7ECDF00F7ECDF00F7ECDF00F6ECDF00F6ECDE00F6EBDE00F5EADC00F4E8DA00F3E6D700F2E5D500F1E3D300EFE0D000E8D1B600B86406008EA19D0088CEFC008ED0FC0086C9FB006DA5F3006C93E5009DAFD600CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C70088A8E400ABADB700C5986600CF965600CF975700D19B5E00CF975700CE935100CC8F4B00CA8B4500C8873F00C6833800C57F3200C37C2C00C1782600BF741F00BD701900BB6C1300BA680C00B864060098A49D0090D1FC0092D2FC008ACEFC0080C8FC0073BFFB005FA6F5005489EA007A98DC00A6B4D400C6C7CC00CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700A0C2DB008AB1F300B1C3DC00C0C7C100C0BCA900BFBBA800BFBBA700BEBAA700BDBAA600BCB9A500BCB9A400BAB7A300B9B6A300B8B5A200B6B4A100B3B2A000B0B0A000ACAE9F00A9AC9E009FC4D5009AD6FC0096D3FC008DCFFC0083CAFC0077C4FC006ABDFC005BB2FA004AA0F8003C81EF003562E000879CD700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700ABC7D80074AAF2008CB3F500B8D6F800C3E3FB00C7EAFC00C7EAFC00C6EAFC00C5EAFC00C4EAFC00C3E9FC00C1E8FC00BFE7FC00BCE6FC00B9E5FC00B6E2FC00B1E0FC00ACDEFC00A6DBFC00A1D9FC0099D5FC0090D0FC0085CBFC007AC5FC006DBFFC005EB5FB004EA7FA003B8BF3003160E0008AA1D900CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700B2C7D6007EB6F000699CF60082ABF600ABCAF800C1DEFA00C4E3FB00C7EAFC00C6EAFC00C4EAFC00C3E8FC00C1E8FC00BFE7FC00BCE6FC00B8E4FC00B4E1FC00AFDFFC00A9DDFC00A3D9FC009AD6FC0091D1FC0087CCFC007CC6FC006EBFFC005DAFF9004786ED006588DE00AEBAD300CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700BCC7D3008ABAEB00669DF7006093F6006A99F60086AEF7009DBFF600B7D6F800BFDFFA00C1E3FB00C0E5FC00BFE7FC00BDE6FC00B9E4FC00B5E2FC00B0E0FC00AADDFC00A3DAFC009CD6FC0092D2FC0084C2F90072ADF5006396EC007F9CDE00B7BFD100CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700C6CBCE009BC1E20071A7F3006095F6005C8FF6005A8CF500578AF5006895F500719CF40082A9F60086ABF40098BDF70095BBF60094BCF50090B9F4008FBCF50091B9F0008BB1E9009AB2DF0096ADDC00AFBAD300CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700B1C7D70088B4E800679BF4005A8FF600578AF5005486F5005083F4004D7FF400497BF4004476F3003E70F200396CF2003D72F0005C86E7007C9ADF0099AED800B8C4D100CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700C3C9CF00A6C0DB0081A9E9006396F200538AF5004F83F4004C7EF400477AF3004275F3003D6FF2003769F1003165F1003B6FEE005982E6007794DF0094A8D800B0BDD300C5CACE00CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700B9C6D2009AB7DD007BA4E7006292EE005084F200477AF4004174F3003C6EF2003667F1002F60F0002A5DF0003667ED00547AE4006E8BDF0087A1DA00A6BCD600CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700BAC5D200A2BADA008BABE100739BE6005E8CEA004F81EC004176EF00376CEF003064EE002E61ED003F72EA005E8FE50089B2DF00BAC7D000CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700C5C9CF00B5C2D400A2BBD90092B1DD0084A7E000799DE0007496E1007095E00072A0E20095B9DC00C6CBD000CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700C5CACE00C2CAD000BDC9D100BDC9D100C0C9D000CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700CAC9C700, 0x20, 0x20)

declare @newbtnparentid int

SELECT @newbtnparentid=@@IDENTITY

insert into menu_lines (hdrseqno, appid, caption, procparams, lineclass, lineclasscoordinates, lineclassproperties, sortorder, parentid, menuimage, menuimage1, menuimage2, procid)
values (@hdrseqno, 1, @mpowercomponent, '', 9, '0, 0, 5, 5', ' ', 20, @newbtnparentid, 0x20, 0x20, 0x20, @proccount)

end

end
else

Print 'Could not update hdrseqno=' + cast(@hdrseqno as varchar(100)) +' and caption='+@caption


end


Procedure: sp_CreateMenu1
Namesp_CreateMenu1
Note
CodeCREATE PROCEDURE [dbo].[sp_CreateMenu1](
@hdrseqno int,
@caption varchar(100))
As
begin

declare @parentid int
declare @count int
select @count=count(parentid) from menu_lines where caption = @caption and hdrseqno=@hdrseqno and appid=300 and procid=0


if @count=1

Begin

select @parentid=parentid from menu_lines where caption = @caption and hdrseqno=@hdrseqno and appid=300 and procid=0

-- Update workspace coordinates
update menu_lines set lineclasscoordinates = '20, 15, 815, 510'
where lineclass=0 and appid=300 and hdrseqno = @hdrseqno

-- Move Reports button to bottom left corner
update menu_lines set lineclasscoordinates='20, 350, 100, 23',
lineclassproperties='|FName=clTahoma|FSize=8|FColor=clBlack|FStyle=;;;|Flat=N|Arrow=Y|GlyphPos=Left|Align=None|Anchors=Left+Bottom|II0=0|II1=0|II2=0|Hottrack=N|Border=N|Color=clBtnFace|Transparent=Y|WordWrap=N|HFName=clTahoma|HFSize=8|HFColor=clBlack|HFStyle=;;;|TextPos=Center|ILN=SmallButton'
where caption = 'reports' and hdrseqno=@hdrseqno and parentid = @parentid

-- Adding a new panel
declare @newparentid int

insert into menu_lines (hdrseqno, appid, caption, procparams, lineclass, lineclasscoordinates, lineclassproperties, parentid, menuimage, menuimage1, menuimage2)
values (@hdrseqno, 300, '', '', 3, '0, 0, 815, 510', '|Color=clBtnFace|EndColor=clBtnFace|Gradient=Horizontal|Align=None|Transparent=Y|Anchors=Top',
@parentid, 0x20, 0x20, 0x20)

SELECT @newparentid=@@IDENTITY

-- Move buttons to panel
update Menu_lines set parentid = @newparentid
where parentid = @parentid and seqno <> @newparentid and lineclass <> 6 and caption <> 'reports'

-- Move EXO Logo and dock to bottom right corner
if @caption ='Direct Material Entry'
begin
-- Move panel 15 pix to the right and reduce height to 350
update menu_lines set lineclasscoordinates = '15, 0, 815, 290'
where seqno = @newparentid

update menu_lines set lineclasscoordinates = '690, 285, 104, 81'
where lineclassproperties like '%Source=ExoLogo%' and parentid = @parentid
end
else
begin
-- Move panel 15 pix to the right and reduce height to 350
update menu_lines set lineclasscoordinates = '15, 0, 815, 510'
where seqno = @newparentid

update menu_lines set lineclasscoordinates = '690, 285, 104, 81'
where lineclassproperties like '%Source=ExoLogo%' and parentid = @parentid
end

end
else

Print 'Could not update hdrseqno=' + cast(@hdrseqno as varchar(100)) +' and caption='+@caption


end


Procedure: SP_CRM_BUDGET_FILLACTUALS
NameSP_CRM_BUDGET_FILLACTUALS
Note
CodeCREATE PROCEDURE [dbo].[SP_CRM_BUDGET_FILLACTUALS]
  (@budgetSeqno int, @Actuals bit, @LYActuals bit)
AS
BEGIN
declare @sql varchar(max), @joins varchar(max)
declare @act_period int, @ly_period int, @level_accgroup bit, @level_accgroup2 bit, @level_accno bit, @level_stockgroup bit, @level_stockgroup2 bit, @level_stockcode bit, @level_branch bit, @level_staff bit
declare @period int, @column varchar(max), @srcview varchar(max)
--get structure
select
@act_period = ACTUAL_PERIOD_STATUS_SEQNO,
@ly_period = LYACTUAL_PERIOD_STATUS_SEQNO,
@level_accgroup = LEVEL_ACCGROUP,
@level_accgroup2 = LEVEL_ACCGROUP2,
@level_accno = LEVEL_ACCNO,
@level_stockgroup = LEVEL_STOCKGROUP,
@level_stockgroup2 = LEVEL_STOCKGROUP2,
@level_stockcode = LEVEL_STOCKCODE,
@level_branch = LEVEL_BRANCH,
@level_staff = LEVEL_STAFF
from CRM_BUDGET where SEQNO = @budgetSeqno
--build joins
set @joins = ''
if @level_accgroup = 1
set @joins = @joins + 'AND L.ACCGROUP = ACT.ACCGROUP '
if @level_accgroup2 = 1
set @joins = @joins + 'AND L.ACCGROUP2 = ACT.ACCGROUP2 '
if @level_accno = 1
set @joins = @joins + 'AND L.ACCNO = ACT.ACCNO '
if @level_stockgroup = 1
set @joins = @joins + 'AND L.STOCK_GROUPNO = ACT.STOCKGROUP '
if @level_stockgroup2 = 1
set @joins = @joins + 'AND L.STOCK_GROUPNO2 = ACT.STOCKGROUP2 '
if @level_stockcode = 1
set @joins = @joins + 'AND L.STOCKCODE = ACT.STOCKCODE '
if @level_branch = 1
set @joins = @joins + 'AND L.BRANCHNO = ACT.BRANCHNO '
if @level_staff = 1
set @joins = @joins + 'AND L.SALESNO = ACT.SALESNO '
--build sql
if @Actuals = 1
begin
set @column = 'ACTUAL'
set @srcview = 'VW_CRM_ACTUAL_SALES'
set @period = @act_period
end
if @LYActuals = 1
begin
set @column = 'LYACTUAL'
set @srcview = 'VW_CRM_LYACTUAL_SALES'
set @period = @ly_period
end
set @sql =
'update CRM_BUDGET_LINE set '+@column+' = S.ACTUAL '+
' from '+
' CRM_BUDGET_LINE UL inner join '+
' ('+
' select L.SEQNO, SUM(ISNULL(ACT.LINETOTAL, 0)) AS ACTUAL '+
' from '+
' CRM_BUDGET_LINE AS L '+
' inner join '+@srcview+' AS ACT '+
' ON '+
' ACT.PERIOD_SEQNO = '+convert(varchar(100), @period)+' '+
+@joins+
' where '+
' L.BUDGET_SEQNO = '+convert(varchar(100), @budgetSeqno)+
' AND ACT.ACCGROUP not in (SELECT ACCGROUP FROM CRM_BUDGET_EXCLUDED_ACCGROUPS WHERE BUDGET_SEQNO = '+convert(varchar(100), @budgetSeqno)+') '+
' AND ACT.ACCGROUP2 not in (SELECT ACCGROUP FROM CRM_BUDGET_EXCLUDED_ACCGROUP2S WHERE BUDGET_SEQNO = '+convert(varchar(100), @budgetSeqno)+') '+
' AND ACT.ACCNO not in (SELECT ACCNO FROM CRM_BUDGET_EXCLUDED_DR_ACCS WHERE BUDGET_SEQNO = '+convert(varchar(100), @budgetSeqno)+') '+
' AND ACT.STOCKGROUP not in (SELECT STOCKGROUP FROM CRM_BUDGET_EXCLUDED_STOCK_GROUPS WHERE BUDGET_SEQNO = '+convert(varchar(100), @budgetSeqno)+') '+
' AND ACT.STOCKGROUP2 not in (SELECT STOCKGROUP FROM CRM_BUDGET_EXCLUDED_STOCK_GROUP2S WHERE BUDGET_SEQNO = '+convert(varchar(100), @budgetSeqno)+') '+
' AND ACT.STOCKCODE not in (SELECT STOCKCODE FROM CRM_BUDGET_EXCLUDED_STOCK_ITEMS WHERE BUDGET_SEQNO = '+convert(varchar(100), @budgetSeqno)+') '+
' AND ACT.BRANCHNO not in (SELECT BRANCHNO FROM CRM_BUDGET_EXCLUDED_BRANCHES WHERE BUDGET_SEQNO = '+convert(varchar(100), @budgetSeqno)+') '+
' AND ACT.SALESNO not in (SELECT STAFFNO FROM CRM_BUDGET_EXCLUDED_STAFF WHERE BUDGET_SEQNO = '+convert(varchar(100), @budgetSeqno)+') '+
' group by L.seqno '+
' ) as S '+
' on UL.SEQNO = S.SEQNO '+
'where '+
' BUDGET_SEQNO = '+convert(varchar(100), @budgetSeqno)
EXEC(@sql)
update CRM_BUDGET set RECALC_LASTRUN = GETDATE() where SEQNO = @budgetSeqno
END


Procedure: SP_CRM_BUDGET_FILL_ACTIVE_ACTUALS
NameSP_CRM_BUDGET_FILL_ACTIVE_ACTUALS
Note
CodeCREATE PROCEDURE [dbo].[SP_CRM_BUDGET_FILL_ACTIVE_ACTUALS]
    AS BEGIN
declare @budget_seqno int
declare budget cursor local for
select B.SEQNO
  FROM
    CRM_BUDGET B inner join CRM_BUDGET_HDR H
    on B.HEADER_SEQNO = H.SEQNO
  where
H.ISACTIVE = 1
open budget
fetch next from budget into @budget_seqno
while @@FETCH_STATUS = 0 begin
  EXEC SP_CRM_BUDGET_FILLACTUALS @budget_seqno, 1, 0
  fetch next from budget into @budget_seqno
end
close budget
deallocate budget
Update GENERAL_INFO Set CRM_SALES_BUDGETS_RECALC_LASTRUN = GETDATE()
END


Procedure: SP_CRM_NEW_BUDGET_TEMPLATE
NameSP_CRM_NEW_BUDGET_TEMPLATE
Note
CodeCREATE PROCEDURE [dbo].[SP_CRM_NEW_BUDGET_TEMPLATE]
@STAFFNO int
AS
BEGIN
SET NOCOUNT ON

declare @TMP_NEW_BUDGET table
( BUDGET_ID int, DATE_FROM datetime, DATE_TO datetime,
  ACCGROUP int, ACCGROUP_NAME varchar(40),
  ACCNO int, ACCNO_NAME varchar(40),
  STOCKGROUP int, STOCKGROUP_NAME varchar(40),
  STOCKCODE varchar(23), STOCKCODE_NAME varchar(40),
  HISTORIC_VALUE decimal(19, 4),
  BUDGET_VALUE decimal(19, 4) )
declare @seqno int, @date_from datetime, @date_to datetime, @level_accgroup bit, @level_accno bit, @level_stockgroup bit, @level_stockcode bit
declare @sql varchar(max), @selectcols varchar(max), @groupbycols varchar(max), @joins varchar(max), @insertcols varchar(max)
declare BUDGET cursor for
 select SEQNO, DATE_FROM, DATE_TO, LEVEL_ACCGROUP, LEVEL_ACCNO, LEVEL_STOCKGROUP, LEVEL_STOCKCODE
 from CRM_BUDGET WHERE STAFFNO = @staffno

 open BUDGET
 FETCH NEXT FROM BUDGET
 INTO @seqno, @date_from, @date_to, @level_accgroup, @level_accno, @level_stockgroup, @level_stockcode

 while @@FETCH_STATUS = 0 begin
SET @selectcols = ''
SET @joins = ''
SET @insertcols = ''
SET @groupbycols = ''
    if @level_accgroup = 1 begin
SET @selectcols = @selectcols + 'ACT.ACCGROUP, AG.GROUPNAME, '
SET @groupbycols = @groupbycols + 'ACT.ACCGROUP, AG.GROUPNAME, '
SET @joins = @joins + ' left join DR_ACCGROUPS AG on ACT.ACCGROUP = AG.ACCGROUP'
SET @insertcols = @insertcols + 'ACCGROUP, ACCGROUP_NAME, '
end else begin
SET @selectcols = @selectcols + 'NULL, NULL, '
end
if @level_accno = 1 begin
SET @selectcols = @selectcols + 'ACT.ACCNO, A.NAME, '
SET @groupbycols = @groupbycols + 'ACT.ACCNO, A.NAME, '
SET @joins = @joins + ' left join DR_ACCS A on ACT.ACCNO = A.ACCNO'
SET @insertcols = @insertcols + 'ACCNO, ACCNO_NAME, '
end else begin
SET @selectcols = @selectcols + 'NULL, NULL, '
end
if @level_stockgroup = 1 begin
SET @selectcols = @selectcols + 'ACT.STOCKGROUP, SG.GROUPNAME, '
SET @groupbycols = @groupbycols + 'ACT.STOCKGROUP, SG.GROUPNAME, '
SET @joins = @joins + ' left join STOCK_GROUPS SG on ACT.STOCKGROUP = SG.GROUPNO'
SET @insertcols = @insertcols + 'STOCKGROUP, STOCKGROUP_NAME, '
end else begin
SET @selectcols = @selectcols + 'NULL, NULL, '
end
if @level_stockcode = 1 begin
SET @selectcols = @selectcols + 'ACT.STOCKCODE, SI.DESCRIPTION, '
SET @groupbycols = @groupbycols + 'ACT.STOCKCODE, SI.DESCRIPTION, '
SET @joins = @joins + ' left join STOCK_ITEMS SI on ACT.STOCKCODE = SI.STOCKCODE'
SET @insertcols = @insertcols + 'STOCKCODE, STOCKCODE_NAME, '
end else begin
SET @selectcols = @selectcols + 'NULL, NULL, '
end
SET @selectcols = SUBSTRING(@selectcols, 0, LEN(@selectcols))
SET @insertcols = SUBSTRING(@insertcols, 0, LEN(@insertcols))
SET @groupbycols = SUBSTRING(@groupbycols, 0, LEN(@groupbycols))
SET @sql = 'SELECT ' + convert(varchar(max), @seqno) + ', CONVERT(datetime, ''' + CONVERT(varchar(max), @date_from, 101) + ''', 101), CONVERT(datetime, ''' + CONVERT(varchar(max), @date_to, 101) + ''', 101), '
+ @selectcols + '
, SUM(ACT.LINETOTAL) AS HISTORIC_VALUE, 0
FROM VW_CRM_ACTUAL_SALES ACT '
+ @joins +
' WHERE TRANSDATE BETWEEN DATEADD(YEAR, -1, CONVERT(datetime, ''' + CONVERT(varchar(max), @date_from, 101) + ''', 101)) AND DATEADD(YEAR, -1, CONVERT(datetime, ''' + CONVERT(varchar(max), @date_to, 101) + ''', 101))
' +
--AND ACT.SALESNO = ' + CONVERT(varchar(max), @staffno) +
' GROUP BY ' + @groupbycols +
' UNION
SELECT ' + convert(varchar(max), @seqno) + ', CONVERT(datetime, ''' + CONVERT(varchar(max), @date_from, 101) + ''', 101), CONVERT(datetime, ''' + CONVERT(varchar(max), @date_to, 101) + ''', 101), '
+ @selectcols + ', SUM(ISNULL(ACT.LINETOTAL, 0)) AS HISTORIC_VALUE, 0
FROM (
select G.ACCGROUP, g.ACCNO, g.GROUPNO AS STOCKGROUP, g.STOCKCODE, ISNULL(ACT.LINETOTAL, 0) AS LINETOTAL, ACT.SALESNO, ACT.TRANSDATE from
(select AG.ACCGROUP, A.ACCNO, SG.GROUPNO, SI.STOCKCODE
from
DR_ACCGROUPS AG
cross join DR_ACCS A
cross join STOCK_GROUPS SG
cross join STOCK_ITEMS SI
) G
left join VW_CRM_ACTUAL_SALES ACT
on G.ACCGROUP = ACT.ACCGROUP and G.ACCNO = ACT.ACCNO and G.GROUPNO = ACT.STOCKGROUP and G.STOCKCODE = ACT.STOCKCODE ) ACT '
+ @joins +
' WHERE ACT.LINETOTAL = 0
GROUP BY ' + @groupbycols
--print @sql ACCGROU
INSERT INTO @TMP_NEW_BUDGET EXECUTE(@sql)
FETCH NEXT FROM BUDGET
    INTO @seqno, @date_from, @date_to, @level_accgroup, @level_accno, @level_stockgroup, @level_stockcode
end
close BUDGET
deallocate BUDGET
--delete from crm_budget_line_TMP
--insert into crm_budget_line_TMP(BUDGET_SEQNO, ACCGROUP, ACCNO, STOCK_GROUPNO, ACCGROUP_NAME, ACCNO_NAME, STOCK_GROUPNO_NAME, stockcode, ACTUALS)
select
 BUDGET_ID , DATE_FROM , DATE_TO ,
  ACCGROUP, isnull(ACCGROUP_NAME, '') as ACCGROUP_NAME,
  ACCNO , isnull(ACCNO_NAME, '') as ACCNO_NAME,
  STOCKGROUP , isnull(STOCKGROUP_NAME, '') as STOCKGROUP_NAME,
  STOCKCODE, isnull(STOCKCODE_NAME, '') as STOCKCODE_NAME,
  HISTORIC_VALUE ,
  BUDGET_VALUE
 from @TMP_NEW_BUDGET
SET NOCOUNT OFF
/*
EXEC SP_CRM_NEW_BUDGET_TEMPLATE 8
*/
END


Procedure: SP_DEMODATA_GST_VERIFICATION
NameSP_DEMODATA_GST_VERIFICATION
Note
Code-- ================================================
-- Only Applicable to New Zealand demo databases
-- Updates the old GST rates to change description and key points
-- Inserts new tax rates (if already not existing)
-- Set new taxrates as defaults for debtors and creditors
-- Fixes invalid tax rates in debtor, creditor, GL and stock
-- Updates the old taxrates in debtor, creditor, GL and stock account tables
-- ================================================
-- =============================================
-- Author: Masha Batra
-- Create date: 12th August, 2010
-- Description: Demo Database update wrt GST changes 2010
-- =============================================
CREATE PROCEDURE [dbo].[SP_DEMODATA_GST_VERIFICATION]
AS
BEGIN
-- SET NOCOUNT ON added to prevent extra result sets from
-- interfering with SELECT statements.
SET NOCOUNT ON;

print 'GST changes starting....'
if not exists(select * from general_info where country = 'NZL' and username like 'Motopartz.%')
Return

print 'Retrieve existing GST info....'

Declare
@OldDrTaxRate_seqno int, @OldCrTaxRate_seqno int, @OldBadDebtsTaxRate_seqno int, @OldBadDebtsRecTaxRate_seqno int,
@NewDrTaxRate_seqno int, @NewCrTaxRate_seqno int, @NewBadDebtsTaxRate_seqno int, @NewBadDebtsRecTaxRate_seqno int
Select @OldDrTaxRate_seqno = 10
Select @OldCrTaxRate_seqno = 13
Select @OldBadDebtsTaxRate_seqno = 16
Select @OldBadDebtsRecTaxRate_seqno = 17

   BEGIN TRANSACTION
print 'Updating old taxrates....'
-------------------------------
--Update Old Rates
-------------------------------
update tax_rates set [name] = 'DEBTORS - OLD GST RATE', shortname = 'DR-OLD', Key_point = '9G' where seqno = @OldDrTaxRate_seqno
update tax_rates set [name] = 'CREDITORS - OLD GST RATE', shortname = 'CR-OLD', Key_point = '13D' where seqno = @OldCrTaxRate_seqno
update tax_rates set [name] = 'BAD DEBTS - OLD RATE', shortname = 'BADOLD', Key_point = '13D' where seqno = @OldBadDebtsTaxRate_seqno
update tax_rates set [name] = 'BAD DEBTS RECOVERED - OLD RATE', shortname = 'BR-OLD', Key_point = '9G' where seqno = @OldBadDebtsRecTaxRate_seqno

print 'Setup New taxrates....'
-------------------------------
--New Tax Rates
-------------------------------
select @NewDrTaxRate_seqno = (select seqno from tax_rates where rate = 15 and key_point = '5' and shortname = 'DR')
if @NewDrTaxRate_seqno is null
begin
select @NewDrTaxRate_seqno = (SELECT MAX(seqno) FROM Tax_rates) + 1
Insert into Tax_rates(seqno, [name], shortname, rate, Key_point)
values (@NewDrTaxRate_seqno, 'DEBTORS STANDARD GST RATE', 'DR', 15, '5')
end

select @NewCrTaxRate_seqno = (select seqno from tax_rates where rate = 15 and key_point = '11' and shortname = 'CR')
if @NewCrTaxRate_seqno is null
begin
select @NewCrTaxRate_seqno = (SELECT MAX(seqno) FROM Tax_rates) + 1
Insert into Tax_rates(seqno, [name], shortname, rate, Key_point)
values (@NewCrTaxRate_seqno, 'CREDITORS STANDARD GST RATE', 'CR', 15, '11')
end

select @NewBadDebtsTaxRate_seqno = (select seqno from tax_rates where rate = 15 and key_point = '13D' and shortname = 'BAD')
if @NewBadDebtsTaxRate_seqno is null
begin
select @NewBadDebtsTaxRate_seqno = (SELECT MAX(seqno) FROM Tax_rates) + 1
Insert into Tax_rates(seqno, [name], shortname, rate, Key_point)
values (@NewBadDebtsTaxRate_seqno , 'BAD DEBTS', 'BAD', 15, '13D')
end

select @NewBadDebtsRecTaxRate_seqno = (select seqno from tax_rates where rate = 15 and key_point = '9G' and shortname = 'BADREC')
if @NewBadDebtsRecTaxRate_seqno is null
begin
select @NewBadDebtsRecTaxRate_seqno = (SELECT MAX(seqno) FROM Tax_rates) + 1
Insert into Tax_rates(seqno, [name], shortname, rate, Key_point)
values (@NewBadDebtsRecTaxRate_seqno, 'BAD DEBTS RECOVERED', 'BADREC', 15, '9G')
end
IF @@ERROR <> 0
BEGIN
-- Rollback the transaction
ROLLBACK
RETURN
END
COMMIT

print 'Set new taxrates as defaults ....'
-------------------------------
--Set Standard Rates
-------------------------------
if (select count(*) from profile_values where fieldname = 'DRDEFAULTTAXRATENO') >=1
begin
Update profile_values set fieldvalue = @NewDrTaxRate_seqno where fieldname = 'DRDEFAULTTAXRATENO'
Update profile_values set fieldvalue = @NewCrTaxRate_seqno where fieldname = 'CRDEFAULTTAXRATENO'
end
else
begin
Insert into profile_values ([profileid], [fieldname], [fieldvalue])
values (1, 'DRDEFAULTTAXRATENO', @NewDrTaxRate_seqno )
Insert into profile_values ([profileid], [fieldname], [fieldvalue])
values (1, 'CRDEFAULTTAXRATENO', @NewCrTaxRate_seqno )

end

print 'Fix invalid taxrates....'
------------------------------
--Fix Invalid Tax Rates
------------------------------
--invalid tax on debtors
update dr_accs set taxstatus = -1
where accno in
(select a.accno from dr_accs a
left join tax_rates r on a.taxstatus = r.seqno
left join tax_key_point k on k.country = (select country from general_info) and r.key_point = k.key_point
and k.dr_ledger = 'y'
where a.taxstatus <> -1 and k.seqno is null)

--invalid tax on creditors
update cr_accs set taxstatus = -1
where accno in
(select a.accno from cr_accs a
left join tax_rates r on a.taxstatus = r.seqno
left join tax_key_point k on k.country = (select country from general_info) and r.key_point = k.key_point
and k.cr_ledger = 'y'
where a.taxstatus <> -1 and k.seqno is null)

--invalid purchase tax on stock items
update stock_items set purchtaxrate = -1
where stockcode in
(select a.stockcode from stock_items a
left join tax_rates r on a.purchtaxrate = r.seqno
left join tax_key_point k on r.key_point = k.key_point and k.country = (select country from general_info)
and k.cr_ledger = 'y'
where a.purchtaxrate <> -1 and k.seqno is null)

--invalid sales tax on stock items
update stock_items set salestaxrate = -1
where stockcode in
(select a.stockcode from stock_items a
left join tax_rates r on a.salestaxrate=r.seqno
left join tax_key_point k on r.key_point=k.key_point and k.country = (select country from general_info)
and k.dr_ledger = 'y'
where a.salestaxrate <> -1 and k.seqno is null)

--invalid tax on glaccs
update glaccs set taxstatus = -1
where accno in
(select a.accno from glaccs a
left join tax_rates r on a.taxstatus = r.seqno
left join tax_key_point k on k.country = (select country from general_info) and r.key_point = k.key_point
and k.cr_ledger = 'y'
where a.taxstatus <> -1 and k.seqno is null)

print 'Update account tables with new taxrates....'
-------------------------------
--Update Tax Rates in Tables
-------------------------------
--Debtors
Update dr_accs set Taxstatus = -1 where Taxstatus = @OldDrTaxRate_seqno

--Creditors
Update cr_accs set Taxstatus = -1 where Taxstatus = @OldCrTaxRate_seqno

--GL
Update glaccs set Taxstatus = @NewDrTaxRate_seqno where Taxstatus = @OldDrTaxRate_seqno
Update glaccs set Taxstatus = @NewCrTaxRate_seqno where Taxstatus = @OldCrTaxRate_seqno
Update glaccs set Taxstatus = @NewBadDebtsTaxRate_seqno where Taxstatus = @OldBadDebtsTaxRate_seqno
Update glaccs set Taxstatus = @NewBadDebtsRecTaxRate_seqno where Taxstatus = @OldBadDebtsRecTaxRate_seqno

--Stock
Update stock_items set SalesTaxRate = @NewDrTaxRate_seqno where SalesTaxRate = @OldDrTaxRate_seqno
Update stock_items set SalesTaxRate = @NewCrTaxRate_seqno where SalesTaxRate = @OldCrTaxRate_seqno
Update stock_items set PurchTaxRate = @NewDrTaxRate_seqno where SalesTaxRate = @OldDrTaxRate_seqno
Update stock_items set PurchTaxRate = @NewCrTaxRate_seqno where SalesTaxRate = @OldCrTaxRate_seqno
END


Procedure: SP_DEMO_DATA_DATE_UPDATER
NameSP_DEMO_DATA_DATE_UPDATER
Note
CodeCREATE PROCEDURE [dbo].[SP_DEMO_DATA_DATE_UPDATER]
AS
-- Procedure uses the first period of the year(January) as a baseline and updates the start and stop dates for periods in periods_defn
-- Updates period_status and the rest of tables, if the Current period in the db is different from the period the current date is in.


Declare @varmonth as integer,
 @varyear as integer,
 @CurrentPeriod as integer,
 @varmonthcurrent as integer,
 @varmonthcurrentDate as integer,
 @FIRSTPERIOD integer,
 @CURRENTYEAR integer,
 @CURRENTPERIODSEQNO integer,
 @LASTPERIODOFCALENDERYEAR integer,
 @JanuaryInCurrentFinYear datetime,
 @UPDATEQUERY VARCHAR(2000),
 @newcurrentperiod integer,
 @firstdayofcurrentmonth datetime,
 @currcode varchar(5),
 @FinStartMonth integer


SELECT @FIRSTPERIOD= FIRST_PERIOD_OF_YEAR FROM GENERAL_INFO
SELECT @CURRENTYEAR =CURRENT_YEAR FROM LEDGER_PERIODS WHERE LEDGER LIKE 'General Ledger'
SELECT @CURRENTPERIODSEQNO =PERIOD_SEQNO FROM LEDGER_PERIODS WHERE LEDGER LIKE 'General Ledger'
SELECT @LASTPERIODOFCALENDERYEAR = (SELECT MAX(SEQNO) LASTPERIOD FROM PERIODS_DEFN WHERE SEQNO < @FIRSTPERIOD)
SELECT @currcode = currcode from currencies where currencyno = 0

if @currcode = 'NZD'
set @FinStartMonth = 4
else if @currcode = 'AUD'
set @FinStartMonth = 7
else
set @FinStartMonth = 4

if month(getdate()) < @FinStartMonth
SELECT @JanuaryInCurrentFinYear =DATEADD(yy, DATEDIFF(yy, 0, getdate()), 0) -- first day of current year if month is less than 4 i.e. April
else
SELECT @JanuaryInCurrentFinYear = DATEADD(year, DATEDIFF(year, -1, getdate()), 0) -- first day of next year


select @varmonth=DATEDIFF(M, (select startdate from periods_defn where seqno =@FIRSTPERIOD), @JanuaryInCurrentFinYear) ,
@varyear=DATEDIFF(Y, (select startdate from periods_defn where seqno =@FIRSTPERIOD), @JanuaryInCurrentFinYear) ,
@varmonthcurrent= DATEDIFF(M, (select startdate from periods_defn where seqno =@CURRENTPERIODSEQNO), (select DATEADD(dd, -(DAY(getdate())-1), getdate()))), --date diff between start of old current period and start of current month
@varmonthcurrentDate= DATEDIFF(M, (select startdate from periods_defn where seqno =@CURRENTPERIODSEQNO), getdate()),
@firstdayofcurrentmonth = DATEADD(dd, -(DAY(getdate())-1), getdate())

IF @varmonthcurrent <> 0
begin

IF OBJECT_ID('dbo.CRM_BUDGET', 'U') IS NOT NULL
--Disable checking constraints on tables with foreign key constraints like CRM_BUDGET
ALTER TABLE CRM_BUDGET NOCHECK CONSTRAINT ALL

IF OBJECT_ID('dbo.CAMPAIGN_WAVE', 'U') IS NOT NULL
--Disable trigger on Campaign_Wave -
ALTER TABLE CAMPAIGN_WAVE DISABLE TRIGGER ALL

--CREATE SQL CODE TO DO UPDATES ONE TABLE AT A TIME AND LOAD INTO CURSOR
DECLARE DATEUPDATE_CURSOR CURSOR FOR
SELECT 'UPDATE ' + SO.NAME + ' SET ' + SC.NAME + ' = ' + 'DATEADD(Month, ' + CONVERT(VARCHAR, @varmonthcurrentDate) + ', ' + SC.NAME + ')'
FROM SYSOBJECTS SO
JOIN SYSCOLUMNS SC ON SC.ID = SO.ID
INNER JOIN SYSTYPES SS ON SS.XTYPE = SC.XTYPE
WHERE not (SO.NAME in ('SYSOBJECTS', 'SYSUSERS', 'MENU_METRICS')) AND SS.NAME = 'DATETIME' AND SO.XTYPE = 'U'

--EXECUTE CURSOR TO UPDATE ALL TABLE DATES SCRIPT CREATED ABOVE
OPEN DATEUPDATE_CURSOR
FETCH NEXT FROM DATEUPDATE_CURSOR INTO @UPDATEQUERY
WHILE @@FETCH_STATUS = 0
BEGIN
EXECUTE (@UPDATEQUERY)
--PRINT @UPDATEQUERY
FETCH NEXT FROM DATEUPDATE_CURSOR INTO @UPDATEQUERY
END

CLOSE DATEUPDATE_CURSOR
DEALLOCATE DATEUPDATE_CURSOR

--Move all dates forward in PERIOD DEFINITION
-- cannot base it on moving forward start/stopdate as they are incorrect in 8.5 nz demo db.
-- Update startdate for month of january with the calculated 1st day of Jan in current fin year
update P set startdate= @JanuaryInCurrentFinYear
, stopdate= DATEADD(dd, -(DAY(DATEADD(mm, 1, @JanuaryInCurrentFinYear))), DATEADD(mm, 1, @JanuaryInCurrentFinYear))
from periods_defn P where seqno = @FIRSTPERIOD
-- Update start dates of the rest of the periods wrt the start date of Jan
update P set startdate= DATEADD(MONTH, DATEDIFF(MONTH, 0, @JanuaryInCurrentFinYear) + (seqno -@firstperiod), 0)
from periods_defn P where seqno <> @FIRSTPERIOD and seqno > 0
-- Update stop dates of the rest of periods.It will be last day of the month wrt the start date.
update P set stopdate= DATEADD(dd, -(DAY(DATEADD(mm, 1, startdate))), DATEADD(mm, 1, startdate))
from periods_defn P where seqno <> @FIRSTPERIOD and seqno > 0

--Update PERIOD STATUS
-- find seqno of the period the current date is in
select @newcurrentperiod = seqno from periods_defn where month(startdate) = month(getdate())
-- Update the start date with first day of period the current date is in for lines with age =0
update P set startdate= (select startdate from periods_defn where seqno =@newcurrentperiod)
from period_status P where age =0
-- Update the start dates for the rest of periods/ledgers using age 0 start date as reference
update P set startdate= DATEADD(MONTH, DATEDIFF(MONTH, 0, @firstdayofcurrentmonth) - age , 0)
from period_status P where age <> 0
-- Update stop dates for all periods. It will be last day of the month wrt the start date
update P set stopdate= DATEADD(dd, -(DAY(DATEADD(mm, 1, startdate))), DATEADD(mm, 1, startdate))
from period_status P

--Update reportcode, period_seqno, periodname, shortname in period_status based on startdate in periodstatus
update PS set REPORTCODE = CAST(year(PS.startdate) AS VARCHAR) + '/' + RIGHT('0' + CONVERT(VARCHAR, MONTH(PS.startdate)), 2)
, PERIODNAME =PD.periodname + ' ' + CAST(year(PS.startdate) AS VARCHAR)
, period_shortname = substring(PD.periodname, 1, 3) + substring(CAST(year(PS.startdate) AS VARCHAR), 3, 2)
, period_seqno = PD.seqno
from period_status PS left join periods_defn PD on month(PS.startdate) = month(PD.startdate)

-- Update YEARAGE in period_status
declare @startdate datetime, @stopdate datetime
select top 1 @startdate = startdate from periods_defn where startdate is not NULL -- startdate for finyear
select top 1 @stopdate = stopdate from periods_defn where stopdate is not NULL order by seqno desc -- last date in the finyear

update period_status
set yearage =
case when startdate between @startdate and @stopdate then 0
when startdate between DateAdd(year, -1, @startdate) and DateAdd(year, -1, @stopdate) then 1
when startdate between DateAdd(year, -2, @startdate) and DateAdd(year, -2, @stopdate) then 2
when startdate between DateAdd(year, -3, @startdate) and DateAdd(year, -3, @stopdate) then 3
else -1
end

--Update dates in certain Transactional tables
-- To make sure Transaction dates belong to month and year of period they point to, it is calculated as follows:
-- Date from transaction date+ Month from report code of period+Year from report code
update D
set Transdate = convert(datetime, substring(PS.reportcode, 1, 4) + right('0' + substring(PS.reportcode, 6, 2), 2) + right('0' + cast(day(dateadd(M, @varmonthcurrent, transdate)) as varchar), 2) , 112)
, Posttime = dateadd(M, @varmonthcurrent, posttime)
from DR_TRANS D inner join period_status PS on D.period_seqno = PS.seqno

update T
set Transdate = convert(datetime, substring(PS.reportcode, 1, 4) + right('0' + substring(PS.reportcode, 6, 2), 2) + right('0' + cast(day(dateadd(M, @varmonthcurrent, transdate)) as varchar), 2) , 112)
, Posttime = dateadd(M, @varmonthcurrent, posttime)
from CR_TRANS T inner join period_status PS on T.period_seqno = PS.seqno

update T
set Transdate = convert(datetime, substring(PS.reportcode, 1, 4) + right('0' + substring(PS.reportcode, 6, 2), 2) + right('0' + cast(day(dateadd(M, @varmonthcurrent, transdate)) as varchar), 2) , 112)
from GLTRANS T inner join period_status PS on T.period_seqno = PS.seqno

update T
set ALLOCTIME = convert(datetime, substring(PS.reportcode, 1, 4) + right('0' + substring(PS.reportcode, 6, 2), 2) + right('0' + cast(day(dateadd(M, @varmonthcurrent, ALLOCTIME)) as varchar), 2) , 112)
from DR_ALLOCATIONS T inner join period_status PS on T.period_seqno = PS.seqno

update T
set ALLOCTIME = convert(datetime, substring(PS.reportcode, 1, 4) + right('0' + substring(PS.reportcode, 6, 2), 2) + right('0' + cast(day(dateadd(M, @varmonthcurrent, ALLOCTIME)) as varchar), 2) , 112)
from CR_ALLOCATIONS T inner join period_status PS on T.period_seqno = PS.seqno

update T
set Transdate = convert(datetime, substring(PS.reportcode, 1, 4) + right('0' + substring(PS.reportcode, 6, 2), 2) + right('0' + cast(day(dateadd(M, @varmonthcurrent, transdate)) as varchar), 2) , 112)
, Posttime = dateadd(M, @varmonthcurrent, posttime)
from STOCK_TRANS T inner join period_status PS on T.period_seqno = PS.seqno

/*Start - Added to maintain reasonable WIP reconciliation*/
UPDATE J
SET WIP_IN_PERIOD_SEQNO = PS.SEQNO
FROM JOB_TRANSACTIONS J
JOIN PERIOD_STATUS PS ON MONTH(TRANSDATE) = MONTH(CONVERT(DATETIME, LEFT(PS.PERIODNAME, 3) + ' 01 2000', 100))
AND YEAR(TRANSDATE) = YEAR(CONVERT(DATETIME, LEFT(PS.PERIODNAME, 3) + ' 01 2000', 100))
AND PS.LEDGER = 'S'

UPDATE J
SET WIP_OUT_PERIOD_SEQNO = PS.SEQNO
FROM JOB_TRANSACTIONS J
JOIN PERIOD_STATUS PS ON MONTH(TRANSDATE) = MONTH(CONVERT(DATETIME, LEFT(PS.PERIODNAME, 3) + ' 01 2000', 100))
AND YEAR(TRANSDATE) = YEAR(CONVERT(DATETIME, LEFT(PS.PERIODNAME, 3) + ' 01 2000', 100))
AND PS.LEDGER = 'S' AND J.WIP_OUT_PERIOD_SEQNO <> -1

/*
End - Added to maintain reasonable WIP reconciliation*/

update T
set Transdate = convert(datetime, substring(PS.reportcode, 1, 4) + right('0' + substring(PS.reportcode, 6, 2), 2) + right('0' + cast(day(dateadd(M, @varmonthcurrent, transdate)) as varchar), 2) , 112)
from STOCK_TRANS_HDR T inner join period_status PS on T.period_seqno = PS.seqno

update T
set Transdate = convert(datetime, substring(PS.reportcode, 1, 4) + right('0' + substring(PS.reportcode, 6, 2), 2) + right('0' + cast(day(dateadd(M, @varmonthcurrent, transdate)) as varchar), 2) , 112)
from TAX_RETURN_CALC T inner join period_status PS on T.period_seqno = PS.seqno

update T
set Inv_Transdate = convert(datetime, substring(PS.reportcode, 1, 4) + right('0' + substring(PS.reportcode, 6, 2), 2) + right('0' + cast(day(dateadd(M, @varmonthcurrent, Inv_transdate)) as varchar), 2) , 112)
from INWARDS_GOODS_LINES T inner join period_status PS on T.period_seqno = PS.seqno

update T
set Transdate = convert(datetime, substring(PS.reportcode, 1, 4) + right('0' + substring(PS.reportcode, 6, 2), 2) + right('0' + cast(day(dateadd(M, @varmonthcurrent, transdate)) as varchar), 2) , 112)
from INWARDS_GOODS_COSTS T inner join period_status PS on T.period_seqno = PS.seqno

update T
set Transdate = convert(datetime, substring(PS.reportcode, 1, 4) + right('0' + substring(PS.reportcode, 6, 2), 2) + right('0' + cast(day(dateadd(M, @varmonthcurrent, transdate)) as varchar), 2) , 112)
from GLBATCH T inner join period_status PS on T.period_seqno = PS.seqno

update T
set Transdate = convert(datetime, substring(PS.reportcode, 1, 4) + right('0' + substring(PS.reportcode, 6, 2), 2) + right('0' + cast(day(dateadd(M, @varmonthcurrent, transdate)) as varchar), 2) , 112)
from CASHBOOKHEADER T inner join period_status PS on T.period_seqno = PS.seqno

UPDATE GL_CONTROL
SET PERIODSTHISYEAR = (SELECT PERIOD_SEQNO FROM PERIOD_STATUS WHERE AGE = 0 AND LEDGER = 'C')

----RECALCULATE GL ACCOUNTS
Declare @EOYSeqno integer, @FirstPeriodofFinYear integer, @PeriodsThisYear integer, @ActualYearPeriod integer, @OldestPeriodinYear integer
SELECT @EOYSeqno = MAX(SEQNO) FROM GLTRANS WHERE (BATCHNO=-1) AND (SOURCE='e')

if @EOYSeqno is null
select @FirstPeriodofFinYear = max(periodno) from gltrans
else
select @FirstPeriodofFinYear = periodno from gltrans where seqno = (select min(seqno) from gltrans where seqno > @EOYSeqno )

select @FirstPeriodofFinYear = isnull(@FirstPeriodofFinYear, -1)

select @PeriodsThisYear = PeriodsThisYear from gl_control
select @PeriodsThisYear = isnull(@PeriodsThisYear, -1)

select @ActualYearPeriod = @FirstPeriodofFinYear + 1

if @ActualYearPeriod > 0 and @PeriodsThisYear<=0
begin
UPDATE GL_CONTROL SET PERIODSTHISYEAR=@ActualYearPeriod
select @OldestPeriodinYear = @FirstPeriodofFinYear
end
else
begin
select @OldestPeriodinYear = @PeriodsThisYear -1
end

UPDATE GLACCS
SET BALANCE=(SELECT SUM(AMOUNT) FROM GLTRANS WHERE ACCNO=GLACCS.ACCNO)
WHERE (SECTION=1)
UPDATE GLACCS
SET BALANCE=(SELECT SUM(AMOUNT) FROM GLTRANS WHERE (ACCNO=GLACCS.ACCNO) AND (PERIODNO between 0 and @OldestPeriodinYear))
WHERE (SECTION=0)
UPDATE GLACCS SET BALANCE=0 WHERE BALANCE IS NULL

--If trial balance is not balanced, insert a one sided journal into errors account to compensate for it.
if (select sum(balance) from glaccs) <> 0
begin
Declare @errors integer, @sub_errors integer
select @errors=errors, @sub_errors=sub_errors from gl_control
insert into gltrans (accno, subaccno, transdate, details, [source], amount, fcamount, period_seqno, companyno, branchno, batchno, source_invlineid, initials)
values (@errors, @sub_errors, getdate(), 'Trial bal adjustment', 'g', -(select sum(balance) from glaccs), -(select sum(balance) from glaccs)
, (select seqno from period_status where ledger = 'G' and age = 0),
0, 0, (select max(batchno) from gltrans), 0, '...')
end

--UPDATE GLMOVEMENTS
DELETE FROM GLMOVEMENTS
DBCC CHECKIDENT ('GLMOVEMENTS', RESEED, 0)
EXEC CALCULATE_GLMOVEMENTS NULL, NULL, NULL, NULL, NULL

----Update the current year and current ledger period value in ledger periods table
UPDATE L set CURRENT_YEAR = (select top 1 year(startdate) from period_status where age =0)
FROM LEDGER_PERIODS L



update LEDGER_PERIODS set PERIOD_SEQNO = (select top 1 period_seqno from period_status where age =0)


--Update MinTransseqnos. There should be no need for this as the period_seqnos are not getting altered in transactional tables.
--But this has been retained from previous script to cover scenarios where the db is in version prior to 8.1 and no minseqno values exist.
--update the GL rows LEDGER='G'
UPDATE PS
SET
MINGLSEQNO =(SELECT ISNULL(MIN(GT.SEQNO)-1, -1)
FROM GLTRANS GT
WHERE GT.PERIOD_SEQNO = PS.SEQNO
GROUP BY PERIOD_SEQNO
)
FROM PERIOD_STATUS PS
WHERE PS.LEDGER='G'
-- update the stock rows LEDGER='S'
UPDATE PS
SET
MINGLSEQNO = (SELECT MINGLSEQNO-1
FROM PERIOD_STATUS PER
WHERE PS.AGE = PER.AGE AND PER.LEDGER = 'G'
),
MINSTOCKSEQNO =(SELECT ISNULL(MIN(ST.SEQNO), -1)
FROM STOCK_TRANS ST
WHERE ST.PERIOD_SEQNO = PS.SEQNO
GROUP BY PERIOD_SEQNO
)
FROM PERIOD_STATUS PS
WHERE PS.LEDGER='S'
-- put the stock info back into the GL rows
UPDATE PS
SET
MINSTOCKSEQNO = (SELECT MINSTOCKSEQNO
FROM PERIOD_STATUS PER
WHERE PS.AGE = PER.AGE AND PER.LEDGER = 'S'
)
FROM PERIOD_STATUS PS
WHERE PS.LEDGER='G'
-- update the Debtors rows LEDGER='D'
UPDATE PS
SET
MINSTOCKSEQNO = (SELECT MINSTOCKSEQNO
FROM PERIOD_STATUS PER
WHERE PS.AGE = PER.AGE AND PER.LEDGER = 'S'
),
MINGLSEQNO = (SELECT MINGLSEQNO-1
FROM PERIOD_STATUS PER
WHERE PS.AGE = PER.AGE AND PER.LEDGER = 'G'
),
MINTRANSEQNO = (SELECT ISNULL(MIN(DT.SEQNO), -1)
FROM DR_TRANS DT
WHERE DT.PERIOD_SEQNO = PS.SEQNO
GROUP BY PERIOD_SEQNO
),
MINTRANLINESEQNO =(SELECT ISNULL(MIN(DL.SEQNO), -1)
FROM DR_TRANS DT
LEFT OUTER JOIN DR_INVLINES DL ON DL.HDR_SEQNO = DT.SEQNO
WHERE DT.PERIOD_SEQNO = PS.SEQNO
GROUP BY PERIOD_SEQNO
)
FROM PERIOD_STATUS PS
WHERE PS.LEDGER='D'
-- update the Creditors rows LEDGER='C'
UPDATE PS
SET
MINSTOCKSEQNO = (SELECT MINSTOCKSEQNO
FROM PERIOD_STATUS PER
WHERE PS.AGE = PER.AGE AND PER.LEDGER = 'S'
),
MINGLSEQNO = (SELECT MINGLSEQNO-1
FROM PERIOD_STATUS PER
WHERE PS.AGE = PER.AGE AND PER.LEDGER = 'G'
),
MINTRANSEQNO = (SELECT ISNULL(MIN(CT.SEQNO), -1)
FROM CR_TRANS CT
WHERE CT.PERIOD_SEQNO = PS.SEQNO
GROUP BY PERIOD_SEQNO
),
MINTRANLINESEQNO =(SELECT ISNULL(MIN(CL.SEQNO), -1)
FROM CR_TRANS CT
LEFT OUTER JOIN CR_INVLINES CL ON CL.HDR_SEQNO = CT.SEQNO
WHERE CT.PERIOD_SEQNO = PS.SEQNO
GROUP BY PERIOD_SEQNO
)
FROM PERIOD_STATUS PS
WHERE PS.LEDGER='C'
-- Fix nulls in the combinations that have no transactions
UPDATE PERIOD_STATUS
SET
MINSTOCKSEQNO = ISNULL(MINSTOCKSEQNO, -1),
MINGLSEQNO = ISNULL(MINGLSEQNO, -1),
MINTRANSEQNO = ISNULL(MINTRANSEQNO, -1),
MINTRANLINESEQNO = ISNULL(MINTRANLINESEQNO, -1),
MINORDSEQNO = ISNULL(MINORDSEQNO, -1),
MINORDLINESEQNO = ISNULL(MINORDLINESEQNO, -1)


-- FIX MONTH NAMES IN MANREP PERIOD TABLE
Update M set M.PERIOD_NAME = UPPER(DATENAME(month, M.STARTDATE))
from manrep_period M where parent_period_seqno <> 0

-- FIX MONTH NAMES IN MANREP TABLE
Update M set M.PERIOD_NAME = P.PERIOD_NAME
from manrep M inner join MANREP_PERIOD P on M.PERIOD_SEQNO = P.PERIOD_SEQNO

IF OBJECT_ID('dbo.CRM_BUDGET', 'U') IS NOT NULL
ALTER TABLE CRM_BUDGET CHECK CONSTRAINT ALL
IF OBJECT_ID('dbo.CAMPAIGN_WAVE', 'U') IS NOT NULL
ALTER TABLE CAMPAIGN_WAVE ENABLE TRIGGER ALL


end


Procedure: SP_GL_CONSOLIDATION
NameSP_GL_CONSOLIDATION
Note
Code-- =============================================
-- create date: october 29, 2010. Modified 30/1/2018
-- description:
-- Accepts age as parameter
-- Consolidates the gltrans records upto the specified age
-- Archives the details to gltrans_archive if not asked to drop the transactions
-- Doesnt run if the period specified lies in the current financial year
-- =============================================
CREATE PROCEDURE [dbo].[SP_GL_CONSOLIDATION]
    @age integer, -- periodno up to and including wil be consolidated
    @droptrans char(1) ='N' -- if 'Y' then dont keep gl trans details (use backup db)

as
begin
-- set nocount on added to prevent extra result sets from
-- interfering with select statements.
set nocount on;

declare @username varchar(3)
declare @newsessionid integer
declare @gldetails_width integer
declare @period_seqno integer
declare @transcount integer
declare @YearAge integer
declare @errorthrown char(1)

set @errorthrown = 'N'

set @YearAge = (select yearage from period_status
     where period_status.age = @age and ledger = 'G')
if @YearAge = 0 -- should not run for current financial year
return;

set @username = (select substring(username, 1, 3) from general_info)

exec GEN_ID 'dr_trans', 'session_id', 'Y', @newsessionid output


exec GET_PROFILE_VALUE_INT 'GLTRANS_DETAILS_WIDTH', @gldetails_width output
if @gldetails_width < 30 set @gldetails_width = 30

select @period_seqno = seqno from period_status
where period_status.age = @age and ledger = 'G'

select @transcount=count(seqno) from gltrans
where period_seqno <= @period_seqno

IF @transcount > 0
BEGIN
SET TRANSACTION ISOLATION LEVEL SERIALIZABLE
BEGIN TRANSACTION
alter table gltrans disable trigger all

--insert consolidated entries in gltrans for selected period
insert into gltrans(
accno, subaccno, period_seqno, companyno, branchno, batchno,
initials, details, source,
amount,
fcamount,
session_id)
select
accno, subaccno, period_seqno, 0 companyno, branchno, 0 batchno,
@username, substring('GL Consolidation', 1, @gldetails_width) , 'g',
sum(amount) amount,
sum(fcamount) fcamount,
@newsessionid
from gltrans
where period_seqno <= @period_seqno
and details <> 'GL Consolidation'
group by
accno, subaccno, period_seqno, branchno
if upper(@droptrans) = 'N'
begin --copy transactions to gltrans_archive table
insert into gltrans_archive(
seqno, accno, subaccno, transdate, period_seqno, companyno, branchno, batchno,
initials, chqno, invno, details, reconciled, source, amount, source_accno, source_seq,
fcamount, auto_reverse, reconcileno, taxretcode, session_id, source_lineseqno)
select
seqno, accno, subaccno, transdate, period_seqno, companyno, branchno, batchno,
initials, chqno, invno, substring(details, 1, @gldetails_width), reconciled, source, amount, source_accno, source_seq,
fcamount, auto_reverse, reconcileno, taxretcode, session_id, source_lineseqno
from gltrans
where period_seqno <= @period_seqno
and details <> 'GL Consolidation'
end
--delete archived transactions from gltrans
delete from gltrans
where period_seqno <= @period_seqno
and details <> 'GL Consolidation'

if @@error <> 0
begin
-- rollback the transaction
rollback transaction
SET @errorthrown = 'Y'
select @errorthrown errorthrown
return
end
alter table gltrans enable trigger all;

COMMIT TRANSACTION
END -- IF TRANSCOUNT > 0

select @errorthrown errorthrown

end


Procedure: SP_MANREP_SNAPSHOT
NameSP_MANREP_SNAPSHOT
Note
CodeCREATE PROCEDURE [dbo].[SP_MANREP_SNAPSHOT]
@MANREPDATE DATETIME,
@SCHEDULED char(1)= 'A'
AS
BEGIN
SET NOCOUNT ON;
DECLARE @errorthrown CHAR(1), @RETURNVALUE INTEGER
  SET @errorthrown = 'N'

IF CONVERT(VARCHAR(10), @MANREPDATE, 101) = CONVERT(VARCHAR(10), GETDATE(), 101)
EXEC @RETURNVALUE = SP_MANREP_SNAPSHOT_CURRENT @MANREPDATE, @SCHEDULED
ELSE
EXEC @RETURNVALUE = SP_MANREP_SNAPSHOT_RETRO @MANREPDATE

IF @RETURNVALUE <> 0
SET @errorthrown = 'Y'
SELECT @errorthrown errorthrown
END


Procedure: SP_MANREP_SNAPSHOT_CURRENT
NameSP_MANREP_SNAPSHOT_CURRENT
Note
CodeCREATE PROCEDURE [dbo].[SP_MANREP_SNAPSHOT_CURRENT]
@MANREPDATE DATETIME,
@SCHEDULED CHAR(1)
AS
Declare
@VersionNumber integer,
@period_seqno integer,
@Period_StartDate datetime,
@Period_EndDate datetime,
@Period_YearStart datetime,
@Period_YearEnd datetime,
@Period_Name varchar(50),
@Period_Parent_seqno integer,
@sql_str varchar(max),
@sql_and varchar(max),
@CurrentDate datetime,
@Current_period_seqno integer,
@CurrentPeriod char(1),
@Day_sales float,
@Period_sales float,
@Year_sales float,
@Debtor_agedBal_0 float,
@Debtor_agedBal_1 float,
@Debtor_agedBal_2 float,
@Debtor_agedBal_3 float,
@Creditor_agedBal_0 float,
@Creditor_agedBal_1 float,
@Creditor_agedBal_2 float,
@Creditor_agedBal_3 float,
@Day_Cost float,
@Period_Cost float,
@Year_Cost float,
@Avg_DebtorDays float,
@Avg_CreditorDays float,
@New_seqno int,
@Range_enddate datetime,
@Sum_DayOrderValue float,
@Sum_DayOrderQty integer,
@Sum_Day_sales float,
@Sum_Period_sales float,
@Sum_Year_sales float,
@sum_Day_Cost float,
@sum_Period_Cost float,
@sum_Year_Cost float,
@sum_DayOrderValue_EXCLUDEQUOTES float,
@sum_DayOrderQty_EXCLUDEQUOTES integer,
@sum_Day_sales_posttime float,
@sum_Period_sales_posttime float,
@sum_Year_sales_posttime float,
@sum_Day_Cost_posttime float,
@sum_Period_Cost_posttime float,
@sum_Year_Cost_posttime float,
@period_days integer,
@days_used integer,
@Budget_Seqno integer,
@PD_budget float,
@TOTALSTOCKCOST_AVECOST float,
@TOTALSTOCKCOST_LATESTCOST float,
@TOTALSTOCKCOST_STDCOST float,
@Manrep_entry_exists CHAR(1),
@Manrep_existing_entry_seqno integer,
@RunrateSoFar float,
@RunrateThisPeriod float,
@MarginPercent float,
@Parent_period_seqno integer

BEGIN
SET NOCOUNT ON;

set @Manrep_entry_exists = 'N'
select @VersionNumber= VERSION_NO from MODULE_SECURITY where APP_ID=1300

set @MANREPDATE= CONVERT(VARCHAR(10), @MANREPDATE, 101)
set @CurrentDate= CONVERT(VARCHAR(10), GETDATE(), 101)
set @Range_enddate = dateadd(day, 1, @MANREPDATE)
-- Get Period_seqno from manrep_period based on on input parameter
select @period_seqno = period_seqno, @Parent_period_seqno= PARENT_PERIOD_SEQNO from MANREP_PERIOD
where ((@MANREPDATE >= STARTDATE) and (@MANREPDATE <= ENDDATE)) and (PARENT_PERIOD_SEQNO<>0)

--find if its the current period
select @Current_period_seqno = period_seqno from MANREP_PERIOD
where ((@CurrentDate >= STARTDATE) and (@CurrentDate <= ENDDATE)) and (PARENT_PERIOD_SEQNO<>0)
if @Current_period_seqno= @period_seqno
set @CurrentPeriod= 'Y'
else
set @CurrentPeriod = 'N'

-- find if the Manrep entry for today exists
select @Manrep_existing_entry_seqno = SEQNO from MANREP where (CALCDATE = @MANREPDATE) and (period_seqno = @period_seqno)
if @Manrep_existing_entry_seqno > 0
set @Manrep_entry_exists = 'Y'
else
set @Manrep_entry_exists = 'N'

-- Get Period Info
SELECT @Period_StartDate=Period.StartDate, @Period_EndDate=Period.EndDate,
@Period_YearStart=Period_Year.StartDate, @Period_YearEnd=Period_Year.EndDate,
@Period_Name=Period.PERIOD_NAME,
@Period_Parent_seqno=Period.PARENT_PERIOD_SEQNO
FROM MANREP_PERIOD Period
LEFT JOIN MANREP_PERIOD Period_Year ON Period_Year.Period_SeqNo = Period.Parent_Period_SeqNo
WHERE (Period.Period_SeqNo=@period_seqno)

-- Get Debtor Balances
SELECT
@Debtor_agedBal_3 = SUM(DR_ACCS.AGEDBAL3 / Currencies.SellRate),
@Debtor_agedBal_2 = SUM(DR_ACCS.AGEDBAL2 / Currencies.SellRate),
@Debtor_agedBal_1 = SUM(DR_ACCS.AGEDBAL1 / Currencies.SellRate),
@Debtor_agedBal_0 = SUM(DR_ACCS.AGEDBAL0 / Currencies.SellRate)
FROM DR_ACCS
LEFT JOIN Currencies ON Currencies.CurrencyNo = DR_Accs.CurrencyNo
-- Get Creditor Balances
SELECT
@Creditor_agedBal_3 = SUM(CR_ACCS.AGEDBAL3 / Currencies.BUYRATE),
@Creditor_agedBal_2 = SUM(CR_ACCS.AGEDBAL2 / Currencies.BUYRATE),
@Creditor_agedBal_1 = SUM(CR_ACCS.AGEDBAL1 / Currencies.BUYRATE),
@Creditor_agedBal_0 = SUM(CR_ACCS.AGEDBAL0 / Currencies.BUYRATE)
FROM CR_ACCS
LEFT JOIN Currencies ON Currencies.CurrencyNo = CR_ACCS.CurrencyNo
-- Get Average Debtor Days
SELECT @Avg_DebtorDays = sum( cast(GetDate() - transdate as integer)) / count(*) FROM DR_TRANS WITH(NOLOCK)
WHERE (Dr_trans.TRANSTYPE=1)
AND (TRANSDATE <@MANREPDATE) and (Allocated = '0')

-- Get Average Creditor Days
SELECT @Avg_CreditorDays = sum( cast(GetDate() - transdate as integer)) / count(*) FROM CR_TRANS WITH(NOLOCK)
WHERE (CR_TRANS.TRANSTYPE=1)
AND (TRANSDATE <@MANREPDATE) and (Allocated = '0')

Declare @Tmp_Branches TABLE
                (
Branchno INTEGER NOT NULL,
DayOrderValue DOUBLE PRECISION NOT NULL DEFAULT(0),
DayOrderQty INTEGER NOT NULL DEFAULT(0),
Day_sales DOUBLE PRECISION NOT NULL DEFAULT(0),
Period_sales DOUBLE PRECISION NOT NULL DEFAULT(0),
Year_sales DOUBLE PRECISION NOT NULL DEFAULT(0),
Day_Cost DOUBLE PRECISION NOT NULL DEFAULT(0),
Period_Cost DOUBLE PRECISION NOT NULL DEFAULT(0),
Year_Cost DOUBLE PRECISION NOT NULL DEFAULT(0),
DayOrderValue_EXCLUDEQUOTES DOUBLE PRECISION NOT NULL DEFAULT(0),
DayOrderQty_EXCLUDEQUOTES INTEGER NOT NULL DEFAULT(0),
Day_sales_posttime DOUBLE PRECISION NOT NULL DEFAULT(0),
Period_sales_posttime DOUBLE PRECISION NOT NULL DEFAULT(0),
Year_sales_posttime DOUBLE PRECISION NOT NULL DEFAULT(0),
Day_Cost_posttime DOUBLE PRECISION NOT NULL DEFAULT(0),
Period_Cost_posttime DOUBLE PRECISION NOT NULL DEFAULT(0),
Year_Cost_posttime DOUBLE PRECISION NOT NULL DEFAULT(0),
Avg_DebtorDays DOUBLE PRECISION NOT NULL DEFAULT(0),
Avg_CreditorDays DOUBLE PRECISION NOT NULL DEFAULT(0),
PD_Budget_Branch DOUBLE PRECISION NOT NULL DEFAULT(0) )

select @period_days= count(*), @RunrateThisperiod= SUM(RUNRATE) from MANREP_DAYPLAN where (PERIOD_SEQNO=@period_seqno) and (WORKDAY= 'Y')
select @days_used= count(*), @RunrateSoFar= SUM(RUNRATE) from MANREP_DAYPLAN where (PERIOD_SEQNO=@period_seqno) and (WORKDAY= 'Y') and (THEDATE between @Period_startDate and @MANREPDATE)
Select @Budget_Seqno=BUDGET_SEQNO, @PD_Budget= BUDGETVALUE, @MarginPercent = MARGINPERCENT from MANREP_BUDGET where (PERIOD_SEQNO=@period_seqno)
select
@TOTALSTOCKCOST_AVECOST = sum(avecost*totalstock),
@TOTALSTOCKCOST_LATESTCOST = sum(latestcost*totalstock),
@TOTALSTOCKCOST_STDCOST = sum(stdcost*totalstock)
from STOCK_ITEMS where TOTALSTOCK<>0 and STATUS = 'S'

SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED
BEGIN TRANSACTION

if @Manrep_entry_exists = 'Y'
begin
delete from manrep where SEQNO = @Manrep_existing_entry_seqno
delete from MANREP_STOCK where MANREP_SEQNO = @Manrep_existing_entry_seqno
delete from MANREP_BRANCH where MANREP_SEQNO = @Manrep_existing_entry_seqno
delete from MANREP_SALESPERSON where MANREP_SEQNO = @Manrep_existing_entry_seqno
end

insert into @Tmp_Branches
select * from FN_MANREP_CALC_BRANCHES(@MANREPDATE, @period_seqno, @CurrentPeriod)

Select
@sum_DayOrderValue = sum(DayOrderValue) ,
@sum_DayOrderQty = sum(DayOrderQty) ,
@sum_Day_sales = sum(Day_sales) ,
@sum_Period_sales = sum(Period_sales) ,
@sum_Year_sales = sum(Year_sales) ,
@sum_Day_Cost = sum(Day_Cost) ,
@sum_Period_Cost = sum(Period_Cost) ,
@sum_Year_Cost = sum(Year_Cost) ,
@sum_DayOrderValue_EXCLUDEQUOTES = sum(DayOrderValue_EXCLUDEQUOTES) ,
@sum_DayOrderQty_EXCLUDEQUOTES = sum(DayOrderQty_EXCLUDEQUOTES) ,
@sum_Day_sales_posttime = sum(Day_sales_posttime) ,
@sum_Period_sales_posttime = sum(Period_sales_posttime) ,
@sum_Year_sales_posttime = sum(Year_sales_posttime) ,
@sum_Day_Cost_posttime = sum(Day_Cost_posttime) ,
@sum_Period_Cost_posttime = sum(Period_Cost_posttime) ,
@sum_Year_Cost_posttime = sum(Year_Cost_posttime)
from @Tmp_Branches

-- insert records into manrep table
select @New_seqno =(case when MAX(seqno) is NULL then 1 else (MAX(seqno)+ 1) end) from MANREP
 INSERT INTO MANREP
 (
PERIOD_SEQNO,
SEQNO,
PERIOD_NAME,
CALCTIME, CALCDATE,
[VERSION],
PERIOD_DAYS,
RUNRATE_THIS_PERIOD,
BUDGET_SEQNO,
PD_BUDGET,
YR_BUDGET,
DAYS_USED,
RUNRATE_SO_FAR,
DAY_ORDERVAL,
DAY_ORDERQTY,
DAY_SALES,
PD_SALES,
YR_SALES,
DEBAGEDBAL3, DEBAGEDBAL2, DEBAGEDBAL1, DEBAGEDBAL0,
CREDAGEDBAL3, CREDAGEDBAL2, CREDAGEDBAL1, CREDAGEDBAL0,
--TOTALSTOCKCOST,
DAY_COST, PD_COST, YR_COST,
AVG_DRTRANS_AGE, AVG_CRTRANS_AGE,
DAY_ORDERVAL_EXCLUDEQUOTES,
DAY_ORDERQTY_EXCLUDEQUOTES,
DAY_SALES_POSTTIME,
PD_SALES_POSTTIME,
YR_SALES_POSTTIME,
DAY_COST_POSTTIME,
PD_COST_POSTTIME,
YR_COST_POSTTIME,
TOTALSTOCKCOST_AVECOST,
TOTALSTOCKCOST_LATESTCOST,
TOTALSTOCKCOST_STDCOST ,
SCHEDULED,
BUDGET_MARGINPERCENT,
PERIOD_STARTDATE,
PERIOD_ENDDATE,
PARENT_PERIOD_SEQNO
  )
VALUES(
@period_seqno,
@New_seqno,
@Period_Name,
GETDATE(), @MANREPDATE,
@Versionnumber,
@period_days,
@RunrateThisPeriod,
@Budget_Seqno,
Round(isnull(@PD_Budget, 0), 0),
Round(isnull(@PD_Budget, 0), 0),
@days_used,
@RunrateSoFar,
Round(isnull(@sum_DayOrderValue, 0), 0),
isnull(@sum_DayOrderQty, 0),
Round(isnull(@sum_Day_sales, 0), 0),
Round(isnull(@sum_Period_sales, 0), 0),
Round(isnull(@sum_Year_sales, 0), 0),
Round(@Debtor_agedBal_3, 0), Round(@Debtor_agedBal_2, 0), Round(@Debtor_agedBal_1, 0), Round(@Debtor_agedBal_0, 0),
Round(@Creditor_agedBal_3, 0), Round(@Creditor_agedBal_2, 0), Round(@Creditor_agedBal_1, 0), Round(@Creditor_agedBal_0, 0),
--(select sum(avecost*totalstock) from STOCK_ITEMS where TOTALSTOCK<>0 and STATUS = 'S'), --need to take cost_methodstr setting into consideration(registry)
Round(isnull(@sum_Day_Cost, 0), 0),
Round(isnull(@sum_Period_Cost, 0), 0),
Round(isnull(@sum_Year_Cost, 0), 0),
@Avg_DebtorDays, @Avg_CreditorDays,
Round(isnull(@sum_DayOrderValue_EXCLUDEQUOTES, 0), 0),
Round(isnull(@sum_DayOrderQty_EXCLUDEQUOTES, 0), 0),
Round(isnull(@sum_Day_sales_posttime, 0), 0),
Round(isnull(@sum_Period_sales_posttime, 0), 0),
Round(isnull(@sum_Year_sales_posttime, 0), 0),
Round(isnull(@sum_Day_Cost_posttime, 0), 0),
Round(isnull(@sum_Period_Cost_posttime, 0), 0),
Round(isnull(@sum_Year_Cost_posttime, 0), 0),
Round(isnull(@TOTALSTOCKCOST_AVECOST, 0), 0),
Round(isnull(@TOTALSTOCKCOST_LATESTCOST, 0), 0),
Round(isnull(@TOTALSTOCKCOST_STDCOST, 0), 0),
@SCHEDULED,
@MarginPercent,
@Period_StartDate,
@Period_EndDate,
@Parent_period_seqno
)

-- insert records into manrep_branch
insert into manrep_branch(manrep_seqno, branchno,
day_orderqty, day_orderval,
day_sales, pd_sales, yr_sales,
day_cost, pd_cost, yr_cost,
avg_drtrans_age, avg_crtrans_age, SCHEDULED,
DAY_ORDERQTY_EXCLUDEQUOTES, DAY_ORDERVAL_EXCLUDEQUOTES,
DAY_SALES_POSTTIME, PD_SALES_POSTTIME, YR_SALES_POSTTIME,
DAY_COST_POSTTIME, PD_COST_POSTTIME, YR_COST_POSTTIME,
Days_used, runrate_so_far, period_days, runrate_this_period,
pd_budget)
select @New_seqno, Branchno,
isnull(DayOrderQty, 0) , Round(isnull(DayOrderValue, 0), 0) ,
Round(isnull(Day_sales, 0), 0) , Round(isnull(Period_sales, 0), 0) , Round(isnull(Year_sales, 0), 0) ,
Round(isnull(Day_Cost, 0), 0) , Round(isnull(Period_Cost, 0), 0) , Round(isnull(Year_Cost, 0), 0) ,
Avg_DebtorDays , Avg_CreditorDays, @SCHEDULED,
isnull(DayOrderQty_EXCLUDEQUOTES, 0) , Round(isnull(DayOrderValue_EXCLUDEQUOTES, 0), 0) ,
Round(isnull(Day_sales_posttime, 0), 0) , Round(isnull(Period_sales_posttime, 0), 0) , Round(isnull(Year_sales_posttime, 0), 0) ,
Round(isnull(Day_Cost_posttime, 0), 0) , Round(isnull(Period_Cost_posttime, 0), 0) , Round(isnull(Year_Cost_posttime, 0), 0) ,
@days_used, @RunrateSoFar, @period_days, @RunrateThisPeriod,
isnull(PD_budget_branch, 0)
from @Tmp_Branches

-- insert records into manrep_Salespersons
insert into manrep_salesperson(manrep_seqno, salesno,
day_orderqty, day_orderval,
day_sales, pd_sales, yr_sales,
day_cost, pd_cost, yr_cost,
avg_drtrans_age, avg_crtrans_age, SCHEDULED,
DAY_ORDERQTY_EXCLUDEQUOTES, DAY_ORDERVAL_EXCLUDEQUOTES,
DAY_SALES_POSTTIME, PD_SALES_POSTTIME, YR_SALES_POSTTIME,
DAY_COST_POSTTIME, PD_COST_POSTTIME, YR_COST_POSTTIME,
Days_used, runrate_so_far, period_days, runrate_this_period,
pd_budget)
select @New_seqno, Salesno,
isnull(DayOrderQty, 0) , Round(isnull(DayOrderValue, 0), 0) ,
Round(isnull(Day_sales, 0), 0) , Round(isnull(Period_sales, 0), 0) , Round(isnull(Year_sales, 0), 0) ,
Round(isnull(Day_Cost, 0), 0) , Round(isnull(Period_Cost, 0), 0) , Round(isnull(Year_Cost, 0), 0) ,
Avg_DebtorDays , Avg_CreditorDays, @SCHEDULED,
isnull(DayOrderQty_EXCLUDEQUOTES, 0) , Round(isnull(DayOrderValue_EXCLUDEQUOTES, 0), 0) ,
Round(isnull(Day_sales_posttime, 0), 0) , Round(isnull(Period_sales_posttime, 0), 0) , Round(isnull(Year_sales_posttime, 0), 0) ,
Round(isnull(Day_Cost_posttime, 0), 0) , Round(isnull(Period_Cost_posttime, 0), 0) , Round(isnull(Year_Cost_posttime, 0), 0) ,
@days_used, @RunrateSoFar, @period_days, @RunrateThisPeriod,
isnull(@PD_budget, 0)
from FN_MANREP_CALC_SALESPERSONS(@MANREPDATE, @period_seqno, @CurrentPeriod)

-- Insert records into manrep_stock
INSERT INTO Manrep_Stock(
ManRep_SeqNo, Location,
Amount_avecost,
Amount_latestcost,
Amount_stdcost,
SCHEDULED
)
SELECT @New_seqno, Location,
Round(Sum( Stock_Items.AVECOST * Stock_Loc_Info.Qty ), 0),
Round(Sum( Stock_Items.LATESTCOST * Stock_Loc_Info.Qty ), 0),
Round(Sum( Stock_Items.STDCOST * Stock_Loc_Info.Qty ), 0),
@SCHEDULED
FROM Stock_Locations
LEFT JOIN Stock_Loc_Info ON Stock_Loc_Info.Location = Stock_Locations.LocNo
LEFT JOIN Stock_Items ON Stock_Items.StockCode = Stock_Loc_Info.StockCode
WHERE Stock_Locations.IsActive = 'Y'
AND Stock_Items.Status = 'S'
Group BY Location

-- Delete existing records from manrep_closing_stock
DELETE FROM MANREP_CLOSING_STOCK WHERE MANREP_SEQNO = @New_seqno

-- insert records in Manrep_closing_stock
INSERT INTO MANREP_CLOSING_STOCK (
MANREP_SEQNO,
STOCKCODE,
TOTALSTOCK,
AVECOST,
LATESTCOST,
STDCOST,
SCHEDULED
)
SELECT @New_seqno, STOCKCODE, TOTALSTOCK, AVECOST,
LATESTCOST,
STDCOST,
@SCHEDULED
FROM STOCK_ITEMS
WHERE TOTALSTOCK > 0

IF @@error <> 0
BEGIN
-- rollback the transaction
ROLLBACK TRANSACTION
RETURN
END
COMMIT TRANSACTION

END


Procedure: SP_MANREP_SNAPSHOT_RETRO
NameSP_MANREP_SNAPSHOT_RETRO
Note
CodeCREATE PROCEDURE [dbo].[SP_MANREP_SNAPSHOT_RETRO]
@MANREPDATE DATETIME
AS
Declare
@seqno integer,
@period_seqno integer,
@calcdate datetime,
@day_sales float,
@PD_sales float,
@Year_sales float,
@Day_cost float,
@PD_Cost float,
@year_cost float,
@Day_orderval float,
@Day_orderqty integer,
@CurrentDate datetime,
@Current_period_seqno integer,
@CurrentPeriod char(1),
@VersionNumber integer,
@cur_seqno integer,
@cur_period_seqno integer,
@cur_calcdate datetime,
@sql_str varchar(max),
@sql_fields varchar(max),
@Day_orderval_EXCLUDEQUOTES float,
@Day_orderqty_EXCLUDEQUOTES integer,
@day_sales_posttime float,
@PD_sales_posttime float,
@Year_sales_posttime float,
@Day_cost_posttime float,
@PD_Cost_posttime float,
@year_cost_posttime float,
@PD_budget float,
@Budget_MarginPercent float
BEGIN
SET NOCOUNT ON;
 Declare @Tmp_Branches table (
Branchno INTEGER NOT NULL,
Day_OrderVal DOUBLE PRECISION NOT NULL DEFAULT(0),
Day_OrderQty INTEGER NOT NULL DEFAULT(0),
Day_sales DOUBLE PRECISION NOT NULL DEFAULT(0),
PD_sales DOUBLE PRECISION NOT NULL DEFAULT(0),
Yr_sales DOUBLE PRECISION NOT NULL DEFAULT(0),
Day_Cost DOUBLE PRECISION NOT NULL DEFAULT(0),
PD_Cost DOUBLE PRECISION NOT NULL DEFAULT(0),
Yr_Cost DOUBLE PRECISION NOT NULL DEFAULT(0),
Day_OrderVal_EXCLUDEQUOTES DOUBLE PRECISION NOT NULL DEFAULT(0),
Day_OrderQty_EXCLUDEQUOTES INTEGER NOT NULL DEFAULT(0),
Day_sales_posttime DOUBLE PRECISION NOT NULL DEFAULT(0),
PD_sales_posttime DOUBLE PRECISION NOT NULL DEFAULT(0),
Yr_sales_posttime DOUBLE PRECISION NOT NULL DEFAULT(0),
Day_Cost_posttime DOUBLE PRECISION NOT NULL DEFAULT(0),
PD_Cost_posttime DOUBLE PRECISION NOT NULL DEFAULT(0),
Yr_Cost_posttime DOUBLE PRECISION NOT NULL DEFAULT(0),
Avg_DebtorDays DOUBLE PRECISION NOT NULL DEFAULT(0),
Avg_CreditorDays DOUBLE PRECISION NOT NULL DEFAULT(0),
PD_Budget_Branch DOUBLE PRECISION NOT NULL DEFAULT(0)
)

select @VersionNumber= VERSION_NO from MODULE_SECURITY where APP_ID=1300

set @CurrentDate= CONVERT(VARCHAR(10), GETDATE(), 101)
-- Get Period_seqno from manrep_period based on on input parameter
select @period_seqno = period_seqno from MANREP_PERIOD
where ((@MANREPDATE >= STARTDATE) and (@MANREPDATE <= ENDDATE)) and (PARENT_PERIOD_SEQNO<>0)

-- calculte Period_seqno budgetvalue
Select @PD_Budget= BUDGETVALUE, @Budget_MarginPercent = MARGINPERCENT
from MANREP_BUDGET where (PERIOD_SEQNO=@period_seqno)

--find if its the current period
select @Current_period_seqno = period_seqno from MANREP_PERIOD
where ((@CurrentDate >= STARTDATE) and (@CurrentDate <= ENDDATE)) and (PARENT_PERIOD_SEQNO<>0)
if @Current_period_seqno= @period_seqno
set @CurrentPeriod= 'Y'
else
set @CurrentPeriod = 'N'


SET TRANSACTION ISOLATION LEVEL SERIALIZABLE
BEGIN TRANSACTION

Declare Period_ctr cursor for
select seqno, period_seqno, calcdate, day_sales, PD_sales, Day_cost, PD_Cost,
Day_orderval, Day_orderqty
from manrep
where calcdate = @MANREPDATE
order by SEQNO

open Period_ctr

FETCH NEXT FROM Period_ctr
INTO @seqno, @period_seqno, @calcdate, @day_sales, @PD_sales, @Day_cost, @PD_Cost,
@Day_orderval, @Day_orderqty

while @@FETCH_STATUS = 0 begin
  FETCH NEXT FROM Period_ctr
INTO @seqno, @period_seqno, @calcdate, @day_sales, @PD_sales, @Day_cost, @PD_Cost,
@Day_orderval, @Day_orderqty

set @cur_seqno = @seqno
set @cur_period_seqno = @period_seqno
set @cur_calcdate = @calcdate

insert into @Tmp_Branches
select * from FN_MANREP_CALC_BRANCHES(@cur_calcdate, @cur_period_seqno, @CurrentPeriod)
select @year_cost= sum(yr_cost), @Year_sales= sum(yr_sales) from @Tmp_Branches

if @MANREPDATE = @cur_calcdate
begin
select
@Day_cost= sum(Day_Cost),
@Day_sales= sum(Day_sales),
@Day_orderval= sum(Day_OrderVal),
@Day_orderqty= sum(Day_OrderQty),
@Day_cost_posttime= sum(Day_Cost_posttime),
@Day_sales_posttime= sum(Day_sales_posttime),
@Day_orderval_EXCLUDEQUOTES= sum(Day_OrderVal_EXCLUDEQUOTES),
@Day_orderqty_EXCLUDEQUOTES= sum(Day_OrderQty_EXCLUDEQUOTES)
from @Tmp_Branches
end

if @cur_period_seqno = @period_seqno
begin
select @PD_Cost= sum(PD_Cost), @PD_sales= sum(PD_sales),
@PD_Cost_posttime= sum(PD_Cost_posttime), @PD_sales_posttime= sum(PD_sales_posttime)
from @Tmp_Branches
end

Update manrep
Set
DAY_SALES = Round(@day_sales, 0),
PD_SALES = Round(@PD_sales, 0),
YR_SALES = Round(@Year_sales, 0),
DAY_ORDERVAL = Round(@Day_orderval, 0),
DAY_ORDERQTY = @Day_orderqty,
calctime = getdate(),
[VERSION] = @VersionNumber,
DAY_COST = Round(@Day_cost, 0),
PD_COST = Round(@PD_cost, 0),
YR_COST = Round(@Year_cost, 0),
DAY_SALES_posttime = Round(@day_sales_posttime, 0),
PD_SALES_posttime = Round(@PD_sales_posttime, 0),
YR_SALES_posttime = Round(@Year_sales_posttime, 0),
DAY_ORDERVAL_excludequotes = Round(@Day_orderval_excludequotes, 0),
DAY_ORDERQTY_excludequotes = @Day_orderqty_excludequotes,
DAY_COST_posttime = Round(@Day_cost_posttime, 0),
PD_COST_posttime = Round(@PD_cost_posttime, 0),
YR_COST_posttime = Round(@Year_cost_posttime, 0)
where SEQNO = @cur_seqno


-- update all branch budget
Update manrep
Set PD_BUDGET = Round(isnull(@PD_Budget, 0), 0),
YR_BUDGET = Round(isnull(@PD_Budget, 0), 0),
BUDGET_MARGINPERCENT = Round(isnull(@Budget_MarginPercent, 0), 0)
where PERIOD_SEQNO = @period_seqno

-- Update branch budget
UPDATE M
SET M.pd_budget = T.PD_budget_branch
FROM MANREP_BRANCH M INNER JOIN
        (select branchno, isnull(PD_budget_branch, 0)AS PD_budget_branch from @Tmp_Branches)AS T
        ON M.Branchno = T.branchno AND M.MANREP_SEQNO = @cur_seqno

-- YEAR SALES AND COST ALWAYS GET UPDATED
UPDATE M
SET M.yr_cost= Round(T.yr_cost, 0), M.yr_sales=Round(T.yr_sales, 0),
M.yr_cost_posttime=Round(T.yr_cost_posttime, 0), M.yr_sales_posttime=Round(T.yr_sales_posttime, 0)
        FROM MANREP_BRANCH M inner join @tmp_branches T on M.branchno = T.branchno
        WHERE M.MANREP_SEQNO = @cur_seqno

UPDATE M
SET M.yr_cost= Round(T.Year_Cost, 0), M.yr_sales=Round(T.Year_sales, 0),
M.yr_cost_posttime=Round(T.Year_Cost_posttime, 0), M.yr_sales_posttime=Round(T.Year_sales_posttime, 0)
        FROM MANREP_SALESPERSON M inner join FN_MANREP_CALC_SALESPERSONS(@cur_calcdate, @cur_period_seqno, @CurrentPeriod) T
        on M.SALESNO = T.SALESNO
        WHERE M.MANREP_SEQNO = @cur_seqno

if @MANREPDATE = @cur_calcdate
begin
UPDATE M
SET M.day_cost=Round(T.day_cost, 0), M.day_sales=Round(T.day_sales, 0),
M.day_orderval=Round(T.day_orderval, 0), M.day_orderqty=T.day_orderqty,
M.day_cost_posttime=Round(T.day_cost_posttime, 0), M.day_sales_posttime=Round(T.day_sales_posttime, 0),
M.day_orderval_excludeQuotes=Round(T.day_orderval_excludeQuotes, 0),
M.day_orderqty_excludeQuotes=T.day_orderqty_excludeQuotes
FROM MANREP_BRANCH M inner join @tmp_branches T on M.branchno = T.branchno
WHERE M.MANREP_SEQNO = @cur_seqno

UPDATE M
SET M.day_cost=Round(T.day_cost, 0), M.day_sales=Round(T.day_sales, 0),
M.day_orderval=Round(T.DayOrderValue, 0), M.day_orderqty=T.dayorderqty,
M.day_cost_posttime=Round(T.day_cost_posttime, 0), M.day_sales_posttime=Round(T.day_sales_posttime, 0),
M.day_orderval_excludeQuotes=Round(T.DayOrderValue_EXCLUDEQUOTES, 0),
M.day_orderqty_excludeQuotes=T.dayorderqty_excludeQuotes
FROM MANREP_SALESPERSON M inner join FN_MANREP_CALC_SALESPERSONS(@cur_calcdate, @cur_period_seqno, @CurrentPeriod) T
on M.SALESNO = T.SalesNo
WHERE M.MANREP_SEQNO = @cur_seqno
end

if @cur_period_seqno = @period_seqno
begin
UPDATE M
SET M.PD_cost=Round(T.PD_cost, 0), M.PD_sales=Round(T.PD_sales, 0),
M.PD_cost_posttime=Round(T.PD_cost_posttime, 0), M.PD_sales_posttime=Round(T.PD_sales_posttime, 0)
FROM MANREP_BRANCH M inner join @tmp_branches T on M.branchno = T.branchno
WHERE M.MANREP_SEQNO = @cur_seqno
UPDATE M
SET M.PD_cost=Round(T.Period_Cost, 0), M.PD_sales=Round(T.Period_sales, 0),
M.PD_cost_posttime=Round(T.Period_Cost_posttime, 0), M.PD_sales_posttime=Round(T.Period_sales_posttime, 0)
FROM MANREP_SALESPERSON M inner join FN_MANREP_CALC_SALESPERSONS(@cur_calcdate, @cur_period_seqno, @CurrentPeriod) T
on M.salesno = T.salesno
WHERE M.MANREP_SEQNO = @cur_seqno
end
end
close Period_ctr
deallocate Period_ctr

IF @@error <> 0
BEGIN
-- rollback the transaction
ROLLBACK TRANSACTION
RETURN
END
COMMIT TRANSACTION
END


Procedure: SP_RefreshAllViews
NameSP_RefreshAllViews
Note
CodeCREATE PROCEDURE [dbo].[SP_RefreshAllViews] (@Param_Viewname VARCHAR(500)= NULL)
AS
      DECLARE @My_View NVARCHAR(256)
      DECLARE @ERR_MSG NVARCHAR(MAX)
BEGIN
--CREATE CURSOR TO READ THE DATABASE VIEWS IN ORDER TO VALIDATE
  DECLARE @View_Cursor CURSOR
  SET @View_Cursor = CURSOR FOR
  SELECT [NAME]
    FROM SYSOBJECTS
   WHERE XTYPE = 'V'
     AND [NAME] NOT IN ('SYSSEGMENTS', 'SYSCONSTRAINTS')
     AND CATEGORY=0
     AND (@Param_Viewname IS NULL OR @Param_Viewname='' OR @Param_Viewname=[NAME])
   ORDER BY CRDATE
  -- fetch the first record in the Cursor
  OPEN @View_Cursor
  FETCH NEXT FROM @View_Cursor INTO @My_View
  WHILE (@@FETCH_STATUS = 0)
  BEGIN
    BEGIN TRY
       SET @Param_Viewname = ('['+@Param_Viewname+']')
       PRINT 'Refreshing View... ' + @My_View
       EXEC sp_refreshview @My_View
    END TRY
    BEGIN CATCH
       SELECT @ERR_MSG=ERROR_MESSAGE()
       PRINT 'Refreshing View... ' + @My_View + ' fail due to '+@ERR_MSG
    END CATCH
    FETCH NEXT FROM @View_Cursor INTO @My_View
  END
  CLOSE @View_Cursor
  DEALLOCATE @View_Cursor
  PRINT 'Refreshed successfully'
END


Procedure: SP_SALESANALYSISMATRIX_CALC
NameSP_SALESANALYSISMATRIX_CALC
Note
Code-- =============================================
-- Description:
-- @SALESANALYSISTYPE (saPeriod, saDateRange, saGroupPercent, saDiscounts, sa12MonthQty, sa12MonthSales, sa5WeeksQty, sa5WeekSales)
-- =============================================
CREATE PROCEDURE [dbo].[SP_SALESANALYSISMATRIX_CALC]
@SALESANALYSISTYPE INTEGER = -1,
@SQL_SELECT_PRIMARY VARCHAR(MAX)= '',
@SQL_SELECT_SECONDARY VARCHAR(MAX)= '',
@SQL_GROUPBY VARCHAR(MAX)= '',
@SQL_WHERE varchar(max) = '',
@AGE INTEGER=0,
@AGE_TO INTEGER =0,
@YEARSTART INTEGER =0,
@DATERANGE_START DATETIME = NULL,
@DATERANGE_END DATETIME = NULL,
@LOGINNAME VARCHAR(50)=''
AS
DECLARE
@SQL_SELECT VARCHAR(MAX),
@AGE_STR VARCHAR(20),
@YEARSTART_STR VARCHAR(20),
@SQL_QUERY VARCHAR(MAX)
BEGIN
SET NOCOUNT ON;

declare @temp_table table
(
groupno VARCHAR(50),
groupname VARCHAR(70),
CODE VARCHAR(70),
Code_DESCRIPTION VARCHAR(70),
AGE INTEGER,
ival DOUBLE PRECISION NOT NULL DEFAULT(0),
ivaldisc DOUBLE PRECISION NOT NULL DEFAULT(0),
icost DOUBLE PRECISION NOT NULL DEFAULT(0),
iquantity DOUBLE PRECISION NOT NULL DEFAULT(0),
ilistval DOUBLE PRECISION NOT NULL DEFAULT(0),
MONTH1 DOUBLE PRECISION NOT NULL DEFAULT(0),
MONTH2 DOUBLE PRECISION NOT NULL DEFAULT(0),
MONTH3 DOUBLE PRECISION NOT NULL DEFAULT(0),
MONTH4 DOUBLE PRECISION NOT NULL DEFAULT(0),
MONTH5 DOUBLE PRECISION NOT NULL DEFAULT(0),
TRANSDATE DATETIME
)

declare @temp_table_GROUP table
(
groupno VARCHAR(50),
groupname VARCHAR(70),
CODE VARCHAR(70),
Code_DESCRIPTION VARCHAR(70)
)

declare @temp_table_GROUP_Totals table
(
groupno VARCHAR(50),
groupname VARCHAR(70),
MTDTotal DOUBLE PRECISION NOT NULL DEFAULT(0),
YTDTotal DOUBLE PRECISION NOT NULL DEFAULT(0),
LYMTDTotal DOUBLE PRECISION NOT NULL DEFAULT(0),
LYYTDTotal DOUBLE PRECISION NOT NULL DEFAULT(0)
)

set @LOGINNAME = '' + @LOGINNAME + ''
IF @DATERANGE_START IS NULL
SET @DATERANGE_START = GETDATE()
IF @DATERANGE_END IS NULL
SET @DATERANGE_END = GETDATE()

IF @SQL_SELECT_SECONDARY = ''
BEGIN
--SET @SQL_GROUPBY= @SQL_SELECT_PRIMARY
set @SQL_SELECT_SECONDARY = @SQL_SELECT_PRIMARY
set @SQL_SELECT_PRIMARY = '0, ''UNGROUPED'' AS GROUPNAME'
END
--ELSE
--BEGIN
-- SET @SQL_GROUPBY= @SQL_SELECT_PRIMARY + ', ' + @SQL_SELECT_SECONDARY
--END

set @SQL_SELECT = @SQL_SELECT_PRIMARY + ', ' + @SQL_SELECT_SECONDARY
SET @AGE_STR= CAST(@AGE AS VARCHAR(20))
SET @YEARSTART_STR= CAST(@YEARSTART AS VARCHAR(20))

IF @SALESANALYSISTYPE = 4
BEGIN
-- 12 month qty
SET @SQL_QUERY = ' SELECT ' + @SQL_SELECT +
', ISNULL([0], 0) as M1, ISNULL([1], 0) as M2, ISNULL([2], 0) as M3,
ISNULL([3], 0) as M4, ISNULL([4], 0) as M5, ISNULL([5], 0) as M6, ISNULL([6], 0) as M7, ISNULL([7], 0) as M8,
ISNULL([8], 0) as M9, ISNULL([9], 0) as M10,
ISNULL([10], 0) as M11, ISNULL([11], 0) as M12, ''' + @LOGINNAME + '''
from
(select ' + @SQL_GROUPBY + ', IQUANTITY, (age-' + @AGE_STR + ') AS AGE1 from VW_FACT_SALES WHERE AGE >= ' + @AGE_STR + ' AND AGE <=(' + @AGE_STR + '+12) ' + @SQL_WHERE + ') S
PIVOT
(
sum(Iquantity)
for age1 in ([0], [1], [2], [3], [4], [5], [6], [7], [8], [9], [10], [11])

) P'

INSERT INTO X_ER_REPORT(groupno, GROUPNAME, code, [DESCRIPTION], MONTH1, MONTH2, MONTH3, MONTH4, MONTH5, MONTH6,
MONTH7, MONTH8, MONTH9, MONTH10, MONTH11, MONTH12, LOGINNAME)
EXECUTE(@SQL_QUERY)

END
ELSE IF @SALESANALYSISTYPE = 5
BEGIN
-- 12 month sales
SET @SQL_QUERY = ' SELECT ' + @SQL_SELECT +
', ISNULL([0], 0) as M1, ISNULL([1], 0) as M2, ISNULL([2], 0) as M3,
ISNULL([3], 0) as M4, ISNULL([4], 0) as M5, ISNULL([5], 0) as M6, ISNULL([6], 0) as M7, ISNULL([7], 0) as M8,
ISNULL([8], 0) as M9, ISNULL([9], 0) as M10,
ISNULL([10], 0) as M11, ISNULL([11], 0) as M12, ''' + @LOGINNAME + '''
from
(select ' + @SQL_GROUPBY + ', IVAL, (age-' + @AGE_STR + ') AS AGE1 from VW_FACT_SALES WHERE AGE >= ' + @AGE_STR + ' AND AGE <=(' + @AGE_STR + '+12) ' + @SQL_WHERE + ') S
PIVOT
(
sum(IVAL)
for age1 in ([0], [1], [2], [3], [4], [5], [6], [7], [8], [9], [10], [11])

) P'
INSERT INTO X_ER_REPORT(groupno, GROUPNAME, code, [DESCRIPTION], MONTH1, MONTH2, MONTH3, MONTH4, MONTH5, MONTH6,
MONTH7, MONTH8, MONTH9, MONTH10, MONTH11, MONTH12, LOGINNAME)
EXECUTE(@SQL_QUERY)

END
ELSE IF @SALESANALYSISTYPE IN (0, 2) --PERIOD AND GROUP PERCENT
BEGIN
SET @SQL_QUERY = 'select ' + @SQL_SELECT +
', AGE, ival, IVALDISC, ICOST, IQUANTITY, ivallist
from VW_FACT_SALES where age between ' + @AGE_STR + ' and (' + @YEARSTART_STR + ' + 12) ' + @SQL_WHERE
insert into @temp_table(groupno, GROUPNAME, code, Code_DESCRIPTION, AGE, ival, ivaldisc, icost, iquantity, ilistval)
EXECUTE(@SQL_QUERY)

INSERT INTO @TEMP_TABLE_GROUP(groupno, GROUPNAME, code, CODE_DESCRIPTION)
SELECT groupno, GROUPNAME, code, CODE_DESCRIPTION FROM @TEMP_TABLE GROUP BY groupno, GROUPNAME, code, CODE_DESCRIPTION

IF @SALESANALYSISTYPE = 0
BEGIN
INSERT INTO X_ER_REPORT(groupno, GROUPNAME, code, [DESCRIPTION],
MTD, MTDCOST, MTDQTY,
YTD, YTDCOST, YTDQTY,
LYMTD, LYMTDCOST, LYMTDQTY,
LYTD, LYTDCOST, LYTDQTY, LOGINNAME)
select t.groupno, t.groupname, t.code, t.Code_DESCRIPTION,
ISNULL(MTD.ival, 0) as MTDVal, ISNULL(MTD.icost, 0) as MTDcost, ISNULL(MTD.quantity, 0) as MTDQty,
ISNULL(YTD.ival, 0) as YTDVal, ISNULL(YTD.icost, 0) as YTDcost, ISNULL(YTD.quantity, 0) as YTDQty,
ISNULL(LYMTD.ival, 0) as LYMTDVal, ISNULL(LYMTD.icost, 0) as LYMTDcost, ISNULL(LYMTD.quantity, 0) as LYMTDQty,
ISNULL(LYTD.ival, 0) as LYTDVal, ISNULL(LYTD.icost, 0) as LYTDcost, ISNULL(LYTD.quantity, 0) as LYTDQty, @LOGINNAME
from @temp_table_GROUP T
left join
( select groupname, Code_DESCRIPTION, SUM(ival) as ival, sum(icost) as icost, SUM(iquantity) as quantity
from @temp_table where AGE = @AGE group by groupname, Code_DESCRIPTION
) as MTD on T.groupname= MTD.groupname and T.Code_DESCRIPTION = MTD.Code_DESCRIPTION
left join
( select groupname, Code_DESCRIPTION, SUM(ival) as ival, sum(icost) as icost, SUM(iquantity) as quantity
from @temp_table where AGE >= @AGE and AGE <= @YEARSTART group by groupname, Code_DESCRIPTION
) as YTD on T.groupname= YTD.groupname and T.Code_DESCRIPTION = YTD.Code_DESCRIPTION
left join
( select groupname, Code_DESCRIPTION, SUM(ival) as ival, sum(icost) as icost, SUM(iquantity) as quantity
from @temp_table where AGE = (@AGE + 12) group by groupname, Code_DESCRIPTION
) as LYMTD on T.groupname= LYMTD.groupname and T.Code_DESCRIPTION = LYMTD.Code_DESCRIPTION
left join
( select groupname, Code_DESCRIPTION, SUM(ival) as ival, sum(icost) as icost, SUM(iquantity) as quantity
from @temp_table where (AGE >= @AGE +12) AND (AGE <= @YEARSTART+12) group by groupname, Code_DESCRIPTION
) as LYTD on T.groupname= LYTD.groupname and T.Code_DESCRIPTION = LYTD.Code_DESCRIPTION
where
ISNULL(MTD.quantity, 0) <> 0 or
ISNULL(YTD.quantity, 0) <> 0 or
ISNULL(LYMTD.quantity, 0) <> 0 or
ISNULL(LYTD.quantity, 0) <> 0
ORDER by t.groupno, t.groupname, t.code, t.Code_Description
END
ELSE
BEGIN
INSERT INTO @TEMP_TABLE_GROUP_totals(groupno, groupname)
SELECT groupno, GROUPNAME FROM @TEMP_TABLE GROUP BY groupno, GROUPNAME

update T set T.MTDTotal= subq.MTDVal,
T.YTDTotal= subq.YTDVal, T.LYMTDTotal= subq.LYMTDVal,
T.LYYTDTotal= subq.LYTDVal
from @TEMP_TABLE_GROUP_totals T inner join (
select t.groupno, t.groupname,
ISNULL(MTD.ival, 0) as MTDVal,
ISNULL(YTD.ival, 0) as YTDVal,
ISNULL(LYMTD.ival, 0) as LYMTDVal,
ISNULL(LYTD.ival, 0) as LYTDVal
from @temp_table_GROUP_Totals T
left join
( select groupname, SUM(ival) as ival, sum(icost) as icost, SUM(iquantity) as quantity
from @temp_table where AGE = @AGE group by groupname
) as MTD on T.groupname= MTD.groupname
left join
( select groupname, SUM(ival) as ival, sum(icost) as icost, SUM(iquantity) as quantity
from @temp_table where AGE >= @AGE and AGE <= @YEARSTART group by groupname
) as YTD on T.groupname= YTD.groupname
left join
( select groupname, SUM(ival) as ival, sum(icost) as icost, SUM(iquantity) as quantity
from @temp_table where AGE = (@AGE + 12) group by groupname
) as LYMTD on T.groupname= LYMTD.groupname
left join
( select groupname, SUM(ival) as ival, sum(icost) as icost, SUM(iquantity) as quantity
from @temp_table where (AGE >= @AGE +12) AND (AGE <= @YEARSTART+12) group by groupname
) as LYTD on T.groupname= LYTD.groupname
) as subq on T.groupname= subq.groupname

INSERT INTO X_ER_REPORT(groupno, GROUPNAME, code, [DESCRIPTION],
MTD, MTDCOST, MTDQTY,
YTD, YTDCOST, YTDQTY,
LYMTD, LYMTDCOST, LYMTDQTY,
LYTD, LYTDCOST, LYTDQTY,
MTDPER, YTDPER, LYMTDPER, LYYTDPER, LOGINNAME)
select t.groupno, t.groupname, t.CODE, t.Code_DESCRIPTION,
ISNULL(MTD.ival, 0) as MTDVal, ISNULL(MTD.icost, 0) as MTDcost, ISNULL(MTD.quantity, 0) as MTDQty,
ISNULL(YTD.ival, 0) as YTDVal, ISNULL(YTD.icost, 0) as YTDcost, ISNULL(YTD.quantity, 0) as YTDQty,
ISNULL(LYMTD.ival, 0) as LYMTDVal, ISNULL(LYMTD.icost, 0) as LYMTDcost, ISNULL(LYMTD.quantity, 0) as LYMTDQty,
ISNULL(LYTD.ival, 0) as LYTDVal, ISNULL(LYTD.icost, 0) as LYTDcost, ISNULL(LYTD.quantity, 0) as LYTDQty,
(case TT.MTDTotal WHEN 0 THEN 0 ELSE ISNULL((MTD.ival/TT.MTDTOTAL)*100, 0) END) AS MTDPER,
(case TT.YTDTotal WHEN 0 THEN 0 ELSE ISNULL((YTD.ival/TT.YTDTOTAL)*100, 0) END) AS YTDPER,
(case TT.LYMTDTotal WHEN 0 THEN 0 ELSE ISNULL((LYMTD.ival/TT.LYMTDTotal)*100, 0) END) AS LYMTDPER,
(case TT.LYYTDTotal WHEN 0 THEN 0 ELSE ISNULL((LYTD.ival/TT.LYYTDTotal)*100, 0) END) AS LYYTDPER,
@LOGINNAME
from @temp_table_GROUP T
left join @temp_table_GROUP_Totals TT on TT.groupname = t.groupname
left join
( select groupname, Code_DESCRIPTION, SUM(ival) as ival, sum(icost) as icost, SUM(iquantity) as quantity
from @temp_table where AGE = @AGE group by groupname, Code_DESCRIPTION
) as MTD on T.groupname= MTD.groupname and T.Code_DESCRIPTION = MTD.Code_DESCRIPTION
left join
( select groupname, Code_DESCRIPTION, SUM(ival) as ival, sum(icost) as icost, SUM(iquantity) as quantity
from @temp_table where AGE >= @AGE and AGE <= @YEARSTART group by groupname, Code_DESCRIPTION
) as YTD on T.groupname= YTD.groupname and T.Code_DESCRIPTION = YTD.Code_DESCRIPTION
left join
( select groupname, Code_DESCRIPTION, SUM(ival) as ival, sum(icost) as icost, SUM(iquantity) as quantity
from @temp_table where AGE = (@AGE + 12) group by groupname, Code_DESCRIPTION
) as LYMTD on T.groupname= LYMTD.groupname and T.Code_DESCRIPTION = LYMTD.Code_DESCRIPTION
left join
( select groupname, Code_DESCRIPTION, SUM(ival) as ival, sum(icost) as icost, SUM(iquantity) as quantity
from @temp_table where (AGE >= @AGE +12) AND (AGE <= @YEARSTART+12) group by groupname, Code_DESCRIPTION
) as LYTD on T.groupname= LYTD.groupname and T.Code_DESCRIPTION = LYTD.Code_DESCRIPTION
where
ISNULL(MTD.quantity, 0) <> 0 or
ISNULL(YTD.quantity, 0) <> 0 or
ISNULL(LYMTD.quantity, 0) <> 0 or
ISNULL(LYTD.quantity, 0) <> 0
ORDER by t.groupno, t.groupname, t.code, t.Code_Description
END
END
ELSE IF @SALESANALYSISTYPE = 1 -- DATERANGE
BEGIN
SET @SQL_QUERY = 'select ' + @SQL_SELECT +
' , ISNULL(SUM(IVAL), 0), ISNULL(SUM(ICOST), 0), ISNULL(SUM(IQUANTITY), 0), ''' + @LOGINNAME + '''
from VW_FACT_SALES
where TRANSDATE BETWEEN CONVERT(datetime, ''' + CONVERT(varchar(20), @DATERANGE_START, 101) + ''', 101) AND
CONVERT(datetime, ''' + CONVERT(varchar(20), @DATERANGE_END, 101) + ''', 101) ' + @SQL_WHERE
+ ' GROUP BY ' + @SQL_GROUPBY
INSERT INTO X_ER_REPORT(groupno, GROUPNAME, code, [DESCRIPTION],
MTD, MTDCOST, MTDQTY, LOGINNAME)
EXECUTE(@SQL_QUERY)
END
ELSE IF @SALESANALYSISTYPE = 3 -- DISCOUNTS
BEGIN
SET @SQL_QUERY = 'select ' + @SQL_SELECT +
' , ISNULL(SUM(IQUANTITY), 0), ISNULL(SUM(IVALLIST), 0), ISNULL(SUM(IVAL), 0),
ISNULL(SUM(1-(IVAL/IVALLIST)*100), 0), ISNULL(SUM(IVALLIST-IVAL), 0), ISNULL(SUM((IVALLIST-IVAL)/IQUANTITY), 0), '''+ @LOGINNAME + '''
from VW_FACT_SALES
where age between ' + CAST(@AGE AS VARCHAR(20)) + ' and ' + CAST(@AGE_TO AS VARCHAR(20)) +
' AND (IVALLIST <> IVAL) AND (IVALLIST <> 0) AND (IVAL <> 0) ' + @SQL_WHERE +
' GROUP BY ' + @SQL_GROUPBY
INSERT INTO X_ER_REPORT(groupno, GROUPNAME, code, [DESCRIPTION], MONTH1, MONTH2, MONTH3, MONTH4, MONTH5, MONTH6, LOGINNAME)
EXECUTE(@SQL_QUERY)
END
ELSE IF @SALESANALYSISTYPE IN (6, 7) -- 5 WEEKS QTY AND SALES
BEGIN
SET @SQL_QUERY = 'select ' + @SQL_SELECT +
', TRANSDATE, ival, IVALDISC, IQUANTITY
from VW_FACT_SALES where TRANSDATE between CONVERT(datetime, ''' + CONVERT(varchar(20), @DATERANGE_START, 101) + ''', 101) and (
CONVERT(datetime, ''' + CONVERT(varchar(20), @DATERANGE_START, 101) + ''', 101)+ 34) ' + @SQL_WHERE
insert into @temp_table(groupno, groupname, code, Code_DESCRIPTION, TRANSDATE, ival, ivaldisc, iquantity)
EXECUTE(@SQL_QUERY)

INSERT INTO @TEMP_TABLE_GROUP(groupno, GROUPNAME, code, CODE_DESCRIPTION)
SELECT groupno, GROUPNAME, code, CODE_DESCRIPTION FROM @TEMP_TABLE GROUP BY groupno, GROUPNAME, code, CODE_DESCRIPTION

IF @SALESANALYSISTYPE = 7
BEGIN
INSERT INTO X_ER_REPORT(groupno, GROUPNAME, code, [DESCRIPTION],
MONTH1, MONTH2, MONTH3, MONTH4, MONTH5, LOGINNAME)
select t.groupno, t.groupname, t.code, t.Code_DESCRIPTION,
ISNULL(M1.ival, 0) as M1Val,
ISNULL(M2.ival, 0) as M2Val,
ISNULL(M3.ival, 0) as M3Val,
ISNULL(M4.ival, 0) as M4Val,
ISNULL(M5.ival, 0) as M5Val,
@LOGINNAME
from @temp_table_GROUP T
left join
( select groupname, Code_Description, SUM(ival) as ival, SUM(iquantity) as quantity
from @temp_table where TRANSDATE BETWEEN @DATERANGE_START AND dateadd(DAY, -1, dateadd(week, 1, @DATERANGE_START))
group by groupname, Code_Description
) as M1 on T.groupname= M1.groupname and T.Code_Description = M1.Code_Description
left join
( select groupname, Code_Description, SUM(ival) as ival, SUM(iquantity) as quantity
from @temp_table where TRANSDATE BETWEEN dateadd(week, 1, @DATERANGE_START) AND dateadd(DAY, -1, dateadd(week, 2, @DATERANGE_START))
group by groupname, Code_Description
) as M2 on T.groupname= M2.groupname and T.Code_Description = M2.Code_Description
left join
( select groupname, Code_Description, SUM(ival) as ival, SUM(iquantity) as quantity
from @temp_table where TRANSDATE BETWEEN dateadd(week, 2, @DATERANGE_START) AND dateadd(DAY, -1, dateadd(week, 3, @DATERANGE_START))
group by groupname, Code_Description
) as M3 on T.groupname= M3.groupname and T.Code_Description = M3.Code_Description
left join
( select groupname, Code_Description, SUM(ival) as ival, SUM(iquantity) as quantity
from @temp_table where TRANSDATE BETWEEN dateadd(week, 3, @DATERANGE_START) AND dateadd(DAY, -1, dateadd(week, 4, @DATERANGE_START))
group by groupname, Code_Description
) as M4 on T.groupname= M4.groupname and T.Code_Description = M4.Code_Description
left join
( select groupname, Code_Description, SUM(ival) as ival, SUM(iquantity) as quantity
from @temp_table where TRANSDATE BETWEEN dateadd(week, 4, @DATERANGE_START) AND dateadd(DAY, -1, dateadd(week, 5, @DATERANGE_START))
group by groupname, Code_Description
) as M5 on T.groupname= M5.groupname and T.Code_Description = M5.Code_Description
where
ISNULL(M1.ival, 0) <> 0 or
ISNULL(M2.ival, 0) <> 0 or
ISNULL(M3.ival, 0) <> 0 or
ISNULL(M4.ival, 0) <> 0 or
ISNULL(M5.ival, 0) <> 0
ORDER by t.groupno, t.groupname, t.code, t.Code_Description
END
ELSE IF @SALESANALYSISTYPE = 6
BEGIN
INSERT INTO X_ER_REPORT(groupno, GROUPNAME, code, [DESCRIPTION],
MONTH1, MONTH2, MONTH3, MONTH4, MONTH5, LOGINNAME)
select t.groupno, t.groupname, t.code, t.Code_DESCRIPTION,
ISNULL(M1.quantity, 0) as M1Qty,
ISNULL(M2.quantity, 0) as M2Qty,
ISNULL(M3.quantity, 0) as M3Qty,
ISNULL(M4.quantity, 0) as M4Qty,
ISNULL(M5.quantity, 0) as M5Qty,
@LOGINNAME
from @temp_table_GROUP T
left join
( select groupname, Code_Description, SUM(ival) as ival, SUM(iquantity) as quantity
from @temp_table where TRANSDATE BETWEEN @DATERANGE_START AND dateadd(DAY, -1, dateadd(week, 1, @DATERANGE_START))
group by groupname, Code_Description
) as M1 on T.groupname= M1.groupname and T.Code_Description = M1.Code_Description
left join
( select groupname, Code_Description, SUM(ival) as ival, SUM(iquantity) as quantity
from @temp_table where TRANSDATE BETWEEN dateadd(week, 1, @DATERANGE_START) AND dateadd(DAY, -1, dateadd(week, 2, @DATERANGE_START))
group by groupname, Code_Description
) as M2 on T.groupname= M2.groupname and T.Code_Description = M2.Code_Description
left join
( select groupname, Code_Description, SUM(ival) as ival, SUM(iquantity) as quantity
from @temp_table where TRANSDATE BETWEEN dateadd(week, 2, @DATERANGE_START) AND dateadd(DAY, -1, dateadd(week, 3, @DATERANGE_START))
group by groupname, Code_Description
) as M3 on T.groupname= M3.groupname and T.Code_Description = M3.Code_Description
left join
( select groupname, Code_Description, SUM(ival) as ival, SUM(iquantity) as quantity
from @temp_table where TRANSDATE BETWEEN dateadd(week, 3, @DATERANGE_START) AND dateadd(DAY, -1, dateadd(week, 4, @DATERANGE_START))
group by groupname, Code_Description
) as M4 on T.groupname= M4.groupname and T.Code_Description = M4.Code_Description
left join
( select groupname, Code_Description, SUM(ival) as ival, SUM(iquantity) as quantity
from @temp_table where TRANSDATE BETWEEN dateadd(week, 4, @DATERANGE_START) AND dateadd(DAY, -1, dateadd(week, 5, @DATERANGE_START))
group by groupname, Code_Description
) as M5 on T.groupname= M5.groupname and T.Code_Description = M5.Code_Description
where
ISNULL(M1.quantity, 0) <> 0 or
ISNULL(M2.quantity, 0) <> 0 or
ISNULL(M3.quantity, 0) <> 0 or
ISNULL(M4.quantity, 0) <> 0 or
ISNULL(M5.quantity, 0) <> 0
ORDER by t.groupno, t.groupname, t.code, t.Code_Description
END
END
END


Procedure: StockQtyTradedInNeg
NameStockQtyTradedInNeg
Note
Code-- =============================================
-- description: Calculates and returns the quantity amount in the input transaction
-- (@TransQty) that was traded in negative total stock region
-- =============================================
CREATE FUNCTION [dbo].[StockQtyTradedInNeg]
(
@StartQty float,
@TransQty float
)
RETURNS Float
AS
BEGIN

DECLARE @ResultQty float;

select @ResultQty = Case
                        when (@StartQty + @TransQty <= 0) AND (@StartQty <= 0) then @TransQty
                        when (@StartQty + @TransQty <= 0) AND (@StartQty > 0) then @StartQty + @TransQty
                        when (@StartQty < 0) and (@StartQty + @TransQty >= 0) then abs(@StartQty)
                        else 0
                      end
RETURN @ResultQty
END


Procedure: STOCK_IN_LOC
NameSTOCK_IN_LOC
Note
CodeCREATE PROCEDURE [dbo].[STOCK_IN_LOC]
  @STOCKCODE Varchar(23),
  @LOCATION Int
AS
BEGIN
  DECLARE @ISINLOC DOUBLE PRECISION,
          @ALLLOCTOTAL DOUBLE PRECISION,
          @ISFREE DOUBLE PRECISION,
          @ISCOMMITTED DOUBLE PRECISION,
          @ISINCOMING DOUBLE PRECISION,
          @ONBACKORDER DOUBLE PRECISION,
          @ISNOTFORSALE DOUBLE PRECISION,
          @RELEASED DOUBLE PRECISION,
          @PICKED DOUBLE PRECISION,
          @NOSALELOCATION CHAR (1),
          @CORRECTED DOUBLE PRECISION,
          @SUPPLIED DOUBLE PRECISION,
          @UNCOSTED DOUBLE PRECISION,
          @MINSTOCK DOUBLE PRECISION,
          @MAXSTOCK DOUBLE PRECISION,
          @BINCODE VARCHAR(12),
          @WIPLOCTOTAL DOUBLE PRECISION,
          @IS_WIPLOCATION CHAR (1)

  EXECUTE STOCK_IN_LOCATION @STOCKCODE, @LOCATION, @ALLLOCTOTAL OUTPUT,
    @ISINLOC OUTPUT, @ISFREE OUTPUT, @ISCOMMITTED OUTPUT, @ISINCOMING OUTPUT,
    @ONBACKORDER OUTPUT, @ISNOTFORSALE OUTPUT, @NOSALELOCATION OUTPUT,
    @RELEASED OUTPUT, @PICKED OUTPUT, @CORRECTED OUTPUT, @SUPPLIED OUTPUT,
    @UNCOSTED OUTPUT, @MINSTOCK OUTPUT, @MAXSTOCK OUTPUT, @BINCODE OUTPUT,
    @WIPLOCTOTAL OUTPUT, @IS_WIPLOCATION OUTPUT

  SELECT @ALLLOCTOTAL ALLLOCTOTAL, @ISINLOC ISINLOC, @ISFREE ISFREE,
    @ISCOMMITTED ISCOMMITTED, @ISINCOMING ISINCOMING, @ONBACKORDER ONBACKORDER,
    @ISNOTFORSALE ISNOTFORSALE, @NOSALELOCATION NOSALELOCATION, @RELEASED RELEASED,
    @PICKED PICKED, @CORRECTED CORRECTED, @SUPPLIED SUPPLIED, @UNCOSTED UNCOSTED,
    @MINSTOCK MINSTOCK, @MAXSTOCK MAXSTOCK, @BINCODE BINCODE,
    @WIPLOCTOTAL WIPLOCTOTAL
END


Procedure: STOCK_IN_LOCATION
NameSTOCK_IN_LOCATION
Note
CodeCREATE PROCEDURE [dbo].[STOCK_IN_LOCATION]
  @STOCKCODE VARCHAR(23),
  @LOCATION INT ,
  @ALLLOCTOTAL FLOAT = 0 OUTPUT,
  @ISINLOC FLOAT = 0 OUTPUT,
  @ISFREE FLOAT = 0 OUTPUT,
  @ISCOMMITTED FLOAT = 0 OUTPUT,
  @ISINCOMING FLOAT = 0 OUTPUT,
  @ONBACKORDER FLOAT = 0 OUTPUT,
  @ISNOTFORSALE FLOAT = 0 OUTPUT,
  @NOSALELOCATION CHAR(1) = 'N' OUTPUT,
  @RELEASED FLOAT = 0 OUTPUT,
  @PICKED FLOAT = 0 OUTPUT,
  @CORRECTED FLOAT = 0 OUTPUT,
  @SUPPLIED FLOAT = 0 OUTPUT,
  @UNCOSTED FLOAT = 0 OUTPUT,
  @MINSTOCK FLOAT = 0 OUTPUT,
  @MAXSTOCK FLOAT = 0 OUTPUT,
  @BINCODE VARCHAR(12) = '' OUTPUT,
  @WIPLOCTOTAL FLOAT = 0 OUTPUT,
  @IS_WIPLOCATION CHAR(1) = 'N' OUTPUT
AS
  DECLARE @INLOC FLOAT,
          @PURCHORDS FLOAT,
          @WORDSOUT FLOAT,
          @WORDSIN FLOAT,
          @ORDS FLOAT,
          @SUP FLOAT,
          @MAXFWDDAYS INT,
          @USEWORKSORDS CHAR(1),
          @ONBACKORD FLOAT,
          @SALESORDS FLOAT,
          @BILLORDS FLOAT,
          @ONRELEASE FLOAT,
          @ONPICKED FLOAT,
          @CORRECTQUANT FLOAT,
          @ONSUPPLY FLOAT,
          @ONUNCOSTQUANT FLOAT,
          @MINSTOCKLEV FLOAT,
          @MAXSTOCKLEV FLOAT,
          @BINCODENAME VARCHAR(12),
          @PO_MAXFWDDAYS INT,
          @WO_MAXFWDDAYS INT

BEGIN
  SELECT
    @ALLLOCTOTAL = ISNULL(SUM(SLI.QTY), 0),
    @WIPLOCTOTAL = ISNULL(SUM(CASE
                                WHEN SL.IS_WIPLOCATION = 'Y' THEN SLI.QTY
                                ELSE 0
                              END), 0)
  FROM STOCK_LOC_INFO SLI
  JOIN STOCK_LOCATIONS SL ON SLI.LOCATION = SL.LOCNO
  WHERE STOCKCODE = @STOCKCODE

  SELECT
    @INLOC = ISNULL(SLI.QTY, 0),
    @MINSTOCKLEV = ISNULL(SLI.MINSTOCK, 0),
    @MAXSTOCKLEV = ISNULL(SLI.MAXSTOCK, 0),
    @BINCODENAME = SLI.BINCODE,
    @IS_WIPLOCATION = SL.IS_WIPLOCATION
  FROM STOCK_LOC_INFO SLI
  JOIN STOCK_LOCATIONS SL ON SL.LOCNO = SLI.LOCATION AND SLI.STOCKCODE = @STOCKCODE AND SLI.LOCATION = @LOCATION

  SET @ISINLOC = @INLOC

  --DEAL WITH USER PROFILES
  EXECUTE GET_PROFILE_VALUE_INT 'ORDER_MAX_FWD_DAYS', @MAXFWDDAYS OUTPUT
  EXECUTE GET_PROFILE_VALUE_INT 'PO_ORDER_MAX_FWD_DAYS', @PO_MAXFWDDAYS OUTPUT
  EXECUTE GET_PROFILE_VALUE_INT 'WO_ORDER_MAX_FWD_DAYS', @WO_MAXFWDDAYS OUTPUT
  EXECUTE GET_PROFILE_VALUE 'USEWORKSORDERS', @USEWORKSORDS OUTPUT
  IF (@USEWORKSORDS IS NULL) SET @USEWORKSORDS = 'N'
  IF ((@MAXFWDDAYS IS NULL) OR (@MAXFWDDAYS=0)) SET @MAXFWDDAYS = 90
  IF ((@PO_MAXFWDDAYS IS NULL) OR (@PO_MAXFWDDAYS = 0)) SET @PO_MAXFWDDAYS = 90
  IF ((@WO_MAXFWDDAYS IS NULL) OR (@WO_MAXFWDDAYS = 0)) SET @WO_MAXFWDDAYS = 90

  IF (@USEWORKSORDS ='Y')
  BEGIN
    SELECT @WORDSOUT = ISNULL(SUM(L.QTYREQD - L.QTYUSED), 0)
    FROM WORKSORD_LINES L, WORKSORD_HDR H
    WHERE (L.HDR_SEQNO = H.SEQNO)
      AND (L.STOCKCODE = @STOCKCODE)
      AND (H.DUEDATE <= GETDATE() + @WO_MAXFWDDAYS)
      AND (H.ORDSTATUS BETWEEN 1 AND 2)
      AND H.COMPONENTLOCNO = @LOCATION

    SELECT @WORDSIN = ISNULL(SUM(PRODQTY - ACTUALQTY), 0)
    FROM WORKSORD_HDR
    WHERE (PRODCODE = @STOCKCODE)
      AND (ORDSTATUS BETWEEN 1 AND 2)
      AND (DUEDATE <= GETDATE() + @WO_MAXFWDDAYS)
      AND PRODLOCNO = @LOCATION
  END
  ELSE
  BEGIN
    SET @WORDSOUT = 0
    SET @WORDSIN = 0
  END

  -- SALES ORDERS
  SELECT
    @ONRELEASE = ISNULL(SUM((L.RELEASE_QUANT + L.RELEASE_NOW) * L.LINKED_QTY) , 0),
    @ONPICKED = ISNULL(SUM((L.PICKED_QUANT + L.PICK_NOW) * L.LINKED_QTY), 0),
    @CORRECTQUANT = ISNULL(SUM(L.CORRECTED_QUANT * L.LINKED_QTY), 0),
    @SALESORDS = ISNULL(SUM(L.UNSUP_QUANT * L.LINKED_QTY), 0),
    @ONBACKORD = ISNULL(SUM(L.BKORD_QUANT * L.LINKED_QTY), 0),
    @ONSUPPLY = ISNULL(SUM((L.SUP_QUANT + L.SUPPLY_NOW) * L.LINKED_QTY), 0)
  FROM SALESORD_LINES L
  INNER JOIN SALESORD_HDR H ON L.HDR_SEQNO = H.SEQNO
  WHERE (L.LINKED_STOCKCODE = @STOCKCODE)
    AND ((L.HDR_STATUS < 2) OR (L.HDR_STATUS BETWEEN 4 AND 5))
    AND (H.DUEDATE <= GETDATE() + @MAXFWDDAYS)
    AND L.LOCATION = @LOCATION

  -- PURCHASE ORDERS
  SELECT
    @PURCHORDS = ISNULL(SUM(((L.ORD_QUANT - L.CORRECTION_QUANT) - L.COST_QUANT) * L.LINKED_QTY), 0),
    @ONUNCOSTQUANT = ISNULL(SUM((L.SUP_QUANT - L.COST_QUANT) * L.LINKED_QTY), 0)
  FROM PURCHORD_LINES L
  INNER JOIN PURCHORD_HDR H ON (L.HDR_SEQNO = H.SEQNO)
  WHERE (L.LINKED_STOCKCODE = @STOCKCODE)
    AND (H.DUEDATE <= GETDATE() + @PO_MAXFWDDAYS)
    AND (H.STATUS < 2)
    AND L.LOCATION = @LOCATION

  SELECT @NOSALELOCATION = EXCLUDE_FROMFREE_STOCK
  FROM STOCK_LOCATIONS
  WHERE LOCNO = @LOCATION

  SET @ISINLOC = @INLOC
  SET @ISFREE = @INLOC - @SALESORDS - @WORDSOUT + @PURCHORDS + @WORDSIN
  SET @ISCOMMITTED = @SALESORDS + @WORDSOUT
  SET @ISINCOMING = @PURCHORDS + @WORDSIN
  SET @ONBACKORDER = @ONBACKORD
  SET @RELEASED = @ONRELEASE
  SET @PICKED = @ONPICKED
  SET @CORRECTED = @CORRECTQUANT
  SET @ISNOTFORSALE = 0
  SET @SUPPLIED = @ONSUPPLY
  SET @UNCOSTED = @ONUNCOSTQUANT
  SET @MINSTOCK = @MINSTOCKLEV
  SET @MAXSTOCK = @MAXSTOCKLEV
  SET @BINCODE = @BINCODENAME

  IF @NOSALELOCATION = 'Y'
  BEGIN
    SET @ISNOTFORSALE = @ISFREE
    SET @ISFREE = 0
  END

  IF @IS_WIPLOCATION = 'Y'
  BEGIN
    SET @ISFREE = 0
    SET @ISCOMMITTED = @INLOC
  END
END


Procedure: STOCK_LEVELS
NameSTOCK_LEVELS
Note
CodeCREATE PROCEDURE [dbo].[STOCK_LEVELS]
  @STOCKCODE VARCHAR(23)
AS
DECLARE
  @MAXFWDDAYS INT,
  @USEWORKSORDS CHAR(1),
  @PO_MAXFWDDAYS INT,
  @WO_MAXFWDDAYS INT
BEGIN

  DECLARE @TMP_STOCK_LEVELS TABLE
  (
    LOCNO INTEGER NOT NULL,
    ISINLOC DOUBLE PRECISION NOT NULL DEFAULT(0),
    ISFREE DOUBLE PRECISION NOT NULL DEFAULT(0),
    ISCOMMITTED DOUBLE PRECISION NOT NULL DEFAULT(0),
    ISINCOMING DOUBLE PRECISION NOT NULL DEFAULT(0),
    ONBACKORDER DOUBLE PRECISION NOT NULL DEFAULT(0),
    ISNOTFORSALE DOUBLE PRECISION NOT NULL DEFAULT(0),
    RELEASED DOUBLE PRECISION NOT NULL DEFAULT(0),
    PICKED DOUBLE PRECISION NOT NULL DEFAULT(0),
    NOSALELOCATION CHAR(1) NOT NULL DEFAULT('N'),
    CORRECTED DOUBLE PRECISION NOT NULL DEFAULT(0),
    SUPPLIED DOUBLE PRECISION NOT NULL DEFAULT(0),
    UNCOSTED DOUBLE PRECISION NOT NULL DEFAULT(0),
    MINSTOCK DOUBLE PRECISION NOT NULL DEFAULT(0),
    MAXSTOCK DOUBLE PRECISION NOT NULL DEFAULT(0),
    BINCODE VARCHAR(12),
    WOUT DOUBLE PRECISION NOT NULL DEFAULT(0),
    WIN DOUBLE PRECISION NOT NULL DEFAULT(0),
    SO DOUBLE PRECISION NOT NULL DEFAULT(0),
    PO DOUBLE PRECISION NOT NULL DEFAULT(0),
    IS_WIPLOCATION CHAR(1) NOT NULL DEFAULT('N')
  )

  -- PREPOPULATE WITH STUFF WHICH DOESNT REQUIED AGGREGATION
  INSERT INTO @TMP_STOCK_LEVELS(
    LOCNO, ISINLOC, MINSTOCK, MAXSTOCK, BINCODE, NOSALELOCATION, IS_WIPLOCATION)
  SELECT L.LOCNO, ISNULL(I.QTY, 0), ISNULL(I.MINSTOCK, 0), ISNULL(I.MAXSTOCK, 0),
    I.BINCODE, L.EXCLUDE_FROMFREE_STOCK, L.IS_WIPLOCATION
  FROM STOCK_LOC_INFO I
  JOIN STOCK_LOCATIONS L ON I.LOCATION = L.LOCNO
  WHERE STOCKCODE = @STOCKCODE

  --DEAL WITH USER PROFILES
  EXECUTE GET_PROFILE_VALUE_INT 'ORDER_MAX_FWD_DAYS', @MAXFWDDAYS OUTPUT
  EXECUTE GET_PROFILE_VALUE_INT 'PO_ORDER_MAX_FWD_DAYS', @PO_MAXFWDDAYS OUTPUT
  EXECUTE GET_PROFILE_VALUE_INT 'WO_ORDER_MAX_FWD_DAYS', @WO_MAXFWDDAYS OUTPUT
  EXECUTE GET_PROFILE_VALUE 'USEWORKSORDERS', @USEWORKSORDS OUTPUT
  IF (@USEWORKSORDS IS NULL) SET @USEWORKSORDS = 'N'
  IF ((@MAXFWDDAYS IS NULL) OR (@MAXFWDDAYS=0)) SET @MAXFWDDAYS = 90
  IF ((@PO_MAXFWDDAYS IS NULL) OR (@PO_MAXFWDDAYS=0)) SET @PO_MAXFWDDAYS = 90
  IF ((@WO_MAXFWDDAYS IS NULL) OR (@WO_MAXFWDDAYS=0)) SET @WO_MAXFWDDAYS = 90

  -- UPDATE RESULTS WITH AGGREGATED VALUES
  IF (@USEWORKSORDS = 'Y')
  BEGIN
    UPDATE T SET
      WOUT = SUBQ.QTY
    FROM @TMP_STOCK_LEVELS T
    INNER JOIN (
      SELECT H.COMPONENTLOCNO AS LOCNO, ISNULL(SUM(L.QTYREQD - L.QTYUSED), 0) AS QTY
      FROM WORKSORD_LINES L, WORKSORD_HDR H
      WHERE (L.HDR_SEQNO = H.SEQNO)
        AND (L.STOCKCODE = @STOCKCODE)
        AND (H.DUEDATE <= GETDATE() + @WO_MAXFWDDAYS)
        AND (H.ORDSTATUS BETWEEN 1 AND 2)
      GROUP BY H.COMPONENTLOCNO) AS SUBQ ON T.LOCNO = SUBQ.LOCNO

    UPDATE T SET
      WIN = SUBQ.QTY
    FROM @TMP_STOCK_LEVELS T
    INNER JOIN (
      SELECT PRODLOCNO AS LOCNO, ISNULL(SUM(PRODQTY - ACTUALQTY), 0) AS QTY
      FROM WORKSORD_HDR
      WHERE (PRODCODE = @STOCKCODE)
        AND (ORDSTATUS BETWEEN 1 AND 2)
        AND (DUEDATE <= GETDATE() + @WO_MAXFWDDAYS)
      GROUP BY PRODLOCNO) AS SUBQ ON T.LOCNO = SUBQ.LOCNO
  END
  ELSE --NO USE WORK ORDERS
  BEGIN
    UPDATE @TMP_STOCK_LEVELS
    SET WOUT = 0,
        WIN = 0
  END

  UPDATE T SET
    RELEASED = SUBQ.RELEASED,
    PICKED = SUBQ.PICKED,
    CORRECTED = SUBQ.CORRECTED,
    SO = SUBQ.SO,
    ONBACKORDER = SUBQ.ONBACKORDER,
    SUPPLIED = SUBQ.SUPPLIED
  FROM @TMP_STOCK_LEVELS T
  INNER JOIN (
    SELECT L.LOCATION AS LOCNO,
      RELEASED = ISNULL(SUM((L.RELEASE_QUANT + L.RELEASE_NOW) * L.LINKED_QTY), 0),
      PICKED = ISNULL(SUM((L.PICKED_QUANT + L.PICK_NOW) * L.LINKED_QTY), 0),
      CORRECTED = ISNULL(SUM(L.CORRECTED_QUANT * L.LINKED_QTY), 0),
      SO = ISNULL(SUM(L.UNSUP_QUANT * L.LINKED_QTY), 0),
      ONBACKORDER = ISNULL(SUM(L.BKORD_QUANT * L.LINKED_QTY), 0),
      SUPPLIED = ISNULL(SUM((L.SUP_QUANT + L.SUPPLY_NOW) * L.LINKED_QTY), 0)
    FROM SALESORD_LINES L
    INNER JOIN SALESORD_HDR H ON L.HDR_SEQNO = H.SEQNO
    WHERE (L.LINKED_STOCKCODE = @STOCKCODE)
      AND ((L.HDR_STATUS < 2) OR (L.HDR_STATUS BETWEEN 4 AND 5))
      AND (H.DUEDATE <= GETDATE() + @MAXFWDDAYS)
    GROUP BY L.LOCATION) AS SUBQ ON T.LOCNO = SUBQ.LOCNO

  UPDATE T SET
    PO = SUBQ.PO,
    UNCOSTED = SUBQ.UNCOSTED
  FROM @TMP_STOCK_LEVELS T
  INNER JOIN (
    SELECT L.LOCATION AS LOCNO,
      PO = ISNULL(SUM(((L.ORD_QUANT - L.CORRECTION_QUANT) - L.COST_QUANT) * L.LINKED_QTY), 0),
      UNCOSTED = ISNULL(SUM((L.SUP_QUANT - L.COST_QUANT) * L.LINKED_QTY), 0)
    FROM PURCHORD_LINES L
    INNER JOIN PURCHORD_HDR H ON (L.HDR_SEQNO = H.SEQNO)
    WHERE (L.LINKED_STOCKCODE = @STOCKCODE)
      AND (H.DUEDATE <= GETDATE() + @PO_MAXFWDDAYS)
      AND (H.STATUS < 2)
    GROUP BY L.LOCATION ) AS SUBQ ON T.LOCNO = SUBQ.LOCNO

  SELECT
    LOCNO, ISINLOC,
    CASE
      WHEN NOSALELOCATION = 'Y' OR IS_WIPLOCATION = 'Y' THEN 0
      ELSE ISINLOC - SO - WOUT + PO + WIN
    END AS ISFREE,
    CASE
      WHEN IS_WIPLOCATION = 'Y' THEN ISINLOC
      ELSE (SO + WOUT)
    END AS ISCOMMITTED,
    (PO + WIN) AS ISINCOMING,
    ONBACKORDER,
    CASE
      WHEN NOSALELOCATION = 'Y' OR IS_WIPLOCATION = 'Y' THEN ISINLOC + SO - WOUT + PO + WIN
      ELSE 0
    END AS ISNOTFORSALE,
    RELEASED, PICKED, NOSALELOCATION, CORRECTED, SUPPLIED, UNCOSTED, MINSTOCK,
    MAXSTOCK, BINCODE
  FROM @TMP_STOCK_LEVELS
END


Procedure: UpdateStockTrans_Period_Traded_In_Seq
NameUpdateStockTrans_Period_Traded_In_Seq
Note
Code-- =============================================
-- Description: This stored procedure updates the stock_trans table for seqno > @FromSeqno.
-- Period_Traded_In_Seq field will be flagged as 'N' if a prior period transaction
-- happened
-- =============================================
CREATE PROCEDURE [dbo].[UpdateStockTrans_Period_Traded_In_Seq]
(
@FromSeqno int
)
AS
BEGIN
  update stock_Trans set Period_Traded_In_Seq = 'N'
  from
  (Select s1.maxseqno maxseqno1, s2.minseqno minseqno2, s1.stockcode
    from
      (Select min(seqno) minseqno, max(seqno) maxseqno, period_seqno, stockcode,
      ROW_NUMBER() over (partition by stockcode order by period_seqno) as SortOrder
      from stock_trans group by stockcode, period_seqno) as s1
      left join
      (Select min(seqno) minseqno, max(seqno) maxseqno, period_seqno, stockcode,
      ROW_NUMBER() over (partition by stockcode order by period_seqno) as SortOrder
      from stock_trans group by stockcode, period_seqno) as s2
      on s1.SortOrder + 1 = s2.SortOrder and s1.stockcode = s2.stockcode
    ) as Result
  where (stock_Trans.stockcode = result.stockcode and
  stock_Trans.seqno >= result.minseqno2 and stock_Trans.seqno <= result.maxseqno1
  AND stock_Trans.seqno > @FromSeqno)
END


Procedure: UPDATE_DEFAULT_CONTACT
NameUPDATE_DEFAULT_CONTACT
Note
CodeCREATE PROCEDURE [dbo].[UPDATE_DEFAULT_CONTACT]
  @DRCONTACTS INTEGER,
  @SEQNO INTEGER,
  @ACCNO INTEGER
AS
BEGIN
  IF (@DRCONTACTS = 1)
    UPDATE DR_CONTACTS SET DEFCONTACT = 'N' WHERE (SEQNO <> @SEQNO) AND (ACCNO = @ACCNO)
  ELSE
    UPDATE CR_CONTACTS SET DEFCONTACT = 'N' WHERE (SEQNO <> @SEQNO) AND (ACCNO = @ACCNO)
END


Procedure: UPDATE_MENU_METRICS
NameUPDATE_MENU_METRICS
Note
CodeCREATE PROCEDURE [dbo].[UPDATE_MENU_METRICS]
@STAFFNO INT,
@APPID INT,
@MENU_CAPTION VARCHAR(100),
@PROCID INT,
@PROCPARAMS VARCHAR(100),
@PINNING CHAR(1)
AS
BEGIN
IF @PINNING <> ' '
BEGIN
IF (EXISTS(SELECT SEQNO FROM MENU_METRICS WHERE STAFFNO = @STAFFNO AND APPID = @APPID AND PROCID = @PROCID AND PROCPARAMS = @PROCPARAMS))
UPDATE MENU_METRICS SET PINNING = @PINNING
WHERE STAFFNO = @STAFFNO AND APPID = @APPID AND PROCID = @PROCID AND PROCPARAMS = @PROCPARAMS
ELSE
INSERT INTO MENU_METRICS (STAFFNO, APPID, MENU_CAPTION, PROCID, PROCPARAMS, LAST_RUN, FREQUENCY, PINNING)
VALUES(@STAFFNO, @APPID, @MENU_CAPTION, @PROCID, @PROCPARAMS, GETDATE(), 1, @PINNING)
END
ELSE
BEGIN
IF (EXISTS(SELECT SEQNO FROM MENU_METRICS WHERE STAFFNO = @STAFFNO AND APPID = @APPID AND PROCID = @PROCID AND PROCPARAMS = @PROCPARAMS))
UPDATE MENU_METRICS SET LAST_RUN = GETDATE(), FREQUENCY = FREQUENCY + 1 WHERE STAFFNO = @STAFFNO AND APPID = @APPID AND PROCID = @PROCID AND PROCPARAMS = @PROCPARAMS
ELSE
INSERT INTO MENU_METRICS (STAFFNO, APPID, MENU_CAPTION, PROCID, PROCPARAMS, LAST_RUN, FREQUENCY)
VALUES(@STAFFNO, @APPID, @MENU_CAPTION, @PROCID, @PROCPARAMS, GETDATE(), 1)
END

RETURN 0
END


Procedure: UPDATE_STOCKTRANS_NEWAVECOST
NameUPDATE_STOCKTRANS_NEWAVECOST
Note
Code-- =============================================
-- Description: This procedure populates the NEW_AVECOST field on STOCK_TRANS for all stock_Trans.
-- NEW_AVECOST is a new field created on STOCK_TRANS table in 8500.
-- NEW_AVECOST is equal to the prev_avecost field from the 'next' transaction
-- =============================================
CREATE PROCEDURE [dbo].[UPDATE_STOCKTRANS_NEWAVECOST]
(
  @STKCODE varchar(23) = ''
)
AS
BEGIN
IF @STKCODE = ''
BEGIN
    --get prev_avecost from next transaction
UPDATE STOCK_TRANS SET STOCK_TRANS.NEW_AVECOST = RESULT.PREV_AVECOST
FROM
    (
      SELECT NEWSEQ1.SEQNO, NEWSEQ2.PREV_AVECOST FROM
(SELECT SEQNO, STOCKCODE, ROW_NUMBER() OVER (PARTITION BY STOCKCODE ORDER BY SEQNO) AS SORTORDER FROM STOCK_TRANS) AS NEWSEQ1
LEFT JOIN
(SELECT PREV_AVECOST, SEQNO, STOCKCODE, ROW_NUMBER() OVER (PARTITION BY STOCKCODE ORDER BY SEQNO) AS SORTORDER FROM STOCK_TRANS) AS NEWSEQ2
ON NEWSEQ1.SORTORDER + 1 = NEWSEQ2.SORTORDER AND NEWSEQ1.STOCKCODE = NEWSEQ2.STOCKCODE
    ) AS RESULT
    INNER JOIN STOCK_TRANS ON STOCK_TRANS.SEQNO = RESULT.SEQNO

    --NEW_AVECOST of the last transaction of each stock item is equal to the AVECOST on STOCK_ITEMS
    UPDATE STOCK_TRANS SET NEW_AVECOST = STOCK_ITEMS.AVECOST
    FROM STOCK_TRANS LEFT JOIN STOCK_ITEMS ON
    STOCK_TRANS.STOCKCODE = STOCK_ITEMS.STOCKCODE
    WHERE STOCK_TRANS.SEQNO IN (SELECT MAX(SEQNO) FROM STOCK_TRANS GROUP BY STOCKCODE)

END
ELSE
BEGIN
UPDATE STOCK_TRANS SET STOCK_TRANS.NEW_AVECOST = RESULT.PREV_AVECOST
FROM
(
      SELECT NEWSEQ1.SEQNO, NEWSEQ2.PREV_AVECOST FROM
(SELECT SEQNO, STOCKCODE, ROW_NUMBER() OVER (PARTITION BY STOCKCODE ORDER BY SEQNO) AS SORTORDER FROM STOCK_TRANS WHERE STOCKCODE = @STKCODE) AS NEWSEQ1
LEFT JOIN
(SELECT PREV_AVECOST, SEQNO, STOCKCODE, ROW_NUMBER() OVER (PARTITION BY STOCKCODE ORDER BY SEQNO) AS SORTORDER FROM STOCK_TRANS WHERE STOCKCODE = @STKCODE) AS NEWSEQ2
ON NEWSEQ1.SORTORDER + 1 = NEWSEQ2.SORTORDER AND NEWSEQ1.STOCKCODE = NEWSEQ2.STOCKCODE
    ) AS RESULT
    INNER JOIN STOCK_TRANS ON STOCK_TRANS.SEQNO = RESULT.SEQNO

    UPDATE STOCK_TRANS SET NEW_AVECOST = STOCK_ITEMS.AVECOST
    FROM STOCK_TRANS LEFT JOIN STOCK_ITEMS ON
    STOCK_TRANS.STOCKCODE = STOCK_ITEMS.STOCKCODE
    WHERE STOCK_TRANS.SEQNO IN (SELECT MAX(SEQNO) FROM STOCK_TRANS WHERE STOCKCODE = @STKCODE)
END
END


Procedure: UPDATE_STOCKTRANS_NEW_LOC_QTY
NameUPDATE_STOCKTRANS_NEW_LOC_QTY
Note
Code-- =============================================
-- Description: This procedure populates the NEW_LOC_QTY field on STOCK_TRANS for all stock_Trans.
-- NEW_LOC_QTY is a new field created on STOCK_TRANS table in 8500.
-- =============================================
CREATE PROCEDURE [dbo].[UPDATE_STOCKTRANS_NEW_LOC_QTY]
AS
BEGIN
SET NOCOUNT ON;
-- the first update statement updates the last stock_trans for each stock item by setting
-- the new_loc_qty field to the current value in the stock_loc_info table
UPDATE STOCK_TRANS SET NEW_LOC_QTY = RESULT.QTY
FROM STOCK_TRANS
INNER JOIN
(SELECT STOCKCODE, LOCATION, QTY FROM STOCK_LOC_INFO) AS RESULT
ON STOCK_TRANS.STOCKCODE = RESULT.STOCKCODE AND STOCK_TRANS.LOCATION = RESULT.LOCATION
WHERE STOCK_TRANS.SEQNO IN (SELECT MAX(SEQNO) SEQNO FROM STOCK_TRANS GROUP BY STOCKCODE, LOCATION)

   DECLARE @FROMSEQNO INT
    SET @FROMSEQNO = 0 -- INITIALISE @FROMSEQNO TO 0 INCASE THAT PERIOD_STATUS DOES NOT HOLD RECORDS FOR SPECIFIED AGE
  -- this second update statement update the stock_trans for each stock item by setting
-- the new_loc_qty field to the current value in the stock_loc_info table minus
  -- the sum of the quantity transacted for the same location after each specific transaction
   SELECT @FROMSEQNO = MINSTOCKSEQNO FROM PERIOD_STATUS WHERE LEDGER = 'S' AND AGE =
   (SELECT CASE WHEN ANALYSIS_AGE_LIMIT=0 THEN 23 ELSE ANALYSIS_AGE_LIMIT END FROM LEDGER_PERIODS WHERE LEDGER = 'STOCK LEDGER')

UPDATE STOCK_TRANS SET NEW_LOC_QTY = RESULT.NEWLOC_QTY
FROM STOCK_TRANS
INNER JOIN
( SELECT STK_TRANS.*, STK_LOC.QTY - TEMPQTY AS NEWLOC_QTY
FROM
(SELECT SEQNO, STOCKCODE, LOCATION, SUM(QUANTITY) AS TEMPQTY
FROM
(
SELECT S1.SEQNO, S1.STOCKCODE, S1.LOCATION, S2.QUANTITY
FROM STOCK_TRANS S1 CROSS JOIN
STOCK_TRANS S2
WHERE S1.STOCKCODE = S2.STOCKCODE
AND S1.LOCATION = S2.LOCATION
AND S1.SEQNO < S2.SEQNO
       AND S1.SEQNO >= @FROMSEQNO
       AND S2.SEQNO >= @FROMSEQNO
) AS TEMPRESULT
GROUP BY SEQNO, STOCKCODE, LOCATION) AS STK_TRANS
LEFT JOIN
(SELECT * FROM STOCK_LOC_INFO ) AS STK_LOC
ON STK_TRANS.STOCKCODE = STK_LOC.STOCKCODE
AND STK_TRANS.LOCATION = STK_LOC.LOCATION
) AS RESULT
ON STOCK_TRANS.SEQNO = RESULT.SEQNO

END


Procedure: UPDATE_STOCKTRANS_NEW_SEQORDER
NameUPDATE_STOCKTRANS_NEW_SEQORDER
Note
Code-- =============================================
-- Description: This method reserialises the stock_trans table. STOCK_TRANS.NEW_SEQORDER field is updated
-- Transactions for the same stockcode will be sorted by PERIOD_SEQNO, TRANSDATE, SEQNO then
-- assigned a number for 1 to n
-- =============================================
CREATE PROCEDURE [dbo].[UPDATE_STOCKTRANS_NEW_SEQORDER]
(
  @STKCODE varchar(23) = '',
  @FROM_SEQNO INTEGER = -1
)
AS
BEGIN
  IF @StkCode = ''
  BEGIN
    UPDATE STOCK_TRANS SET NEW_SEQORDER = NEWSEQ.SORTORDER
    FROM
    (SELECT SEQNO, ROW_NUMBER() OVER (PARTITION BY STOCKCODE ORDER BY PERIOD_SEQNO, TRANSDATE, SEQNO) AS SORTORDER
    FROM STOCK_TRANS) AS NEWSEQ
    INNER JOIN STOCK_TRANS ON STOCK_TRANS.SEQNO = NEWSEQ.SEQNO
    WHERE STOCK_TRANS.SEQNO >= @FROM_SEQNO
  END
  ELSE
  BEGIN
    UPDATE STOCK_TRANS SET NEW_SEQORDER = NEWSEQ.SORTORDER
    FROM
    (SELECT SEQNO, ROW_NUMBER() OVER (PARTITION BY STOCKCODE ORDER BY PERIOD_SEQNO, TRANSDATE, SEQNO) AS SORTORDER
    FROM STOCK_TRANS WHERE STOCKCODE = @STKCODE ) AS NEWSEQ
    INNER JOIN STOCK_TRANS ON STOCK_TRANS.SEQNO = NEWSEQ.SEQNO
    WHERE STOCK_TRANS.SEQNO >= @FROM_SEQNO
  END
END


Procedure: UPDATE_STOCKTRANS_TRADED_IN_NEG
NameUPDATE_STOCKTRANS_TRADED_IN_NEG
Note
Code-- =============================================
-- Description: This method updates the stock_trans table, making use of the StockQtyTradedInNeg function
-- The QTY_Traded_In_Neg and ValueTradedInNeg field will be updated if the
-- Transaction happens when total stock on hand is negative when the transaction occurred
-- =============================================
CREATE PROCEDURE [dbo].[UPDATE_STOCKTRANS_TRADED_IN_NEG]
(
@FromSeqno int
)
AS
BEGIN
UPDATE STOCK_TRANS SET QTY_Traded_In_Neg = dbo.StockQtyTradedInNeg(prev_quantity, Quantity),
    Value_Traded_In_Neg =
CASE
WHEN TRANSTYPE = 1 then dbo.StockQtyTradedInNeg(prev_quantity, Quantity) * UnitPrice
WHEN TRANSTYPE = 0 then dbo.StockQtyTradedInNeg(prev_quantity, Quantity) * Prev_AveCost
ELSE 0
END
WHERE SEQNO > @FromSeqno
END