如何利用Access查詢采集用友8.x輔助賬

字號:

今年在對某單位開展計(jì)算機(jī)審計(jì)時(shí),了解到被審計(jì)單位財(cái)務(wù)核算軟件為用友8.0,后臺(tái)數(shù)據(jù)庫為SQL Server 2000。筆者使用用友8.x SQLServer備份模板將該單位財(cái)務(wù)數(shù)據(jù)導(dǎo)入到AO中,但在進(jìn)行會(huì)計(jì)科目審查時(shí)發(fā)現(xiàn),由于被審計(jì)單位對預(yù)付賬款、其他應(yīng)收款、應(yīng)付賬款等往來核算項(xiàng)目實(shí)行了輔助核算,因此在AO科目審查中無法查看到往來核算明細(xì)科目。
    在這種情況下,審計(jì)人員要對往來核算明細(xì)進(jìn)行審查,就仍然要翻閱手工明細(xì)賬,給審計(jì)工作帶來了很大的不便,也極大地影響了審計(jì)效率的提高。筆者經(jīng)過對財(cái)務(wù)軟件后臺(tái)數(shù)據(jù)庫表進(jìn)行分析,探索出了利用Access查詢生成新的科目表、余額表及憑證表,從而實(shí)現(xiàn)在AO中導(dǎo)入往來輔助賬的方法,介紹出來供讀者參考。
    一、確定導(dǎo)入往來輔助賬所需要的數(shù)據(jù)表及表間關(guān)系
    (一)基本數(shù)據(jù)表:
    1.code 科目表;
    2.GL_accsum 科目余額表;
    3.GL_accvouch 憑證表
    (二)往來輔助核算表:
    1.Customer 單位往來編碼表
    2.Person 個(gè)人往來編碼表
    3.Vendor 應(yīng)付款項(xiàng)編碼表
    (三)輔助核算表與憑證表之間的關(guān)系如下所示:
     序號 憑證表 關(guān)聯(lián)字段 輔助核算表 關(guān)聯(lián)字段
     1 GL_accvouch cperson_id Personc PersonCode
     2 GL_accvouch ccus_id Customer CusCode
     3 GL_accvouch csup_id Vendor VenCode
    二、具體步驟
    (一)采集原始數(shù)據(jù)并進(jìn)行數(shù)據(jù)整理
    1.采集數(shù)據(jù)。從被審計(jì)單位采集用友8.0財(cái)務(wù)軟件的SQL Server備份數(shù)據(jù),拷貝到審計(jì)人員的電腦中進(jìn)行數(shù)據(jù)庫還原,然后選擇code、GL_accsum、GL_accvouch、Customer、Person、Vendor共六張表導(dǎo)出到Access數(shù)據(jù)庫中。
    2.?dāng)?shù)據(jù)整理。由于被審計(jì)單位在對輔助核算科目進(jìn)行編碼時(shí)存在個(gè)別不規(guī)則的現(xiàn)象,因此要對數(shù)據(jù)進(jìn)行規(guī)范化整理。例如Customer表的cCusCode字段應(yīng)以“KH”加數(shù)字編碼組成,對其進(jìn)行整理時(shí),執(zhí)行如下查詢:
    Select * from Customer where cCusCode not like 'KH*'
    篩選出編碼不規(guī)則的記錄,利用編輯菜單的替換功能進(jìn)行批量更改。Person表的cPersonCode字段應(yīng)以“GR” 加數(shù)字編碼組成,Vendor表的cVenCode字段應(yīng)以“GYS”加數(shù)字編碼組成,整理方法同Customer表。
    (二)生成新的數(shù)據(jù)表
    1.生成新科目余額表
    ⑴生成余額表。查詢語句如下:
    SELECT GL_accsum.ccode AS 科目編碼, GL_accsum.mb AS 期初余額, GL_accsum.cendd_c AS 余額方向 INTO 余額表 FROM GL_accsum
    WHERE (((GL_accsum.iperiod)=1))
    ORDER BY GL_accsum.ccode;
    ⑵生成往來余額明細(xì)表。查詢語句如下:
    SELECT GL_accvouch.ccode AS 科目編碼, GL_accvouch.md AS 借方余額, GL_accvouch.mc AS 貸方余額, GL_accvouch.cperson_id AS 個(gè)人往來編碼, Person.cPersonName, GL_accvouch.csup_id AS 應(yīng)付單位編碼, Vendor.cVenName, GL_accvouch.ccus_id AS 單位往來編碼, Customer.cCusName, GL_accvouch.dbill_date INTO 往來余額明細(xì)表
    FROM Vendor RIGHT JOIN (Customer RIGHT JOIN (Person RIGHT JOIN GL_accvouch ON Person.cPersonCode = GL_accvouch.cperson_id) ON Customer.cCusCode = GL_accvouch.ccus_id) ON Vendor.cVenCode = GL_accvouch.csup_id WHERE (((GL_accvouch.dbill_date) Like '2007-12-31'));
    ⑶生成新往來余額表。查詢語句如下:
    SELECT
    IIf([單位往來編碼] Is Not Null,IIf(Len([單位往來編碼])=3,余額表.科目編碼+'0'+Right([單位往來編碼],1),余額表.科目編碼+Right([單位往來編碼],2)),
    IIf([應(yīng)付單位編碼] Is Not Null,IIf(Len([應(yīng)付單位編碼])=4,余額表.科目編碼+'0'+Right([應(yīng)付單位編碼],1),余額表.科目編碼+Right([應(yīng)付單位編碼],2)),
    IIf(Len([個(gè)人往來編碼])=3,余額表.科目編碼+'0'+Right([個(gè)人往來編碼],1),余額表.科目編碼+Right([個(gè)人往來編碼],2)))) AS 新科目編碼,
    IIf([借方余額]>0,[借方余額],[貸方余額]) AS 余額,
    IIf([借方余額]>0,'借','貸') AS 方向,
    IIf([cpersonname] Is Not Null,[cpersonname],IIf([cvenname] Is Not Null,[cvenname],[ccusname])) AS 科目名稱 INTO 新往來余額表
    FROM 往來余額明細(xì)表 INNER JOIN 余額表 ON 往來余額明細(xì)表.科目編碼 = 余額表.科目編碼;
    ⑷生成新余額表。查詢語句如下:
    SELECT * INTO 新余額表 FROM [SELECT * from 余額表
    union select 新科目編碼,余額,方向 from 新往來余額表]. AS A
    ORDER BY A.科目編碼;
    2.生成新憑證表
    ⑴生成新憑證中間表。查詢語句如下:
    SELECT GL_accvouch.dbill_date AS 編制日期, GL_accvouch.ino_id AS 憑證編號, GL_accvouch.ccode AS 科目編碼, GL_accvouch.md AS 借方金額, GL_accvouch.mc AS 貸方金額, GL_accvouch.cdigest AS 摘要, GL_accvouch.cperson_id AS 個(gè)人編碼, Person.cPersonName, GL_accvouch.ccus_id AS 單位往來編碼, Customer.cCusName, GL_accvouch.csup_id AS 應(yīng)付款編碼, Vendor.cVenName INTO 新憑證中間表
    FROM Vendor RIGHT JOIN (Person RIGHT JOIN (Customer RIGHT JOIN GL_accvouch ON Customer.cCusCode = GL_accvouch.ccus_id) ON Person.cPersonCode = GL_accvouch.cperson_id) ON Vendor.cVenCode = GL_accvouch.csup_id
    WHERE (((GL_accvouch.dbill_date) Like '2008*') AND ((GL_accvouch.ino_id) Is Not Null))
    ORDER BY GL_accvouch.dbill_date, GL_accvouch.ino_id;
    ⑵生成新憑證表。查詢語句如下:
    SELECT 新憑證中間表.編制日期, 新憑證中間表.憑證編號,
    IIf([單位往來編碼] Is Not Null,IIf(Len([單位往來編碼])=3,[科目編碼]+'0'+Right([單位往來編碼],1),[科目編碼]+Right([單位往來編碼],2)),
    IIf([應(yīng)付款編碼] Is Not Null,IIf(Len([應(yīng)付款編碼])=4,[科目編碼]+'0'+Right([應(yīng)付款編碼],1),[科目編碼]+Right([應(yīng)付款編碼],2)),
    IIf([個(gè)人編碼] Is Not Null,IIf(Len([個(gè)人編碼])=3,[科目編碼]+'0'+Right([個(gè)人編碼],1),[科目編碼]+Right([個(gè)人編碼],2)),[科目編碼])
    )) AS 新科目編碼,
    新憑證中間表.借方金額, 新憑證中間表.貸方金額, 新憑證中間表.摘要 INTO 新憑證表 FROM 新憑證中間表;
    3.生成新科目表
    ⑴生成科目表。查詢語句如下:
    SELECT code.ccode AS 科目編碼, code.ccode_name AS 科目名稱 INTO 科目表 FROM code;
    ⑵生成新科目表。查詢語句如下:
    SELECT * INTO 新科目表
    FROM (SELECT DISTINCT
    iif([單位往來編碼] Is Not Null,IIf(Len([單位往來編碼])=3,科目表.科目編碼+'0'+Right([單位往來編碼],1),科目表.科目編碼+Right([單位往來編碼],2)),
    IIf([應(yīng)付款編碼] Is Not Null,IIf(Len([應(yīng)付款編碼])=4,科目表.科目編碼+'0'+Right([應(yīng)付款編碼],1),科目表.科目編碼+Right([應(yīng)付款編碼],2)),
    IIf([個(gè)人編碼] Is Not Null,IIf(Len([個(gè)人編碼])=3,科目表.科目編碼+'0'+Right([個(gè)人編碼],1),科目表.科目編碼+Right([個(gè)人編碼],2)),科目表.科目編碼))) AS 新科目編碼,
    iif([單位往來編碼] Is Not Null,[ccusname],
    iif([應(yīng)付款編碼] Is Not Null,[cVenName],
    iif([個(gè)人編碼] Is Not Null,[cPersonName],[科目名稱])
    )) AS 新科目名稱
    FROM 新憑證中間表 RIGHT JOIN 科目表 ON 新憑證中間表.科目編碼 = 科目表.科目編碼
    union select * from 科目表 union select 新科目編碼,科目名稱 from 新往來余額表) AS A;
    (三)利用AO采集轉(zhuǎn)換功能生成電子賬套
    將以上在Access數(shù)據(jù)庫中整理后形成的新科目表、新余額表和新憑證表,通過財(cái)務(wù)軟件數(shù)據(jù)庫采集方式導(dǎo)入AO,然后利用輔助導(dǎo)入向?qū)О凑仗崾据斎爰纯赏瓿伞?BR>    (四)數(shù)據(jù)核對
    數(shù)據(jù)導(dǎo)入AO完成后,需對操作的準(zhǔn)確性進(jìn)行判斷。可從AO 的“審計(jì)分析/賬表分析/報(bào)表審查”菜單生成被審計(jì)單位的資產(chǎn)負(fù)債表,與該單位的紙制報(bào)表進(jìn)行核對;或“審計(jì)分析/賬表分析/會(huì)計(jì)科目審查”界面,將科目樹中的信息與被審計(jì)單位提供的紙制會(huì)計(jì)賬簿進(jìn)行核對。如果相符,則證明數(shù)據(jù)導(dǎo)入成功。
    三、幾點(diǎn)體會(huì)
    審計(jì)人員在數(shù)據(jù)采集過程中遇到需要采集輔助賬的情況時(shí),只要通過對數(shù)據(jù)庫表進(jìn)行認(rèn)真分析,找出導(dǎo)入數(shù)據(jù)所需的關(guān)鍵數(shù)據(jù)表及其相互關(guān)系,就可以實(shí)現(xiàn)將輔助核算數(shù)據(jù)導(dǎo)入AO中。例如本例中通過Access查詢實(shí)現(xiàn)導(dǎo)入往來輔助賬后,審計(jì)人員可以方便地在AO中對往來明細(xì)科目進(jìn)行審查,極大地提高審計(jì)工作效率。