Merge 2ecee8d480df

This commit is contained in:
Heng Sin Low 2013-03-06 11:43:37 +08:00
commit 44dad4a15a
21 changed files with 530 additions and 25 deletions

View File

@ -0,0 +1,42 @@
CREATE OR REPLACE FUNCTION asu_get1099bucket (
p_cbpartner_id IN NUMBER,
p_cut_date IN DATE,
p_bucket IN NUMBER
)
RETURN NUMBER
IS
tmpvar NUMBER;
/******************************************************************************
NAME: asu_get1099bucket
PURPOSE:
REVISIONS:
Ver Date Author Description
--------- ---------- --------------- ------------------------------------
1.0 04/01/2008 Carlos Ruiz 1. Created this function.
******************************************************************************/
BEGIN
SELECT SUM ( (NVL (linenetamt, 0) + NVL (taxamt, 0))
* DECODE
(docbasetype,
'API', 1,
'APC', -1,
0
) -- +API->AP Invoice / -APC->AP Credit Memo
)
INTO tmpvar
FROM C_INVOICE i, C_INVOICELINE il, ASU_1099BOX b, C_DOCTYPE dt
WHERE i.c_invoice_id = il.c_invoice_id
AND i.issotrx = 'N'
AND il.asu_1099box_id = b.asu_1099box_id
AND i.dateacct BETWEEN TRUNC (p_cut_date, 'YEAR') AND p_cut_date
AND c_bpartner_id = p_cbpartner_id
AND b.bucket = p_bucket
AND i.c_doctype_id = dt.c_doctype_id
AND i.docstatus IN ('CO', 'CL');
RETURN tmpvar;
END asu_get1099bucket;
/

View File

