Skip to content

Commit

Permalink
#6394 Showing logo on each page and the right total pages count! (#6422)
Browse files Browse the repository at this point in the history
* #6394 Showing logo on each page and the right total pages count!

* Add `AD_Org_ID` to report

#6394

* #6394 fix organisation and logo subreport.

* Add `AD_Org_ID` to report

#6394

* #6394 logo subreport.

Co-authored-by: TheBestPessimist <cristian@tbp.land>
  • Loading branch information
2 people authored and metas-ts committed Apr 3, 2020
1 parent eeae86f commit ebaff10
Show file tree
Hide file tree
Showing 3 changed files with 152 additions and 11 deletions.
Original file line number Diff line number Diff line change
@@ -0,0 +1,127 @@
DROP FUNCTION IF EXISTS report.Current_Vs_Previous_Pricelist_Comparison_Report(p_C_BPartner_ID numeric, p_C_BP_Group_ID numeric, p_IsSoTrx text, p_AD_Language text)
;

CREATE OR REPLACE FUNCTION report.Current_Vs_Previous_Pricelist_Comparison_Report(p_C_BPartner_ID numeric = NULL,
p_C_BP_Group_ID numeric = NULL,
p_IsSoTrx text = 'Y',
p_AD_Language TEXT = 'en_US')
RETURNS TABLE
(
bp_value text,
bp_name text,
ProductCategory text,
M_Product_ID integer,
value text,
CustomerProductNumber text,
ProductName text,
IsSeasonFixedPrice text,
ItemProductName text,
qtycuspertu numeric,
packingmaterialname text,
pricestd numeric,
altpricestd numeric,
hasaltprice integer,
uomsymbol text,
uom_x12de355 text,
Attributes text,
m_productprice_id integer,
m_attributesetinstance_id integer,
m_hu_pi_item_product_id integer,
currency text,
currency2 text,
validFromPLV1 timestamp,
validFromPLV2 timestamp,
namePLV1 text,
namePLV2 text,
bpl_name text,
AD_Org_ID numeric
)
AS
$$
WITH PriceListVersionsByValidFrom AS
(
SELECT t.*
FROM (SELECT --
plv.c_bpartner_id,
plv.m_pricelist_version_id,
plv.validfrom,
plv.name,
row_number() OVER (PARTITION BY plv.c_bpartner_id ORDER BY plv.validfrom DESC, plv.m_pricelist_version_id DESC) rank
FROM Report.Fresh_PriceList_Version_Val_Rule plv
WHERE TRUE
AND plv.validfrom <= now()
AND plv.issotrx = p_IsSoTrx
AND (p_C_BPartner_ID IS NULL OR plv.c_bpartner_id = p_C_BPartner_ID)
AND (p_C_BP_Group_ID IS NULL OR plv.c_bpartner_id IN (SELECT DISTINCT b.c_bpartner_id FROM c_bpartner b WHERE b.c_bp_group_id = p_C_BP_Group_ID))
ORDER BY TRUE,
plv.validfrom DESC,
plv.m_pricelist_version_id DESC) t
WHERE t.rank <= 2
),
currentAndPreviousPLV AS
(
-- implementation detail: all these sub-selects would be better implemented with a pivot. Unfortunately i cant understand how pivots work.
SELECT DISTINCT --
plvv.c_bpartner_id,
(SELECT plvv2.m_pricelist_version_id FROM PriceListVersionsByValidFrom plvv2 WHERE plvv2.rank = 1 AND plvv2.c_bpartner_id = plvv.c_bpartner_id) PLV1_ID,
(SELECT plvv2.m_pricelist_version_id FROM PriceListVersionsByValidFrom plvv2 WHERE plvv2.rank = 2 AND plvv2.c_bpartner_id = plvv.c_bpartner_id) PLV2_ID,
(SELECT plvv2.validfrom FROM PriceListVersionsByValidFrom plvv2 WHERE plvv2.rank = 1 AND plvv2.c_bpartner_id = plvv.c_bpartner_id) validFromPLV1,
(SELECT plvv2.validfrom FROM PriceListVersionsByValidFrom plvv2 WHERE plvv2.rank = 2 AND plvv2.c_bpartner_id = plvv.c_bpartner_id) validFromPLV2,
(SELECT plvv2.name FROM PriceListVersionsByValidFrom plvv2 WHERE plvv2.rank = 1 AND plvv2.c_bpartner_id = plvv.c_bpartner_id) namePLV1,
(SELECT plvv2.name FROM PriceListVersionsByValidFrom plvv2 WHERE plvv2.rank = 2 AND plvv2.c_bpartner_id = plvv.c_bpartner_id) namePLV2
FROM PriceListVersionsByValidFrom plvv
ORDER BY plvv.c_bpartner_id
),
result AS
(
SELECT t.*,
plv.validFromPLV1,
plv.validFromPLV2,
plv.namePLV1,
plv.namePLV2,
(SELECT bpl.name FROM c_bpartner_location bpl WHERE bpl.c_bpartner_id = plv.c_bpartner_id ORDER BY bpl.isbilltodefault DESC LIMIT 1) bpl_name,
(SELECT plv2.ad_org_id FROM m_pricelist_version plv2 WHERE plv2.m_pricelist_version_id = plv.PLV1_ID) AD_Org_ID
FROM currentAndPreviousPLV plv
INNER JOIN LATERAL report.fresh_PriceList_Details_Report(
plv.c_bpartner_id,
plv.PLV1_ID,
plv.PLV2_ID,
p_AD_Language
) AS t ON TRUE
)
SELECT --
r.bp_value,
r.bp_name,
r.productcategory,
r.m_product_id,
r.value,
r.customerproductnumber,
r.productname,
r.isseasonfixedprice::text,
r.itemproductname,
r.qtycuspertu,
r.packingmaterialname,
r.pricestd,
r.altpricestd,
r.hasaltprice,
r.uomsymbol,
r.uom_x12de355,
r.attributes,
r.m_productprice_id,
r.m_attributesetinstance_id,
r.m_hu_pi_item_product_id,
r.currency::text,
r.currency2::text,
r.validFromPLV1,
r.validFromPLV2,
r.namePLV1,
r.namePLV2,
r.bpl_name,
r.AD_Org_ID
FROM result r
ORDER BY TRUE,
r.bp_value,
r.value
$$
LANGUAGE sql STABLE
;
Original file line number Diff line number Diff line change
Expand Up @@ -6,7 +6,6 @@
<property name="ireport.zoom" value="1.241842646118328"/>
<property name="ireport.x" value="0"/>
<property name="ireport.y" value="0"/>
<property name="com.jaspersoft.studio.data.defaultdataadapter" value="jasperreports\dev.xml"/>
<property name="com.jaspersoft.studio.data.sql.tables" value=""/>
<property name="com.jaspersoft.studio.unit." value="pixel"/>
<property name="com.jaspersoft.studio.unit.pageHeight" value="pixel"/>
Expand All @@ -17,6 +16,7 @@
<property name="com.jaspersoft.studio.unit.rightMargin" value="pixel"/>
<property name="com.jaspersoft.studio.unit.columnWidth" value="pixel"/>
<property name="com.jaspersoft.studio.unit.columnSpacing" value="pixel"/>
<property name="com.jaspersoft.studio.data.defaultdataadapter" value="jasperreports\dev.xml"/>
<import value="net.sf.jasperreports.engine.*"/>
<import value="java.util.*"/>
<import value="net.sf.jasperreports.engine.data.*"/>
Expand Down Expand Up @@ -109,15 +109,15 @@
<field name="nameplv1" class="java.lang.String">
<property name="com.jaspersoft.studio.field.label" value="nameplv1"/>
</field>
<field name="nameplv2" class="java.lang.String">
<property name="com.jaspersoft.studio.field.label" value="nameplv2"/>
</field>
<field name="validfromplv1" class="java.sql.Timestamp">
<property name="com.jaspersoft.studio.field.label" value="validfromplv1"/>
</field>
<field name="validfromplv2" class="java.sql.Timestamp">
<property name="com.jaspersoft.studio.field.label" value="validfromplv2"/>
</field>
<field name="ad_org_id" class="java.math.BigDecimal">
<property name="com.jaspersoft.studio.field.label" value="ad_org_id"/>
</field>
<variable name="LINE_COUNT" class="java.lang.Number" calculation="Count">
<variableExpression><![CDATA[1]]></variableExpression>
<initialValueExpression><![CDATA[0]]></initialValueExpression>
Expand Down Expand Up @@ -325,7 +325,7 @@
<subreport isUsingCache="true">
<reportElement key="subreport-8" x="0" y="100" width="225" height="100" uuid="c5d77fa4-7184-4f47-a49b-955bd96be83c"/>
<subreportParameter name="org_id">
<subreportParameterExpression><![CDATA[new BigDecimal(1000000)]]></subreportParameterExpression>
<subreportParameterExpression><![CDATA[$F{ad_org_id}]]></subreportParameterExpression>
</subreportParameter>
<subreportParameter name="IsSOTrx">
<subreportParameterExpression><![CDATA["Y"]]></subreportParameterExpression>
Expand All @@ -336,15 +336,26 @@
<subreport isUsingCache="true">
<reportElement key="subreport-4" x="0" y="31" width="595" height="85" uuid="45686b08-5564-415f-85da-91f50a1ce8f5"/>
<subreportParameter name="org_id">
<subreportParameterExpression><![CDATA[new BigDecimal(1000000)]]></subreportParameterExpression>
<subreportParameterExpression><![CDATA[$F{ad_org_id}]]></subreportParameterExpression>
</subreportParameter>
<connectionExpression><![CDATA[$P{REPORT_CONNECTION}]]></connectionExpression>
<subreportExpression><![CDATA["de/metas/docs/generics/report_logo.jasper"]]></subreportExpression>
</subreport>
</band>
</title>
<pageHeader>
<band height="116" splitType="Stretch"/>
<band height="116" splitType="Stretch">
<subreport isUsingCache="true">
<reportElement key="subreport-4" x="0" y="0" width="595" height="85" uuid="1c1e4c3b-2d81-4dab-8ba8-ab4ec82a59da">
<printWhenExpression><![CDATA[$V{PAGE_NUMBER} > 1]]></printWhenExpression>
</reportElement>
<subreportParameter name="org_id">
<subreportParameterExpression><![CDATA[$F{ad_org_id}]]></subreportParameterExpression>
</subreportParameter>
<connectionExpression><![CDATA[$P{REPORT_CONNECTION}]]></connectionExpression>
<subreportExpression><![CDATA["de/metas/docs/generics/report_logo.jasper"]]></subreportExpression>
</subreport>
</band>
</pageHeader>
<detail>
<band height="16" splitType="Stretch">
Expand Down Expand Up @@ -472,7 +483,7 @@
</textElement>
<textFieldExpression><![CDATA[$V{PAGE_NUMBER} + "/ "]]></textFieldExpression>
</textField>
<textField evaluationTime="Report" pattern="" isBlankWhenNull="false">
<textField evaluationTime="Master" pattern="" isBlankWhenNull="false">
<reportElement key="textField-64" x="536" y="25" width="15" height="12" forecolor="#000000" backcolor="#FFFFFF" uuid="342602a8-2434-4675-be8b-2350fe69d96a"/>
<box>
<topPen lineWidth="0.0" lineStyle="Solid" lineColor="#000000"/>
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -33,7 +33,8 @@ CREATE OR REPLACE FUNCTION report.Current_Vs_Previous_Pricelist_Comparison_Repor
validFromPLV2 timestamp,
namePLV1 text,
namePLV2 text,
bpl_name text
bpl_name text,
AD_Org_ID numeric
)
AS
$$
Expand Down Expand Up @@ -78,7 +79,8 @@ WITH PriceListVersionsByValidFrom AS
plv.validFromPLV2,
plv.namePLV1,
plv.namePLV2,
(SELECT bpl.name FROM c_bpartner_location bpl WHERE bpl.c_bpartner_id = plv.c_bpartner_id ORDER BY bpl.isbilltodefault DESC LIMIT 1) bpl_name
(SELECT bpl.name FROM c_bpartner_location bpl WHERE bpl.c_bpartner_id = plv.c_bpartner_id ORDER BY bpl.isbilltodefault DESC LIMIT 1) bpl_name,
(SELECT plv2.ad_org_id FROM m_pricelist_version plv2 WHERE plv2.m_pricelist_version_id = plv.PLV1_ID) AD_Org_ID
FROM currentAndPreviousPLV plv
INNER JOIN LATERAL report.fresh_PriceList_Details_Report(
plv.c_bpartner_id,
Expand Down Expand Up @@ -114,7 +116,8 @@ SELECT --
r.validFromPLV2,
r.namePLV1,
r.namePLV2,
r.bpl_name
r.bpl_name,
r.AD_Org_ID
FROM result r
ORDER BY TRUE,
r.bp_value,
Expand Down

0 comments on commit ebaff10

Please sign in to comment.