001/*
002 * Copyright 2007 The Kuali Foundation
003 * 
004 * Licensed under the Educational Community License, Version 2.0 (the "License");
005 * you may not use this file except in compliance with the License.
006 * You may obtain a copy of the License at
007 * 
008 * http://www.opensource.org/licenses/ecl2.php
009 * 
010 * Unless required by applicable law or agreed to in writing, software
011 * distributed under the License is distributed on an "AS IS" BASIS,
012 * WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
013 * See the License for the specific language governing permissions and
014 * limitations under the License.
015 */
016package org.kuali.ole.gl.dataaccess.impl;
017
018import java.math.BigDecimal;
019import java.util.ArrayList;
020import java.util.List;
021import java.util.Map;
022
023import org.kuali.ole.gl.GeneralLedgerConstants;
024import org.kuali.ole.gl.dataaccess.AccountBalanceLevelDao;
025import org.kuali.ole.gl.service.AccountBalanceService;
026import org.kuali.ole.sys.OLEConstants;
027import org.kuali.ole.sys.businessobject.SystemOptions;
028import org.kuali.ole.sys.businessobject.UniversityDate;
029import org.springframework.dao.IncorrectResultSizeDataAccessException;
030import org.springframework.jdbc.support.rowset.SqlRowSet;
031
032/**
033 * Calculate Balance By Level Balance Inquiry Screen
034 */
035public class AccountBalanceLevelDaoJdbc extends AccountBalanceDaoJdbcBase implements AccountBalanceLevelDao {
036    private static org.apache.log4j.Logger LOG = org.apache.log4j.Logger.getLogger(AccountBalanceLevelDaoJdbc.class);
037
038    /**
039     * Summarizes all of the qualifying account balance information for the balance by level inquiry
040     * 
041     * @param universityFiscalYear the university fiscal year of reported on account balances
042     * @param chartOfAccountsCode the chart of accounts code of reported on account balances
043     * @param accountNumber the account number of reported on account balances
044     * @param financialConsolidationObjectCode the consolidation code of reported on account balances
045     * @param isCostShareExcluded whether cost share account balances should be excluded from the query or not
046     * @param isConsolidated whether the results of the query should be consolidated
047     * @param pendingEntriesCode whether this query should account for no pending entries, approved pending entries, or all pending
048     *        entries
049     * @param today the current university date
050     * @param options system options
051     * @return a List of Maps with appropriate report data
052     * @see @see org.kuali.ole.gl.dataaccess.AccountBalanceLevelDao#findAccountBalanceByLevel(java.lang.Integer, java.lang.String,
053     *      java.lang.String, java.lang.String, boolean, boolean, int, org.kuali.ole.sys.businessobject.UniversityDate,
054     *      org.kuali.ole.sys.businessobject.SystemOptions)
055     */
056    @Override
057    public List findAccountBalanceByLevel(Integer universityFiscalYear, String chartOfAccountsCode, String accountNumber, String financialConsolidationObjectCode, boolean isCostShareExcluded, boolean isConsolidated, int pendingEntriesCode, UniversityDate today, SystemOptions options) {
058
059        // Set the default sort so that income entries are first, then expense below.
060        String financialReportingSortCode = "A";
061        String sessionId = java.util.UUID.randomUUID().toString();
062        List<Map<String, Object>> data = null;
063
064        try {
065            // Delete any data for this session if it exists already (unlikely, but you never know)
066            clearTempTable("FP_BAL_BY_LEVEL_MT", "SESID", sessionId);
067            clearTempTable("FP_INTERIM1_LEVEL_MT", "SESID", sessionId);
068            clearTempTable("FP_INTERIM2_LEVEL_MT", "SESID", sessionId);
069
070            // Add in all the data we need
071            getSimpleJdbcTemplate().update("INSERT INTO FP_INTERIM1_LEVEL_MT (UNIV_FISCAL_YR, FIN_COA_CD, ACCOUNT_NBR, SUB_ACCT_NBR, FIN_OBJECT_CD, FIN_SUB_OBJ_CD, " + " CURR_BDLN_BAL_AMT, " + "ACLN_ACTLS_BAL_AMT, ACLN_ENCUM_BAL_AMT, TIMESTAMP, FIN_REPORT_SORT_CD, " + " FIN_OBJ_LEVEL_CD, SESID) " + " SELECT a.UNIV_FISCAL_YR, a.FIN_COA_CD, a.ACCOUNT_NBR, a.SUB_ACCT_NBR,a.FIN_OBJECT_CD, " + " a.FIN_SUB_OBJ_CD,a.CURR_BDLN_BAL_AMT, a.ACLN_ACTLS_BAL_AMT, a.ACLN_ENCUM_BAL_AMT, " + " a.TIMESTAMP, l.fin_report_sort_cd, l.fin_obj_level_cd, ? " + " FROM GL_ACCT_BALANCES_T a, CA_OBJECT_CODE_T o, CA_OBJ_LEVEL_T l " + " WHERE a.univ_fiscal_yr = ? AND a.fin_coa_cd = ? AND a.account_nbr = ?" + " AND a.univ_fiscal_yr = o.univ_fiscal_yr AND a.fin_coa_cd = o.fin_coa_cd " + " AND a.fin_object_cd = o.fin_object_cd AND o.fin_coa_cd = l.fin_coa_cd AND o.fin_obj_level_cd = l.fin_obj_level_cd" + " AND l.fin_cons_obj_cd = ? AND o.univ_fiscal_yr = ? AND o.fin_coa_cd = ? ", sessionId, universityFiscalYear,
072                    chartOfAccountsCode, accountNumber, financialConsolidationObjectCode, universityFiscalYear, chartOfAccountsCode);
073
074            // Summarize pending entries into fp_interim1_level_mt if necessary
075            if ((pendingEntriesCode == AccountBalanceService.PENDING_ALL) || (pendingEntriesCode == AccountBalanceService.PENDING_APPROVED)) {
076                if (getMatchingPendingEntriesByLevel(options, universityFiscalYear, chartOfAccountsCode, accountNumber, financialConsolidationObjectCode, isCostShareExcluded, pendingEntriesCode, sessionId, today)) {
077                    summarizePendingEntriesByLevel(options, sessionId);
078                }
079            }
080
081            // Add some reference data
082            getSimpleJdbcTemplate().update(
083                    "INSERT INTO FP_INTERIM2_LEVEL_MT (UNIV_FISCAL_YR, FIN_COA_CD, ACCOUNT_NBR, SUB_ACCT_NBR, FIN_OBJECT_CD, FIN_SUB_OBJ_CD, CURR_BDLN_BAL_AMT, ACLN_ACTLS_BAL_AMT, " + "ACLN_ENCUM_BAL_AMT, TIMESTAMP, SESID, FIN_REPORT_SORT_CD, FIN_OBJ_LEVEL_CD, ACCTG_CTGRY_CD ) " + 
084                            " SELECT a.UNIV_FISCAL_YR, a.FIN_COA_CD, a.ACCOUNT_NBR, a.SUB_ACCT_NBR,a.FIN_OBJECT_CD, a.FIN_SUB_OBJ_CD, a.CURR_BDLN_BAL_AMT, a.ACLN_ACTLS_BAL_AMT, " + "a.ACLN_ENCUM_BAL_AMT, a.TIMESTAMP, a.SESID, t.fin_report_sort_cd, l.fin_obj_level_cd, t.acctg_ctgry_cd" + 
085                            " FROM FP_INTERIM1_LEVEL_MT a, CA_OBJECT_CODE_T o, CA_OBJ_LEVEL_T l, CA_OBJ_TYPE_T t " +
086                            " WHERE a.univ_fiscal_yr = o.univ_fiscal_yr " + 
087                            " AND a.fin_coa_cd = o.fin_coa_cd " +
088                            " AND a.fin_object_cd = o.fin_object_cd " +
089                            " AND o.fin_coa_cd = l.fin_coa_cd " +
090                            " AND o.fin_obj_level_cd = l.fin_obj_level_cd " + 
091                            " AND o.fin_obj_typ_cd = t.fin_obj_typ_cd " + 
092                            " AND o.univ_fiscal_yr = ?" + 
093                            " AND o.fin_coa_cd = ?" +
094                            " AND l.fin_coa_cd = ?" + 
095                            " AND a.SESID = ?", universityFiscalYear, chartOfAccountsCode, chartOfAccountsCode, sessionId);
096            
097            // Delete what we don't need
098            if (isCostShareExcluded) {
099                purgeCostShareEntries("FP_INTERIM2_LEVEL_MT", "sesid", sessionId);
100            }
101
102            // Summarize
103            if (isConsolidated) {
104                getSimpleJdbcTemplate().update("INSERT INTO FP_BAL_BY_LEVEL_MT (SUB_ACCT_NBR, FIN_OBJ_LEVEL_CD, FIN_REPORT_SORT_CD, ACCTG_CTGRY_CD, CURR_BDLN_BAL_AMT, ACLN_ACTLS_BAL_AMT, ACLN_ENCUM_BAL_AMT, " + "TYP_FIN_REPORT_SORT_CD, SESID) SELECT '*ALL*', fin_obj_level_cd,fin_report_sort_cd, acctg_ctgry_cd, SUM(curr_bdln_bal_amt), " + "SUM(acln_actls_bal_amt), SUM(acln_encum_bal_amt),?, ?" + " FROM FP_INTERIM2_LEVEL_MT " + " WHERE SESID = ? " + " GROUP BY fin_report_sort_cd, fin_obj_level_cd, acctg_ctgry_cd", financialReportingSortCode, sessionId, sessionId);
105            }
106            else {
107                getSimpleJdbcTemplate().update("INSERT INTO FP_BAL_BY_LEVEL_MT (SUB_ACCT_NBR, FIN_OBJ_LEVEL_CD, FIN_REPORT_SORT_CD, ACCTG_CTGRY_CD, CURR_BDLN_BAL_AMT, ACLN_ACTLS_BAL_AMT, ACLN_ENCUM_BAL_AMT, " + "TYP_FIN_REPORT_SORT_CD, SESID) SELECT  sub_acct_nbr, fin_obj_level_cd, fin_report_sort_cd, acctg_ctgry_cd, SUM(curr_bdln_bal_amt), " + "SUM(acln_actls_bal_amt), SUM(acln_encum_bal_amt), ?, ? " + " FROM FP_INTERIM2_LEVEL_MT " + " WHERE SESID = ? " + " GROUP BY sub_acct_nbr, fin_report_sort_cd, fin_obj_level_cd, acctg_ctgry_cd", financialReportingSortCode, sessionId, sessionId);
108            }
109
110            // Here's the data
111            data = getSimpleJdbcTemplate().queryForList("select SUB_ACCT_NBR, FIN_OBJ_LEVEL_CD, FIN_REPORT_SORT_CD, CURR_BDLN_BAL_AMT, ACLN_ACTLS_BAL_AMT, ACLN_ENCUM_BAL_AMT, TYP_FIN_REPORT_SORT_CD, ACCTG_CTGRY_CD " + "from FP_BAL_BY_LEVEL_MT where SESID = ? order by fin_report_sort_cd", sessionId);
112        }
113        finally {
114            // Clean up everything
115            clearTempTable("FP_BAL_BY_LEVEL_MT", "SESID", sessionId);
116            clearTempTable("FP_INTERIM1_LEVEL_MT", "SESID", sessionId);
117            clearTempTable("FP_INTERIM2_LEVEL_MT", "SESID", sessionId);
118            clearTempTable("GL_PENDING_ENTRY_MT", "SESID", sessionId);
119        }
120        return data;
121    }
122
123    /**
124     * Summarizes all pending entries by level, so they can be added to the general query if necessary
125     * 
126     * @param options a given set of system options
127     * @param sessionId the unique web id of the currently inquiring user, which acts as a key for the temporary table
128     */
129    protected void summarizePendingEntriesByLevel(SystemOptions options, String sessionId) {
130        LOG.debug("summarizePendingEntriesByLevel() started");
131
132        try {
133            String balanceStatementSql = "SELECT CURR_BDLN_BAL_AMT,ACLN_ACTLS_BAL_AMT,ACLN_ENCUM_BAL_AMT " + "FROM FP_INTERIM1_LEVEL_MT " + "WHERE sesid = ? AND univ_fiscal_yr = ? AND fin_coa_cd = ? AND account_nbr = ? AND sub_acct_nbr = ?" + " AND fin_object_cd = ? AND fin_sub_obj_cd = ?";
134
135            String updateBalanceStatementSql = "UPDATE FP_INTERIM1_LEVEL_MT " + " SET curr_bdln_bal_amt = ?,acln_actls_bal_amt = ?,acln_encum_bal_amt = ? " + " WHERE sesid = ? AND univ_fiscal_yr = ? AND fin_coa_cd = ? AND account_nbr = ? AND sub_acct_nbr = ?" + " AND fin_object_cd = ? AND fin_sub_obj_cd = ?";
136
137            String insertBalanceStatementSql = "INSERT INTO FP_INTERIM1_LEVEL_MT (UNIV_FISCAL_YR, FIN_COA_CD, ACCOUNT_NBR, SUB_ACCT_NBR, FIN_OBJECT_CD, " + "FIN_SUB_OBJ_CD, CURR_BDLN_BAL_AMT, ACLN_ACTLS_BAL_AMT, ACLN_ENCUM_BAL_AMT, TIMESTAMP, FIN_REPORT_SORT_CD, " + "FIN_OBJ_LEVEL_CD, SESID) " + "VALUES (?,?,?,?,?,?,?,?,?," + getDbPlatform().getCurTimeFunction() + ",?,?,?)";
138
139            SqlRowSet pendingEntryRowSet = getJdbcTemplate().queryForRowSet("SELECT o.FIN_OBJ_LEVEL_CD,b.FIN_OFFST_GNRTN_CD,t.FIN_OBJTYP_DBCR_CD,l.fin_report_sort_cd,e.*" + " FROM GL_PENDING_ENTRY_MT e,CA_OBJ_TYPE_T t,CA_BALANCE_TYPE_T b,CA_OBJECT_CODE_T o,CA_OBJ_LEVEL_T l" + " WHERE e.SESID = ?" + " AND e.FIN_OBJ_TYP_CD = t.FIN_OBJ_TYP_CD" + " AND e.fin_balance_typ_cd = b.fin_balance_typ_cd" + " AND e.univ_fiscal_yr = o.univ_fiscal_yr" + " AND e.fin_coa_cd = o.fin_coa_cd" + " AND e.fin_object_cd = o.fin_object_cd" + " AND o.fin_coa_cd = l.fin_coa_cd" + " AND o.fin_obj_level_cd = l.fin_obj_level_cd " + "ORDER BY e.univ_fiscal_yr,e.account_nbr,e.sub_acct_nbr,e.fin_object_cd,e.fin_sub_obj_cd,e.fin_obj_typ_cd", new Object[] { sessionId });
140
141
142            int updateCount = 0;
143            int insertCount = 0;
144            while (pendingEntryRowSet.next()) {
145                String sortCode = pendingEntryRowSet.getString(GeneralLedgerConstants.ColumnNames.REPORT_SORT_CODE);
146                if (sortCode.length() > 1) {
147                    sortCode = sortCode.substring(0, 1);
148                }
149
150                Map<String, Object> balance = null;
151                try {
152                    balance = getSimpleJdbcTemplate().queryForMap(balanceStatementSql, sessionId, pendingEntryRowSet.getInt(GeneralLedgerConstants.ColumnNames.UNIVERSITY_FISCAL_YEAR), pendingEntryRowSet.getString(GeneralLedgerConstants.ColumnNames.CHART_OF_ACCOUNTS_CODE), pendingEntryRowSet.getString(GeneralLedgerConstants.ColumnNames.ACCOUNT_NUMBER), pendingEntryRowSet.getString(GeneralLedgerConstants.ColumnNames.SUB_ACCOUNT_NUMBER), pendingEntryRowSet.getString(GeneralLedgerConstants.ColumnNames.OBJECT_CODE), pendingEntryRowSet.getString(GeneralLedgerConstants.ColumnNames.SUB_OBJECT_CODE));
153                }
154                catch (IncorrectResultSizeDataAccessException ex) {
155                    if (ex.getActualSize() != 0) {
156                        LOG.error("balance request sql returned more than one row, aborting", ex);
157                        throw ex;
158                    }
159                    // no rows returned - that's ok
160                }
161
162                String balanceType = pendingEntryRowSet.getString(GeneralLedgerConstants.ColumnNames.BALANCE_TYPE_CODE);
163                String objectType = pendingEntryRowSet.getString(GeneralLedgerConstants.ColumnNames.OBJECT_TYPE_CODE);
164                String debitCreditCode = pendingEntryRowSet.getString(GeneralLedgerConstants.ColumnNames.DEBIT_CREDIT_CODE);
165                String objectTypeDebitCreditCode = pendingEntryRowSet.getString(GeneralLedgerConstants.ColumnNames.OBJECT_TYPE_DEBIT_CREDIT_CODE);
166                String offsetGenerationCode = pendingEntryRowSet.getString(GeneralLedgerConstants.ColumnNames.OFFSET_GENERATION_CODE);
167
168                if (balance != null) {
169                    updateCount++;
170
171                    BigDecimal budget = (BigDecimal) balance.get(GeneralLedgerConstants.ColumnNames.CURRENT_BDLN_BALANCE_AMOUNT);
172                    BigDecimal actual = (BigDecimal) balance.get(GeneralLedgerConstants.ColumnNames.ACCOUNTING_LINE_ACTUALS_BALANCE_AMOUNT);
173                    BigDecimal encumb = (BigDecimal) balance.get(GeneralLedgerConstants.ColumnNames.ACCOUNTING_LINE_ENCUMBRANCE_BALANCE_AMOUNT);
174
175                    if (balanceType.equals(options.getBudgetCheckingBalanceTypeCd())) {
176                        budget = budget.add(pendingEntryRowSet.getBigDecimal(GeneralLedgerConstants.ColumnNames.TRANSACTION_LEDGER_ENTRY_AMOUNT));
177                    }
178                    else if (balanceType.equals(options.getActualFinancialBalanceTypeCd())) {
179                        if (debitCreditCode.equals(objectTypeDebitCreditCode) || (("N".equals(offsetGenerationCode) && OLEConstants.GL_BUDGET_CODE.equals(debitCreditCode)))) {
180                            actual = actual.add(pendingEntryRowSet.getBigDecimal(GeneralLedgerConstants.ColumnNames.TRANSACTION_LEDGER_ENTRY_AMOUNT));
181                        }
182                        else {
183                            actual = actual.subtract(pendingEntryRowSet.getBigDecimal(GeneralLedgerConstants.ColumnNames.TRANSACTION_LEDGER_ENTRY_AMOUNT));
184                        }
185                    }
186                    else if (balanceType.equals(options.getExtrnlEncumFinBalanceTypCd()) || balanceType.equals(options.getIntrnlEncumFinBalanceTypCd()) || balanceType.equals(options.getPreencumbranceFinBalTypeCd()) || "CE".equals(balanceType)) {
187                        if (debitCreditCode.equals(objectTypeDebitCreditCode) || (("N".equals(offsetGenerationCode) && OLEConstants.GL_BUDGET_CODE.equals(debitCreditCode)))) {
188                            encumb = encumb.add(pendingEntryRowSet.getBigDecimal(GeneralLedgerConstants.ColumnNames.TRANSACTION_LEDGER_ENTRY_AMOUNT));
189                        }
190                        else {
191                            encumb = encumb.subtract(pendingEntryRowSet.getBigDecimal(GeneralLedgerConstants.ColumnNames.TRANSACTION_LEDGER_ENTRY_AMOUNT));
192                        }
193                    }
194
195                    // A balance exists, so we need to update it
196                    getSimpleJdbcTemplate().update(updateBalanceStatementSql, budget, actual, encumb, sessionId, pendingEntryRowSet.getInt(GeneralLedgerConstants.ColumnNames.UNIVERSITY_FISCAL_YEAR), pendingEntryRowSet.getString(GeneralLedgerConstants.ColumnNames.CHART_OF_ACCOUNTS_CODE), pendingEntryRowSet.getString(GeneralLedgerConstants.ColumnNames.ACCOUNT_NUMBER), pendingEntryRowSet.getString(GeneralLedgerConstants.ColumnNames.SUB_ACCOUNT_NUMBER), pendingEntryRowSet.getString(GeneralLedgerConstants.ColumnNames.OBJECT_CODE), pendingEntryRowSet.getString(GeneralLedgerConstants.ColumnNames.SUB_OBJECT_CODE));
197                }
198                else {
199                    insertCount++;
200
201                    BigDecimal budget = new BigDecimal("0");
202                    BigDecimal actual = new BigDecimal("0");
203                    BigDecimal encumb = new BigDecimal("0");
204
205                    if (balanceType.equals(options.getBudgetCheckingBalanceTypeCd())) {
206                        budget = pendingEntryRowSet.getBigDecimal(GeneralLedgerConstants.ColumnNames.TRANSACTION_LEDGER_ENTRY_AMOUNT);
207                    }
208                    else if (balanceType.equals(options.getActualFinancialBalanceTypeCd())) {
209                        if (debitCreditCode.equals(objectTypeDebitCreditCode) || (("N".equals(offsetGenerationCode) && OLEConstants.GL_BUDGET_CODE.equals(debitCreditCode)))) {
210                            actual = pendingEntryRowSet.getBigDecimal(GeneralLedgerConstants.ColumnNames.TRANSACTION_LEDGER_ENTRY_AMOUNT);
211                        }
212                        else {
213                            actual = pendingEntryRowSet.getBigDecimal(GeneralLedgerConstants.ColumnNames.TRANSACTION_LEDGER_ENTRY_AMOUNT).negate();
214                        }
215                    }
216                    else if (balanceType.equals(options.getExtrnlEncumFinBalanceTypCd()) || balanceType.equals(options.getIntrnlEncumFinBalanceTypCd()) || balanceType.equals(options.getPreencumbranceFinBalTypeCd()) || "CE".equals(balanceType)) {
217                        if (debitCreditCode.equals(objectTypeDebitCreditCode) || (("N".equals(offsetGenerationCode) && OLEConstants.GL_BUDGET_CODE.equals(debitCreditCode)))) {
218                            encumb = pendingEntryRowSet.getBigDecimal(GeneralLedgerConstants.ColumnNames.TRANSACTION_LEDGER_ENTRY_AMOUNT);
219                        }
220                        else {
221                            encumb = pendingEntryRowSet.getBigDecimal(GeneralLedgerConstants.ColumnNames.TRANSACTION_LEDGER_ENTRY_AMOUNT).negate();
222                        }
223                    }
224
225                    // No balance exists, so we need to insert one
226                    getSimpleJdbcTemplate().update(insertBalanceStatementSql, pendingEntryRowSet.getInt(GeneralLedgerConstants.ColumnNames.UNIVERSITY_FISCAL_YEAR), pendingEntryRowSet.getString(GeneralLedgerConstants.ColumnNames.CHART_OF_ACCOUNTS_CODE), pendingEntryRowSet.getString(GeneralLedgerConstants.ColumnNames.ACCOUNT_NUMBER), pendingEntryRowSet.getString(GeneralLedgerConstants.ColumnNames.SUB_ACCOUNT_NUMBER), pendingEntryRowSet.getString(GeneralLedgerConstants.ColumnNames.OBJECT_CODE), pendingEntryRowSet.getString(GeneralLedgerConstants.ColumnNames.SUB_OBJECT_CODE), budget, actual, encumb, pendingEntryRowSet.getString(GeneralLedgerConstants.ColumnNames.REPORT_SORT_CODE), pendingEntryRowSet.getString(GeneralLedgerConstants.ColumnNames.OBJECT_LEVEL_CODE2), sessionId);
227                }
228            }
229            LOG.info("summarizePendingEntriesByLevel() INSERTS: " + insertCount);
230            LOG.info("summarizePendingEntriesByLevel() UPDATES: " + updateCount);
231        }
232        catch (RuntimeException ex) {
233            LOG.error("summarizePendingEntriesByLevel() Exception running sql", ex);
234            throw ex;
235        }
236    }
237
238    /**
239     * Fetches pending entries summarized by level matching the keys passed in as parameter, and then saves those summaries in a
240     * temporary table
241     * 
242     * @param options a given set of system options
243     * @param universityFiscalYear the university fiscal year of pending entries to find
244     * @param chartOfAccountsCode the chart of accounts code of pending entries to find
245     * @param accountNumber the account number of pending entries to find
246     * @param financialConsolidationObjectCode the consolidation code of pending entries to find
247     * @param isCostShareExcluded whether to exclude cost share entries or not
248     * @param pendingEntriesCode whether to include all, approved, or no pending entries in this inquiry
249     * @param sessionId the unique web id of the currently inquiring user, used as a key for the temporary tables
250     * @return true if summarization process found pending entries to process, false otherwise
251     */
252    protected boolean getMatchingPendingEntriesByLevel(SystemOptions options, Integer universityFiscalYear, String chartOfAccountsCode, String accountNumber, String financialConsolidationObjectCode, boolean isCostShareExcluded, int pendingEntriesCode, String sessionId, UniversityDate today) {
253        LOG.debug("getMatchingPendingEntriesByLevel() started");
254
255        // If they have specified this year, we will get all the pending entries where the year is equal or the year is null
256        // (because most eDocs don't fill in the year field).
257        // If they have specified a previous year, we will get all the pending entries where the year is equal to their selection
258        // without the nulls (because we will post eDocs
259        // with blank years tonight most probably.
260
261
262        clearTempTable("GL_PENDING_ENTRY_MT", "SESID", sessionId);
263
264        List<Object> params = new ArrayList<Object>(20);
265
266        String insertSql = "insert into GL_PENDING_ENTRY_MT (SESID, FS_ORIGIN_CD, FDOC_NBR, TRN_ENTR_SEQ_NBR,FIN_COA_CD, ACCOUNT_NBR, SUB_ACCT_NBR, FIN_OBJECT_CD, FIN_SUB_OBJ_CD, FIN_BALANCE_TYP_CD,FIN_OBJ_TYP_CD, UNIV_FISCAL_YR, UNIV_FISCAL_PRD_CD, TRN_LDGR_ENTR_DESC, TRN_LDGR_ENTR_AMT, TRN_DEBIT_CRDT_CD," + "TRANSACTION_DT, FDOC_TYP_CD, ORG_DOC_NBR, PROJECT_CD, ORG_REFERENCE_ID, FDOC_REF_TYP_CD, FS_REF_ORIGIN_CD,FDOC_REF_NBR, FDOC_REVERSAL_DT, TRN_ENCUM_UPDT_CD, FDOC_APPROVED_CD, ACCT_SF_FINOBJ_CD, TRN_ENTR_OFST_CD,TRNENTR_PROCESS_TM) ";
267
268        String selectSql = "SELECT ?, p.FS_ORIGIN_CD, p.FDOC_NBR, p.TRN_ENTR_SEQ_NBR," + " p.FIN_COA_CD, p.ACCOUNT_NBR, " + getDbPlatform().getIsNullFunction("p.SUB_ACCT_NBR", "'-----'") + ", p.FIN_OBJECT_CD, " + getDbPlatform().getIsNullFunction("p.FIN_SUB_OBJ_CD", "'---'") + ", p.FIN_BALANCE_TYP_CD,p.FIN_OBJ_TYP_CD, p.UNIV_FISCAL_YR, p.UNIV_FISCAL_PRD_CD, p.TRN_LDGR_ENTR_DESC, p.TRN_LDGR_ENTR_AMT, p.TRN_DEBIT_CRDT_CD," + " p.TRANSACTION_DT, p.FDOC_TYP_CD, p.ORG_DOC_NBR, PROJECT_CD, p.ORG_REFERENCE_ID, p.FDOC_REF_TYP_CD, p.FS_REF_ORIGIN_CD,p.FDOC_REF_NBR, p.FDOC_REVERSAL_DT, p.TRN_ENCUM_UPDT_CD, p.FDOC_APPROVED_CD, p.ACCT_SF_FINOBJ_CD, p.TRN_ENTR_OFST_CD,p.TRNENTR_PROCESS_TM " + " FROM GL_PENDING_ENTRY_T p,CA_OBJECT_CODE_T o,CA_OBJ_LEVEL_T l,KRNS_DOC_HDR_T d,FS_DOC_HEADER_T fd " + " WHERE o.FIN_COA_CD = p.FIN_COA_CD AND o.FIN_OBJECT_CD = p.FIN_OBJECT_CD AND o.UNIV_FISCAL_YR = ? "
269                + " AND l.fin_coa_cd = o.fin_coa_cd AND l.fin_obj_level_cd = o.fin_obj_level_cd AND p.fdoc_nbr = d.DOC_HDR_ID AND d.DOC_HDR_ID = fd.fdoc_nbr " + " AND l.FIN_CONS_OBJ_CD = ?" + " AND p.FIN_COA_CD = ? AND p.account_nbr = ? ";
270        params.add(sessionId);
271        params.add(universityFiscalYear);
272        params.add(financialConsolidationObjectCode);
273        params.add(chartOfAccountsCode);
274        params.add(accountNumber);
275
276        if (pendingEntriesCode == AccountBalanceService.PENDING_APPROVED) {
277            selectSql = selectSql + " AND fd.fdoc_status_cd = '" + OLEConstants.DocumentStatusCodes.APPROVED + "' ";
278        }
279        else {
280            selectSql = selectSql + " AND fd.fdoc_status_cd <> '" + OLEConstants.DocumentStatusCodes.DISAPPROVED + "' ";
281        }
282        selectSql = selectSql + " AND fd.fdoc_status_cd <> '" + OLEConstants.DocumentStatusCodes.CANCELLED + "' ";
283        selectSql = selectSql + " AND p.FDOC_APPROVED_CD <> '" + OLEConstants.DocumentStatusCodes.CANCELLED + "' ";
284
285        if (today.getUniversityFiscalYear().equals(universityFiscalYear)) {
286            selectSql = selectSql + "AND (p.univ_fiscal_yr is null OR p.univ_fiscal_yr = ? )";
287            params.add(universityFiscalYear);
288        }
289        else {
290            selectSql = selectSql + "AND p.univ_fiscal_yr = ?";
291            params.add(universityFiscalYear);
292        }
293        getSimpleJdbcTemplate().update(insertSql + selectSql, params.toArray());
294
295        if (isCostShareExcluded) {
296            purgeCostShareEntries("GL_PENDING_ENTRY_MT", "sesid", sessionId);
297        }
298
299        if (!hasEntriesInPendingTable(sessionId)) {
300            return false;
301        }
302
303        fixPendingEntryDisplay(options.getUniversityFiscalYear(), sessionId);
304
305        return true;
306    }
307}