@ -0,0 +1,142 @@
CREATE OR REPLACE VIEW rv_fact_adaxa AS
SELECT f.ad_client_id, f.ad_org_id, ( SELECT cli.name
FROM ad_client cli
WHERE cli.ad_client_id = f.ad_client_id) AS clientname, f.dateacct,
CASE
WHEN f.dateacct < (( SELECT clinfo.fy_startdate
FROM ad_clientinfo clinfo
WHERE clinfo.ad_client_id = f.ad_client_id)) THEN (( SELECT clinfo.fy_startdate - 1
FROM ad_clientinfo clinfo
WHERE clinfo.ad_client_id = f.ad_client_id))
ELSE f.dateacct
END AS bsdate,
CASE
WHEN f.dateacct < (( SELECT clinfo.fy_startdate
FROM ad_clientinfo clinfo
WHERE clinfo.ad_client_id = f.ad_client_id)) THEN ( SELECT to_char((clinfo.fy_startdate - 1), 'YYYY-MM') AS to_char
FROM ad_clientinfo clinfo
WHERE clinfo.ad_client_id = f.ad_client_id)
ELSE to_char(f.dateacct, 'YYYY-MM')
END AS bsmth, to_char((f.dateacct + 184), '"FY"YYYY') AS fyear, to_char(f.dateacct, 'YYYY-MM') AS fymth, ( SELECT t.name
FROM ad_table t
WHERE t.ad_table_id = f.ad_table_id) AS table_name, f.record_id, ( SELECT gl.name
FROM gl_budget gl
WHERE gl.gl_budget_id = f.gl_budget_id) AS budname, ( SELECT tax.name
FROM c_tax tax
WHERE tax.c_tax_id = f.c_tax_id) AS taxname,
CASE f.postingtype
WHEN 'A' THEN 'Actual'
WHEN 'B' THEN 'Budget'
WHEN 'E' THEN 'Encumbrance'
WHEN 'S' THEN 'Statistic'
ELSE 'Other'
END AS act_bud, ( SELECT c.iso_code
FROM c_currency c
WHERE c.c_currency_id = f.c_currency_id) AS currency, f.amtsourcedr - f.amtsourcecr AS amtsce, f.amtacctdr - f.amtacctcr AS amtacct,
CASE
WHEN f.postingtype = 'B' THEN 0
ELSE f.amtacctcr - f.amtacctdr
END AS "pl$act",
CASE
WHEN f.postingtype = 'B' THEN 0
WHEN ev.accounttype = 'A' THEN f.amtacctdr - f.amtacctcr
WHEN ev.accounttype = 'L' THEN f.amtacctdr - f.amtacctcr
WHEN ev.accounttype = 'O' THEN f.amtacctcr - f.amtacctdr
WHEN ev.accounttype = 'E' THEN f.amtacctcr - f.amtacctdr
WHEN ev.accounttype = 'R' THEN f.amtacctcr - f.amtacctdr
ELSE 0
END AS "bs$act",
CASE
WHEN f.postingtype = 'A' THEN 0
WHEN ev.accounttype = 'E' THEN f.amtacctcr - f.amtacctdr
WHEN ev.accounttype = 'R' THEN f.amtacctcr - f.amtacctdr
ELSE 0
END AS "pl$bud", ( SELECT um.uomsymbol
FROM c_uom um
WHERE um.c_uom_id = f.c_uom_id) AS uomname, f.qty, ( SELECT prj.name
FROM c_project prj
WHERE prj.c_project_id = f.c_project_id) AS projectname, f.description, o.name AS orgname, ev.value AS ac_code, ev.name AS ac_name, (ev.value || '-' || ev.name) AS account_name,
CASE ev.accounttype
WHEN 'A' THEN '1 Asset'
WHEN 'E' THEN '3 Equity'
WHEN 'L' THEN '2 Liability'
WHEN 'M' THEN '9 Memo'
WHEN 'O' THEN '3 Equity'
WHEN 'R' THEN '3 Equity'
ELSE '9. Unknown'
END AS bstypename,
CASE ev.accounttype
WHEN 'A' THEN '9 BSheet'
WHEN 'E' THEN '6 Expense'
WHEN 'L' THEN '9 BSheet'
WHEN 'M' THEN '9 Memo'
WHEN 'O' THEN '9 BSheet'
WHEN 'R' THEN '4 Revenue'
ELSE '9. Unknown'
END AS pltypename, ( SELECT (ss.value || '-') || ss.name
FROM c_elementvalue ss
WHERE ss.value = substr(ev.value, 1, 1) AND ss.issummary = 'Y' AND ss.ad_client_id = f.ad_client_id) AS ac_group,
CASE ev.accounttype
WHEN 'A' THEN ( SELECT (TO_CHAR(ss.value) || '-') || TO_CHAR(ss.name)
FROM c_elementvalue ss
WHERE ss.value = substr(ev.value, 1, 3) AND ss.issummary = 'Y' AND ss.ad_client_id = f.ad_client_id)
WHEN 'E' THEN '330-Current P and L Accounts Balance'
WHEN 'L' THEN ( SELECT (TO_CHAR(ss.value) || '-') || TO_CHAR(ss.name)
FROM c_elementvalue ss
WHERE ss.value = substr(ev.value, 1, 3) AND ss.issummary = 'Y' AND ss.ad_client_id = f.ad_client_id)
WHEN 'O' THEN ( SELECT (TO_CHAR(ss.value) || '-') || TO_CHAR(ss.name)
FROM c_elementvalue ss
WHERE ss.value = substr(ev.value, 1, 3) AND ss.issummary = 'Y' AND ss.ad_client_id = f.ad_client_id)
WHEN 'R' THEN '330-Current P and L Accounts Balance'
ELSE 'Unknown Account Type'
END AS bsgroup,
CASE ev.accounttype
WHEN 'A' THEN '999-Balance Sheet Item'
WHEN 'E' THEN ( SELECT (TO_CHAR(ss.value) || '-') || TO_CHAR(ss.name)
FROM c_elementvalue ss
WHERE ss.value = substr(ev.value, 1, 3) AND ss.issummary = 'Y' AND ss.ad_client_id = f.ad_client_id)
WHEN 'L' THEN '999-Balance Sheet Item'
WHEN 'O' THEN '999-Balance Sheet Item'
WHEN 'R' THEN ( SELECT (TO_CHAR(ss.value) || '-') || TO_CHAR(ss.name)
FROM c_elementvalue ss
WHERE ss.value = substr(ev.value, 1, 3) AND ss.issummary = 'Y' AND ss.ad_client_id = f.ad_client_id)
ELSE 'Unknown Account Type'
END AS plgroup,
CASE ev.accounttype
WHEN 'A' THEN 'BS'
WHEN 'E' THEN 'PL'
WHEN 'L' THEN 'BS'
WHEN 'M' THEN 'Unknown Account Type'
WHEN 'O' THEN 'BS'
WHEN 'R' THEN 'PL'
ELSE 'Unknown Account Type'
END AS plbs,
CASE ev.accounttype
WHEN 'A' THEN '1 NetAssets'
WHEN 'E' THEN '2 Equity'
WHEN 'L' THEN '1 NetAssets'
WHEN 'M' THEN '9 Memo'
WHEN 'O' THEN '2 Equity'
WHEN 'R' THEN '2 Equity'
ELSE 'Unknown Account Type'
END AS na_eq, bp.value AS bpcode, bp.name AS bpname,
CASE
WHEN bp.name IS NULL THEN NULL
ELSE (TO_CHAR(bp.value) || '-') || TO_CHAR(bp.name)
END AS bpartnercodeandname, ( SELECT bpg.name
FROM c_bp_group bpg
WHERE bpg.c_bp_group_id = bp.c_bp_group_id) AS bpgroupname, ( SELECT ad_user.name
FROM ad_user
WHERE ad_user.ad_user_id = bp.salesrep_id) AS repname, p.value AS prodcode, p.name AS prodname,
CASE
WHEN p.name IS NULL THEN NULL
ELSE (TO_CHAR(p.value) || '-') || TO_CHAR(p.name)
END AS product, ( SELECT pc.name
FROM m_product_category pc
WHERE pc.m_product_category_id = p.m_product_category_id) AS prodcategory
FROM fact_acct f
JOIN ad_org o ON f.ad_org_id = o.ad_org_id
JOIN c_elementvalue ev ON f.account_id = ev.c_elementvalue_id
LEFT JOIN c_bpartner bp ON f.c_bpartner_id = bp.c_bpartner_id
LEFT JOIN m_product p ON f.m_product_id = p.m_product_id
;

View File

