oracle 动态sql:
--差旅费用值变化时 同步更新报销模块的差旅费用值(税率值更新由前台方法实现同步)。
procedure UPDATE_EMAMOUNT(p_tenantid number, p_mainid in number) IS
tm_amount decimal(10,2); --差旅费用值
em_formula varchar2(200); --率费计算公式
em_tax decimal(10,4); -- 税费
em_expenseid number; --报销主表Id
em_detailid number; --报销明细ID
BEGIN
--取差旅费用值
select realamount
into tm_amount
from tm_travelmain t
where TRAVELMAINID = p_mainid;
--取报销明细ID
select expensedetailid
into em_detailid
from em_expensetravel
where travelmainid = p_mainid
and tenantid = p_tenantid;
--取报销主表ID
select expenseid
into em_expenseid
from em_expenselist
where expensedetailid = em_detailid;
--取税率值
EXECUTE IMMEDIATE 'select replace(taxformula,''总额'',''' ||
to_char(tm_amount) ||
''') from em_itemtypetax where itemtypeid=
(select itemtypeid from em_item where itemid=
(select expenseitemid from em_expenselist where expensedetailid=' ||
em_detailid || '))'
into em_formula;
-- dbms_output.put_line(em_formula);
EXECUTE IMMEDIATE 'select round(' || em_formula || ',4) rate from dual'
into em_tax;
-- dbms_output.put_line(em_rate);
--更新报销明细表差旅费用及税额
update em_expenselist
set amount = tm_amount,taxamount=em_tax
where expensedetailid = em_detailid;
--更新报销主表中费用及税额
update em_expensemain
set amountsum = (select sum(amount)
from em_expenselist
where expenseid = em_expenseid),
businesstax = (select sum(taxamount)
from em_expenselist
where expenseid = em_expenseid)
where expenseid = em_expenseid;
END;
执行oracle带有参数的存储过程:
--调用1: DECLARE mainid number; tenantid number; BEGIN mainid := 94; tenantid := 41; pkg_tm.update_emamount(tenantid,mainid); END;
--调用2:
begin
-- Call the procedure
pkg_tm.update_emamount(p_tenantid => 41,
p_mainid => 94);
end;