@ -0,0 +1,21 @@
CREATE OR REPLACE VIEW rv_fact_simple AS
SELECT rv_fact_acct.ad_client_id, rv_fact_acct.ad_org_id, rv_fact_acct.isactive, rv_fact_acct.created, rv_fact_acct.createdby,
rv_fact_acct.updated, rv_fact_acct.updatedby, rv_fact_acct.c_project_id, rv_fact_acct.c_acctschema_id, rv_fact_acct.account_id,
rv_fact_acct.accountvalue, rv_fact_acct.accounttype, rv_fact_acct.dateacct, to_char(rv_fact_acct.dateacct, 'YYYY-MM') AS finyear_mth,
sum(rv_fact_acct.amtacctdr - rv_fact_acct.amtacctcr) AS amtacct, to_char(rv_fact_acct.dateacct, '"FY"YYYY') AS finyear,
CASE rv_fact_acct.accounttype
WHEN 'A' THEN 'B'
WHEN 'E' THEN 'P'
WHEN 'L' THEN 'B'
WHEN 'M' THEN 'B'
WHEN 'O' THEN 'B'
WHEN 'R' THEN 'P'
ELSE '9. Unknown'
END AS "case"
FROM rv_fact_acct
WHERE rv_fact_acct.postingtype = 'A'
GROUP BY rv_fact_acct.ad_client_id, rv_fact_acct.ad_org_id, rv_fact_acct.isactive, rv_fact_acct.created,
rv_fact_acct.createdby, rv_fact_acct.updated, rv_fact_acct.updatedby, rv_fact_acct.c_project_id,
rv_fact_acct.c_acctschema_id, rv_fact_acct.account_id, rv_fact_acct.accountvalue, rv_fact_acct.accounttype,
rv_fact_acct.dateacct, rv_fact_acct.amtacct
;

View File

@ -0,0 +1,10 @@
CREATE OR REPLACE VIEW RV_M_Product_WhereUsed_V AS
SELECT bom.ad_client_id, bom.ad_org_id, p2.m_product_id, p2.name AS selectedproductname,
p2.value AS selectedproductvalue, p2.description AS selectedproductdescription, b.pp_product_bom_id,
p.value, p.name, p.description, b.qtybom, b.line
FROM m_product p2
LEFT JOIN pp_product_bomline b ON p2.m_product_id = b.m_product_id
LEFT JOIN pp_product_bom bom ON b.pp_product_bom_id = bom.pp_product_bom_id
LEFT JOIN m_product p ON bom.m_product_id = p.m_product_id
WHERE p.isactive = 'Y' AND b.isactive = 'Y' AND p2.isactive = 'Y'
;

View File

@ -0,0 +1,18 @@
CREATE OR REPLACE VIEW RV_T_1099Extract AS
SELECT t.ad_pinstance_id, t.ad_client_id, t.ad_org_id, t.isactive, t.created, t.createdby, t.updated, t.updatedby,
t.c_bpartner_id, t.value, t.name, t.taxid, l.address1 || ' ' || l.address2 || ' ' || l.address3 || ' ' || l.address4 AS address,
l.address1, l.address2, l.address3, l.address4, l.city || ', ' || r.name || ' ' || l.postal AS citystatezip,
l.city, r.name AS region, l.postal AS zip, ctry.name AS country, t.cut_year, t.cut_date,
COALESCE(t.amtbucket01, 0) AS amtbucket01, COALESCE(t.amtbucket02, 0) AS amtbucket02, COALESCE(t.amtbucket03, 0) AS amtbucket03,
COALESCE(t.amtbucket04, 0) AS amtbucket04, COALESCE(t.amtbucket05, 0) AS amtbucket05, COALESCE(t.amtbucket06, 0) AS amtbucket06,
COALESCE(t.amtbucket07, 0) AS amtbucket07, COALESCE(t.amtbucket08, 0) AS amtbucket08, COALESCE(t.amtbucket09, 0) AS amtbucket09,
COALESCE(t.amtbucket10, 0) AS amtbucket10, COALESCE(t.amtbucket11, 0) AS amtbucket11, COALESCE(t.amtbucket12, 0) AS amtbucket12,
COALESCE(t.amtbucket13, 0) AS amtbucket13, COALESCE(t.amtbucket14, 0) AS amtbucket14, COALESCE(t.amtbucket15, 0) AS amtbucket15,
COALESCE(t.amtbucket16, 0) AS amtbucket16
FROM t_1099extract t
LEFT JOIN c_location l ON t.c_location_id = l.c_location_id
LEFT JOIN c_region r ON r.c_region_id = l.c_region_id
LEFT JOIN c_country ctry ON ctry.c_country_id = l.c_country_id
WHERE t.ad_pinstance_id = (SELECT max(t_1099extract.ad_pinstance_id) AS max
FROM t_1099extract)
;

View File

@ -0,0 +1,6 @@
CREATE OR REPLACE VIEW x_packagelineweight AS
SELECT pl.ad_client_id, pl.m_package_id, pl.qty, pl.m_inoutline_id, iol.m_inout_id, iol.m_product_id, p.weight, pl.qty * p.weight AS lineweight, pl.m_packagemps_id
FROM m_packageline pl
JOIN m_inoutline iol ON pl.m_inoutline_id = iol.m_inoutline_id
JOIN m_product p ON iol.m_product_id = p.m_product_id
;

View File

@ -0,0 +1,45 @@
CREATE OR REPLACE FUNCTION asu_get1099bucket (
p_cbpartner_id IN numeric,
p_cut_date IN timestamp with time zone,
p_bucket IN numeric
)
RETURNS numeric
AS
$BODY$
DECLARE
tmpvar numeric;
/******************************************************************************
NAME: asu_get1099bucket
PURPOSE:
REVISIONS:
Ver Date Author Description
--------- ---------- --------------- ------------------------------------
1.0 04/01/2008 Carlos Ruiz 1. Created this function.
******************************************************************************/
BEGIN
SELECT SUM ( (COALESCE (linenetamt, 0) + COALESCE (taxamt, 0))
* (CASE WHEN docbasetype = 'API' THEN 1
WHEN docbasetype = 'APC' THEN -1
ELSE 0
END)
) -- +API->AP Invoice / -APC->AP Credit Memo
INTO tmpvar
FROM C_INVOICE i, C_INVOICELINE il, ASU_1099BOX b, C_DOCTYPE dt
WHERE i.c_invoice_id = il.c_invoice_id
AND i.issotrx = 'N'
AND il.asu_1099box_id = b.asu_1099box_id
AND i.dateacct BETWEEN TRUNC (p_cut_date, 'YEAR') AND p_cut_date
AND c_bpartner_id = p_cbpartner_id
AND b.bucket = p_bucket
AND i.c_doctype_id = dt.c_doctype_id
AND i.docstatus IN ('CO', 'CL');
RETURN tmpvar;
END;
$BODY$
LANGUAGE plpgsql VOLATILE
COST 100
;

View File

@ -0,0 +1,142 @@
CREATE OR REPLACE VIEW rv_fact_adaxa AS
SELECT f.ad_client_id, f.ad_org_id, ( SELECT cli.name
FROM ad_client cli
WHERE cli.ad_client_id = f.ad_client_id) AS clientname, f.dateacct,
CASE
WHEN f.dateacct < (( SELECT clinfo.fy_startdate
FROM ad_clientinfo clinfo
WHERE clinfo.ad_client_id = f.ad_client_id)) THEN (( SELECT clinfo.fy_startdate - 1
FROM ad_clientinfo clinfo
WHERE clinfo.ad_client_id = f.ad_client_id))
ELSE f.dateacct
END AS bsdate,
CASE
WHEN f.dateacct < (( SELECT clinfo.fy_startdate
FROM ad_clientinfo clinfo
WHERE clinfo.ad_client_id = f.ad_client_id)) THEN ( SELECT to_char((clinfo.fy_startdate - 1), 'YYYY-MM') AS to_char
FROM ad_clientinfo clinfo
WHERE clinfo.ad_client_id = f.ad_client_id)
ELSE to_char(f.dateacct, 'YYYY-MM')
END AS bsmth, to_char((f.dateacct + 184), '"FY"YYYY') AS fyear, to_char(f.dateacct, 'YYYY-MM') AS fymth, ( SELECT t.name
FROM ad_table t
WHERE t.ad_table_id = f.ad_table_id) AS table_name, f.record_id, ( SELECT gl.name
FROM gl_budget gl
WHERE gl.gl_budget_id = f.gl_budget_id) AS budname, ( SELECT tax.name
FROM c_tax tax
WHERE tax.c_tax_id = f.c_tax_id) AS taxname,
CASE f.postingtype
WHEN 'A' THEN 'Actual'
WHEN 'B' THEN 'Budget'
WHEN 'E' THEN 'Encumbrance'
WHEN 'S' THEN 'Statistic'
ELSE 'Other'
END AS act_bud, ( SELECT c.iso_code
FROM c_currency c
WHERE c.c_currency_id = f.c_currency_id) AS currency, f.amtsourcedr - f.amtsourcecr AS amtsce, f.amtacctdr - f.amtacctcr AS amtacct,
CASE
WHEN f.postingtype = 'B' THEN 0
ELSE f.amtacctcr - f.amtacctdr
END AS "pl$act",
CASE
WHEN f.postingtype = 'B' THEN 0
WHEN ev.accounttype = 'A' THEN f.amtacctdr - f.amtacctcr
WHEN ev.accounttype = 'L' THEN f.amtacctdr - f.amtacctcr
WHEN ev.accounttype = 'O' THEN f.amtacctcr - f.amtacctdr
WHEN ev.accounttype = 'E' THEN f.amtacctcr - f.amtacctdr
WHEN ev.accounttype = 'R' THEN f.amtacctcr - f.amtacctdr
ELSE 0
END AS "bs$act",
CASE
WHEN f.postingtype = 'A' THEN 0
WHEN ev.accounttype = 'E' THEN f.amtacctcr - f.amtacctdr
WHEN ev.accounttype = 'R' THEN f.amtacctcr - f.amtacctdr
ELSE 0
END AS "pl$bud", ( SELECT um.uomsymbol
FROM c_uom um
WHERE um.c_uom_id = f.c_uom_id) AS uomname, f.qty, ( SELECT prj.name
FROM c_project prj
WHERE prj.c_project_id = f.c_project_id) AS projectname, f.description, o.name AS orgname, ev.value AS ac_code, ev.name AS ac_name, (ev.value || '-' || ev.name) AS account_name,
CASE ev.accounttype
WHEN 'A' THEN '1 Asset'
WHEN 'E' THEN '3 Equity'
WHEN 'L' THEN '2 Liability'
WHEN 'M' THEN '9 Memo'
WHEN 'O' THEN '3 Equity'
WHEN 'R' THEN '3 Equity'
ELSE '9. Unknown'
END AS bstypename,
CASE ev.accounttype
WHEN 'A' THEN '9 BSheet'
WHEN 'E' THEN '6 Expense'
WHEN 'L' THEN '9 BSheet'
WHEN 'M' THEN '9 Memo'
WHEN 'O' THEN '9 BSheet'
WHEN 'R' THEN '4 Revenue'
ELSE '9. Unknown'
END AS pltypename, ( SELECT (ss.value || '-') || ss.name
FROM c_elementvalue ss
WHERE ss.value = substr(ev.value, 1, 1) AND ss.issummary = 'Y' AND ss.ad_client_id = f.ad_client_id) AS ac_group,
CASE ev.accounttype
WHEN 'A' THEN (( SELECT (ss.value || '-') || ss.name
FROM c_elementvalue ss
WHERE ss.value = substr(ev.value, 1, 3) AND ss.issummary = 'Y' AND ss.ad_client_id = f.ad_client_id))
WHEN 'E' THEN '330-Current P and L Accounts Balance'
WHEN 'L' THEN (( SELECT (ss.value || '-') || ss.name
FROM c_elementvalue ss
WHERE ss.value = substr(ev.value, 1, 3) AND ss.issummary = 'Y' AND ss.ad_client_id = f.ad_client_id))
WHEN 'O' THEN (( SELECT (ss.value || '-') || ss.name
FROM c_elementvalue ss
WHERE ss.value = substr(ev.value, 1, 3) AND ss.issummary = 'Y' AND ss.ad_client_id = f.ad_client_id))
WHEN 'R' THEN '330-Current P and L Accounts Balance'
ELSE 'Unknown Account Type'
END AS bsgroup,
CASE ev.accounttype
WHEN 'A' THEN '999-Balance Sheet Item'
WHEN 'E' THEN (( SELECT (ss.value || '-') || ss.name
FROM c_elementvalue ss
WHERE ss.value = substr(ev.value, 1, 3) AND ss.issummary = 'Y' AND ss.ad_client_id = f.ad_client_id))
WHEN 'L' THEN '999-Balance Sheet Item'
WHEN 'O' THEN '999-Balance Sheet Item'
WHEN 'R' THEN (( SELECT (ss.value || '-') || ss.name
FROM c_elementvalue ss
WHERE ss.value = substr(ev.value, 1, 3) AND ss.issummary = 'Y' AND ss.ad_client_id = f.ad_client_id))
ELSE 'Unknown Account Type'
END AS plgroup,
CASE ev.accounttype
WHEN 'A' THEN 'BS'
WHEN 'E' THEN 'PL'
WHEN 'L' THEN 'BS'
WHEN 'M' THEN 'Unknown Account Type'
WHEN 'O' THEN 'BS'
WHEN 'R' THEN 'PL'
ELSE 'Unknown Account Type'
END AS plbs,
CASE ev.accounttype
WHEN 'A' THEN '1 NetAssets'
WHEN 'E' THEN '2 Equity'
WHEN 'L' THEN '1 NetAssets'
WHEN 'M' THEN '9 Memo'
WHEN 'O' THEN '2 Equity'
WHEN 'R' THEN '2 Equity'
ELSE 'Unknown Account Type'
END AS na_eq, bp.value AS bpcode, bp.name AS bpname,
CASE
WHEN bp.name IS NULL THEN NULL
ELSE (bp.value || '-') || bp.name
END AS bpartnercodeandname, ( SELECT bpg.name
FROM c_bp_group bpg
WHERE bpg.c_bp_group_id = bp.c_bp_group_id) AS bpgroupname, ( SELECT ad_user.name
FROM ad_user
WHERE ad_user.ad_user_id = bp.salesrep_id) AS repname, p.value AS prodcode, p.name AS prodname,
CASE
WHEN p.name IS NULL THEN NULL
ELSE (p.value || '-') || p.name
END AS product, ( SELECT pc.name
FROM m_product_category pc
WHERE pc.m_product_category_id = p.m_product_category_id) AS prodcategory
FROM fact_acct f
JOIN ad_org o ON f.ad_org_id = o.ad_org_id
JOIN c_elementvalue ev ON f.account_id = ev.c_elementvalue_id
LEFT JOIN c_bpartner bp ON f.c_bpartner_id = bp.c_bpartner_id
LEFT JOIN m_product p ON f.m_product_id = p.m_product_id
;

View File

@ -0,0 +1,21 @@
CREATE OR REPLACE VIEW rv_fact_simple AS
SELECT rv_fact_acct.ad_client_id, rv_fact_acct.ad_org_id, rv_fact_acct.isactive, rv_fact_acct.created, rv_fact_acct.createdby,
rv_fact_acct.updated, rv_fact_acct.updatedby, rv_fact_acct.c_project_id, rv_fact_acct.c_acctschema_id, rv_fact_acct.account_id,
rv_fact_acct.accountvalue, rv_fact_acct.accounttype, rv_fact_acct.dateacct, to_char(rv_fact_acct.dateacct, 'YYYY-MM') AS finyear_mth,
sum(rv_fact_acct.amtacctdr - rv_fact_acct.amtacctcr) AS amtacct, to_char(rv_fact_acct.dateacct, '"FY"YYYY') AS finyear,
CASE rv_fact_acct.accounttype
WHEN 'A' THEN 'B'
WHEN 'E' THEN 'P'
WHEN 'L' THEN 'B'
WHEN 'M' THEN 'B'
WHEN 'O' THEN 'B'
WHEN 'R' THEN 'P'
ELSE '9. Unknown'
END AS "case"
FROM rv_fact_acct
WHERE rv_fact_acct.postingtype = 'A'
GROUP BY rv_fact_acct.ad_client_id, rv_fact_acct.ad_org_id, rv_fact_acct.isactive, rv_fact_acct.created,
rv_fact_acct.createdby, rv_fact_acct.updated, rv_fact_acct.updatedby, rv_fact_acct.c_project_id,
rv_fact_acct.c_acctschema_id, rv_fact_acct.account_id, rv_fact_acct.accountvalue, rv_fact_acct.accounttype,
rv_fact_acct.dateacct, rv_fact_acct.amtacct
;

View File

@ -0,0 +1,10 @@
CREATE OR REPLACE VIEW RV_M_Product_WhereUsed_V AS
SELECT bom.ad_client_id, bom.ad_org_id, p2.m_product_id, p2.name AS selectedproductname,
p2.value AS selectedproductvalue, p2.description AS selectedproductdescription, b.pp_product_bom_id,
p.value, p.name, p.description, b.qtybom, b.line
FROM m_product p2
LEFT JOIN pp_product_bomline b ON p2.m_product_id = b.m_product_id
LEFT JOIN pp_product_bom bom ON b.pp_product_bom_id = bom.pp_product_bom_id
LEFT JOIN m_product p ON bom.m_product_id = p.m_product_id
WHERE p.isactive = 'Y' AND b.isactive = 'Y' AND p2.isactive = 'Y'
;

View File

@ -0,0 +1,18 @@
CREATE OR REPLACE VIEW RV_T_1099Extract AS
SELECT t.ad_pinstance_id, t.ad_client_id, t.ad_org_id, t.isactive, t.created, t.createdby, t.updated, t.updatedby,
t.c_bpartner_id, t.value, t.name, t.taxid, l.address1 || ' ' || l.address2 || ' ' || l.address3 || ' ' || l.address4 AS address,
l.address1, l.address2, l.address3, l.address4, l.city || ', ' || r.name || ' ' || l.postal AS citystatezip,
l.city, r.name AS region, l.postal AS zip, ctry.name AS country, t.cut_year, t.cut_date,
COALESCE(t.amtbucket01, 0) AS amtbucket01, COALESCE(t.amtbucket02, 0) AS amtbucket02, COALESCE(t.amtbucket03, 0) AS amtbucket03,
COALESCE(t.amtbucket04, 0) AS amtbucket04, COALESCE(t.amtbucket05, 0) AS amtbucket05, COALESCE(t.amtbucket06, 0) AS amtbucket06,
COALESCE(t.amtbucket07, 0) AS amtbucket07, COALESCE(t.amtbucket08, 0) AS amtbucket08, COALESCE(t.amtbucket09, 0) AS amtbucket09,
COALESCE(t.amtbucket10, 0) AS amtbucket10, COALESCE(t.amtbucket11, 0) AS amtbucket11, COALESCE(t.amtbucket12, 0) AS amtbucket12,
COALESCE(t.amtbucket13, 0) AS amtbucket13, COALESCE(t.amtbucket14, 0) AS amtbucket14, COALESCE(t.amtbucket15, 0) AS amtbucket15,
COALESCE(t.amtbucket16, 0) AS amtbucket16
FROM t_1099extract t
LEFT JOIN c_location l ON t.c_location_id = l.c_location_id
LEFT JOIN c_region r ON r.c_region_id = l.c_region_id
LEFT JOIN c_country ctry ON ctry.c_country_id = l.c_country_id
WHERE t.ad_pinstance_id = (SELECT max(t_1099extract.ad_pinstance_id) AS max
FROM t_1099extract)
;

View File

@ -0,0 +1,6 @@
CREATE OR REPLACE VIEW x_packagelineweight AS
SELECT pl.ad_client_id, pl.m_package_id, pl.qty, pl.m_inoutline_id, iol.m_inout_id, iol.m_product_id, p.weight, pl.qty * p.weight AS lineweight, pl.m_packagemps_id
FROM m_packageline pl
JOIN m_inoutline iol ON pl.m_inoutline_id = iol.m_inoutline_id
JOIN m_product p ON iol.m_product_id = p.m_product_id
;

View File

@ -5119,7 +5119,8 @@ CREATE OR REPLACE VIEW x_packagelineweight AS
SELECT pl.ad_client_id, pl.m_package_id, pl.qty, pl.m_inoutline_id, iol.m_inout_id, iol.m_product_id, p.weight, pl.qty * p.weight AS lineweight, pl.m_packagemps_id
FROM m_packageline pl
JOIN m_inoutline iol ON pl.m_inoutline_id = iol.m_inoutline_id
JOIN m_product p ON iol.m_product_id = p.m_product_id;
JOIN m_product p ON iol.m_product_id = p.m_product_id
;
-- Dec 6, 2012 4:40:10 PM SGT
-- Ticket 1001758: FedEx & UPS

View File

@ -1293,7 +1293,10 @@ CREATE OR REPLACE VIEW RV_T_1099Extract AS
LEFT JOIN c_region r ON r.c_region_id = l.c_region_id
LEFT JOIN c_country ctry ON ctry.c_country_id = l.c_country_id
WHERE t.ad_pinstance_id = (SELECT max(t_1099extract.ad_pinstance_id) AS max
FROM t_1099extract);-- Feb 28, 2013 5:57:20 PM SGT
FROM t_1099extract)
;
-- Feb 28, 2013 5:57:20 PM SGT
-- Ticket 1001763: Standard Templates for Docs and Forms - Reporting
INSERT INTO AD_Column (Version,AD_Table_ID,AD_Column_ID,EntityType,IsMandatory,IsTranslated,IsIdentifier,IsParent,FieldLength,IsSelectionColumn,AD_Reference_ID,IsKey,AD_Element_ID,AD_Column_UU,IsUpdateable,ColumnName,Description,Name,CreatedBy,Updated,AD_Org_ID,IsActive,Created,UpdatedBy,AD_Client_ID,IsAlwaysUpdateable,IsEncrypted) VALUES (0,200068,208646,'D','N','N','N','N',10,'N',19,'N',114,'23bfec04-9c67-4d6e-8483-dc3ae4a8f522','N','AD_PInstance_ID','Instance of the process','Process Instance',100,TO_DATE('2013-02-28 17:57:19','YYYY-MM-DD HH24:MI:SS'),0,'Y',TO_DATE('2013-02-28 17:57:19','YYYY-MM-DD HH24:MI:SS'),100,0,'N','N')
;

View File

@ -1,3 +1,6 @@
SET SQLBLANKLINES ON
SET DEFINE OFF
-- Mar 1, 2013 12:13:25 PM SGT
-- Ticket 1001763: Standard Templates for Docs and Forms - Reporting
INSERT INTO AD_Table (ImportTable,CopyColumnsFromTable,IsSecurityEnabled,AccessLevel,LoadSeq,AD_Table_ID,IsHighVolume,IsView,IsChangeLog,EntityType,ReplicationType,AD_Table_UU,IsCentrallyMaintained,IsDeleteable,TableName,Name,AD_Client_ID,IsActive,AD_Org_ID,Updated,CreatedBy,UpdatedBy,Created) VALUES ('N','N','N','4',0,200070,'N','N','N','D','L','056ac053-9bfe-418e-b853-c5bc786bb13d','Y','Y','T_BankRegister','Bank Register',0,'Y',0,TO_DATE('2013-03-01 12:13:23','YYYY-MM-DD HH24:MI:SS'),100,100,TO_DATE('2013-03-01 12:13:23','YYYY-MM-DD HH24:MI:SS'))

View File

@ -1,3 +1,6 @@
SET SQLBLANKLINES ON
SET DEFINE OFF
CREATE OR REPLACE VIEW RV_M_Product_WhereUsed_V AS
SELECT bom.ad_client_id, bom.ad_org_id, p2.m_product_id, p2.name AS selectedproductname,
p2.value AS selectedproductvalue, p2.description AS selectedproductdescription, b.pp_product_bom_id,
@ -6,7 +9,8 @@ CREATE OR REPLACE VIEW RV_M_Product_WhereUsed_V AS
LEFT JOIN pp_product_bomline b ON p2.m_product_id = b.m_product_id
LEFT JOIN pp_product_bom bom ON b.pp_product_bom_id = bom.pp_product_bom_id
LEFT JOIN m_product p ON bom.m_product_id = p.m_product_id
WHERE p.isactive = 'Y' AND b.isactive = 'Y' AND p2.isactive = 'Y';
WHERE p.isactive = 'Y' AND b.isactive = 'Y' AND p2.isactive = 'Y'
;
-- Mar 1, 2013 2:25:30 PM SGT
-- Ticket 1001763: Standard Templates for Docs and Forms - Reporting

View File

@ -42,7 +42,8 @@ CREATE OR REPLACE VIEW rv_fact_simple AS
GROUP BY rv_fact_acct.ad_client_id, rv_fact_acct.ad_org_id, rv_fact_acct.isactive, rv_fact_acct.created,
rv_fact_acct.createdby, rv_fact_acct.updated, rv_fact_acct.updatedby, rv_fact_acct.c_project_id,
rv_fact_acct.c_acctschema_id, rv_fact_acct.account_id, rv_fact_acct.accountvalue, rv_fact_acct.accounttype,
rv_fact_acct.dateacct, rv_fact_acct.amtacct;
rv_fact_acct.dateacct, rv_fact_acct.amtacct
;
CREATE OR REPLACE VIEW rv_fact_adaxa AS
SELECT f.ad_client_id, f.ad_org_id, ( SELECT cli.name
@ -184,8 +185,10 @@ CREATE OR REPLACE VIEW rv_fact_adaxa AS
JOIN ad_org o ON f.ad_org_id = o.ad_org_id
JOIN c_elementvalue ev ON f.account_id = ev.c_elementvalue_id
LEFT JOIN c_bpartner bp ON f.c_bpartner_id = bp.c_bpartner_id
LEFT JOIN m_product p ON f.m_product_id = p.m_product_id;
-- Mar 1, 2013 5:49:51 PM SGT
LEFT JOIN m_product p ON f.m_product_id = p.m_product_id
;
-- Mar 1, 2013 5:49:51 PM SGT
-- Ticket 1001763: Standard Templates for Docs and Forms - Reporting
INSERT INTO AD_Table (ImportTable,CopyColumnsFromTable,IsSecurityEnabled,AccessLevel,LoadSeq,AD_Table_ID,IsHighVolume,IsView,IsChangeLog,EntityType,ReplicationType,AD_Table_UU,IsCentrallyMaintained,IsDeleteable,TableName,Name,AD_Client_ID,IsActive,AD_Org_ID,Updated,CreatedBy,UpdatedBy,Created) VALUES ('N','N','N','3',0,200072,'N','Y','N','D','L','014cfa42-6fad-47d9-bc06-d29272245190','Y','N','RV_Fact_Simple','Simple Fact View',0,'Y',0,TO_DATE('2013-03-01 17:49:50','YYYY-MM-DD HH24:MI:SS'),100,100,TO_DATE('2013-03-01 17:49:50','YYYY-MM-DD HH24:MI:SS'))
;

View File

@ -5116,7 +5116,8 @@ CREATE OR REPLACE VIEW x_packagelineweight AS
SELECT pl.ad_client_id, pl.m_package_id, pl.qty, pl.m_inoutline_id, iol.m_inout_id, iol.m_product_id, p.weight, pl.qty * p.weight AS lineweight, pl.m_packagemps_id
FROM m_packageline pl
JOIN m_inoutline iol ON pl.m_inoutline_id = iol.m_inoutline_id
JOIN m_product p ON iol.m_product_id = p.m_product_id;
JOIN m_product p ON iol.m_product_id = p.m_product_id
;
-- Dec 6, 2012 4:40:10 PM SGT
-- Ticket 1001758: FedEx & UPS

View File

@ -1293,7 +1293,10 @@ CREATE OR REPLACE VIEW RV_T_1099Extract AS
LEFT JOIN c_region r ON r.c_region_id = l.c_region_id
LEFT JOIN c_country ctry ON ctry.c_country_id = l.c_country_id
WHERE t.ad_pinstance_id = (SELECT max(t_1099extract.ad_pinstance_id) AS max
FROM t_1099extract);-- Feb 28, 2013 5:57:20 PM SGT
FROM t_1099extract)
;
-- Feb 28, 2013 5:57:20 PM SGT
-- Ticket 1001763: Standard Templates for Docs and Forms - Reporting
INSERT INTO AD_Column (Version,AD_Table_ID,AD_Column_ID,EntityType,IsMandatory,IsTranslated,IsIdentifier,IsParent,FieldLength,IsSelectionColumn,AD_Reference_ID,IsKey,AD_Element_ID,AD_Column_UU,IsUpdateable,ColumnName,Description,Name,CreatedBy,Updated,AD_Org_ID,IsActive,Created,UpdatedBy,AD_Client_ID,IsAlwaysUpdateable,IsEncrypted) VALUES (0,200068,208646,'D','N','N','N','N',10,'N',19,'N',114,'23bfec04-9c67-4d6e-8483-dc3ae4a8f522','N','AD_PInstance_ID','Instance of the process','Process Instance',100,TO_TIMESTAMP('2013-02-28 17:57:19','YYYY-MM-DD HH24:MI:SS'),0,'Y',TO_TIMESTAMP('2013-02-28 17:57:19','YYYY-MM-DD HH24:MI:SS'),100,0,'N','N')
;
@ -6803,8 +6806,9 @@ DECLARE
BEGIN
SELECT SUM ( (COALESCE (linenetamt, 0) + COALESCE (taxamt, 0))
* (CASE WHEN docbasetype = 'API' THEN 1
CASE WHEN docbasetype = 'APC' THEN -1
ELSE 0 END)
WHEN docbasetype = 'APC' THEN -1
ELSE 0
END)
) -- +API->AP Invoice / -APC->AP Credit Memo
INTO tmpvar
FROM C_INVOICE i, C_INVOICELINE il, ASU_1099BOX b, C_DOCTYPE dt
@ -6821,7 +6825,8 @@ BEGIN
END;
$BODY$
LANGUAGE plpgsql VOLATILE
COST 100;
COST 100
;
SELECT register_migration_script('201303041619_TICKET-1001763_1099Extract.sql') FROM dual
;

View File

@ -6,7 +6,8 @@ CREATE OR REPLACE VIEW RV_M_Product_WhereUsed_V AS
LEFT JOIN pp_product_bomline b ON p2.m_product_id = b.m_product_id
LEFT JOIN pp_product_bom bom ON b.pp_product_bom_id = bom.pp_product_bom_id
LEFT JOIN m_product p ON bom.m_product_id = p.m_product_id
WHERE p.isactive = 'Y' AND b.isactive = 'Y' AND p2.isactive = 'Y';
WHERE p.isactive = 'Y' AND b.isactive = 'Y' AND p2.isactive = 'Y'
;
-- Mar 1, 2013 2:25:30 PM SGT
-- Ticket 1001763: Standard Templates for Docs and Forms - Reporting

View File

@ -42,7 +42,8 @@ CREATE OR REPLACE VIEW rv_fact_simple AS
GROUP BY rv_fact_acct.ad_client_id, rv_fact_acct.ad_org_id, rv_fact_acct.isactive, rv_fact_acct.created,
rv_fact_acct.createdby, rv_fact_acct.updated, rv_fact_acct.updatedby, rv_fact_acct.c_project_id,
rv_fact_acct.c_acctschema_id, rv_fact_acct.account_id, rv_fact_acct.accountvalue, rv_fact_acct.accounttype,
rv_fact_acct.dateacct, rv_fact_acct.amtacct;
rv_fact_acct.dateacct, rv_fact_acct.amtacct
;
CREATE OR REPLACE VIEW rv_fact_adaxa AS
SELECT f.ad_client_id, f.ad_org_id, ( SELECT cli.name
@ -184,7 +185,9 @@ CREATE OR REPLACE VIEW rv_fact_adaxa AS
JOIN ad_org o ON f.ad_org_id = o.ad_org_id
JOIN c_elementvalue ev ON f.account_id = ev.c_elementvalue_id
LEFT JOIN c_bpartner bp ON f.c_bpartner_id = bp.c_bpartner_id
LEFT JOIN m_product p ON f.m_product_id = p.m_product_id;
LEFT JOIN m_product p ON f.m_product_id = p.m_product_id
;
-- Mar 1, 2013 5:49:51 PM SGT
-- Ticket 1001763: Standard Templates for Docs and Forms - Reporting
INSERT INTO AD_Table (ImportTable,CopyColumnsFromTable,IsSecurityEnabled,AccessLevel,LoadSeq,AD_Table_ID,IsHighVolume,IsView,IsChangeLog,EntityType,ReplicationType,AD_Table_UU,IsCentrallyMaintained,IsDeleteable,TableName,Name,AD_Client_ID,IsActive,AD_Org_ID,Updated,CreatedBy,UpdatedBy,Created) VALUES ('N','N','N','3',0,200072,'N','Y','N','D','L','014cfa42-6fad-47d9-bc06-d29272245190','Y','N','RV_Fact_Simple','Simple Fact View',0,'Y',0,TO_TIMESTAMP('2013-03-01 17:49:50','YYYY-MM-DD HH24:MI:SS'),100,100,TO_TIMESTAMP('2013-03-01 17:49:50','YYYY-MM-DD HH24:MI:SS'))