ReceiptLedgerInfoMapper.xml 14.8 KB
<?xml version="1.0" encoding="UTF-8"?>
<!DOCTYPE mapper PUBLIC "-//mybatis.org//DTD Mapper 3.0//EN" "http://mybatis.org/dtd/mybatis-3-mapper.dtd">
<mapper namespace="com.lframework.xingyun.sc.mappers.ReceiptLedgerInfoMapper">

    <resultMap id="ReceiptLedgerInfo" type="com.lframework.xingyun.sc.entity.ReceiptLedgerInfo">
        <id column="id" property="id"/>
        <result column="type" property="type"/>
        <result column="parent_id" property="parentId"/>
        <result column="customer_short_id" property="customerShortId"/>
        <result column="customer_short_name" property="customerShortName"/>
        <result column="customer_type" property="customerType"/>
        <result column="quota" property="quota"/>
        <result column="settle_term" property="settleTerm"/>
        <result column="dept_id" property="deptId"/>
        <result column="dept_name" property="deptName"/>
        <result column="region" property="region"/>
        <result column="region_name" property="regionName"/>
        <result column="stock_up_company_id" property="stockUpCompanyId"/>
        <result column="stock_up_company_name" property="stockUpCompanyName"/>
        <result column="customer_id" property="customerId"/>
        <result column="customer_name" property="customerName"/>
        <result column="factory_type" property="factoryType"/>
        <result column="shipment_date" property="shipmentDate"/>
        <result column="start_account_receivable" property="startAccountReceivable"/>
        <result column="arrival_date" property="arrivalDate"/>
        <result column="processed_date" property="processedDate"/>
        <result column="actual_returned_date" property="actualReturnedDate"/>
        <result column="returned_amount" property="returnedAmount"/>
        <result column="end_account_receivable" property="endAccountReceivable"/>
        <result column="apply_status" property="applyStatus"/>
        <result column="coordinate_date" property="coordinateDate"/>
        <result column="remark" property="remark"/>
        <result column="second_coordinate_date" property="secondCoordinateDate"/>
        <result column="third_coordinate_date" property="thirdCoordinateDate"/>
        <result column="fourth_coordinate_date" property="fourthCoordinateDate"/>
        <result column="fifth_coordinate_date" property="fifthCoordinateDate"/>
        <result column="description" property="description"/>
        <result column="del_flag" property="delFlag"/>
        <result column="debt_status" property="debtStatus"/>
        <result column="create_by_id" property="createById"/>
        <result column="update_by_id" property="updateById"/>
        <result column="create_time" property="createTime"/>
        <result column="update_time" property="updateTime"/>
    </resultMap>

    <sql id="ReceiptLedgerInfo_sql">
        SELECT
            tb.id,
            tb.type,
            tb.parent_id,
            tb.customer_short_id,
            cs.short_name as customer_short_name,
            cs.type as customer_type,
            tb.quota,
            tb.settle_term,
            tb.dept_id,
            d.name as dept_name,
            tb.region,
            r.name as region_name,
            tb.stock_up_company_id,
            sc.name as stock_up_company_name,
            tb.customer_id,
            oc.name as customer_name,
            tb.factory_type,
            tb.shipment_date,
            tb.start_account_receivable,
            tb.arrival_date,
            tb.processed_date,
            tb.actual_returned_date,
            tb.returned_amount,
            tb.end_account_receivable,
            tb.apply_status,
            tb.coordinate_date,
            tb.remark,
            tb.second_coordinate_date,
            tb.third_coordinate_date,
            tb.fourth_coordinate_date,
            tb.fifth_coordinate_date,
            tb.description,
            tb.del_flag,
            tb.debt_status,
            tb.create_by_id,
            tb.update_by_id,
            tb.create_time,
            tb.update_time
        FROM receipt_ledger_info AS tb
        LEFT JOIN base_data_customer_short cs ON tb.customer_short_id = cs.id
        LEFT JOIN base_data_customer sc ON tb.stock_up_company_id = sc.id
        LEFT JOIN base_data_customer oc ON tb.customer_id = oc.id
        LEFT JOIN sys_dept d ON tb.dept_id = d.id
        LEFT JOIN sys_dept r ON tb.region = r.id
    </sql>

    <select id="query" resultMap="ReceiptLedgerInfo">
        <include refid="ReceiptLedgerInfo_sql"/>
        <where>
            AND tb.del_flag = false
            <if test="vo.id != null and vo.id != ''">
                AND tb.id = #{vo.id}
            </if>
            <if test="vo.type != null and vo.type != ''">
                AND tb.type = #{vo.type}
            </if>
            <if test="vo.factoryType != null and vo.factoryType != ''">
                AND tb.factory_type = #{vo.factoryType}
            </if>
            <if test="vo.customerShortId != null and vo.customerShortId != ''">
                AND tb.customer_short_id = #{vo.customerShortId}
            </if>
            <if test="vo.deptId != null and vo.deptId != ''">
                AND tb.dept_id = #{vo.deptId}
            </if>
            <if test="vo.customerId != null and vo.customerId != ''">
                AND tb.customer_id = #{vo.customerId}
            </if>
            <if test="vo.createTimeStart != null and vo.createTimeStart != ''">
                AND tb.create_time >= #{vo.createTimeStart}
            </if>
            <if test="vo.createTimeEnd != null and vo.createTimeEnd != ''">
                AND tb.create_time &lt;= #{vo.createTimeEnd}
            </if>
            <if test="vo.customerName != null and vo.customerName != ''">
                AND oc.name LIKE CONCAT('%', #{vo.customerName}, '%')
            </if>
            <if test="vo.customerShortName != null and vo.customerShortName != ''">
                AND cs.short_name LIKE CONCAT('%', #{vo.customerShortName}, '%')
            </if>
            <if test="vo.deptName != null and vo.deptName != ''">
                AND d.name LIKE CONCAT('%', #{vo.deptName}, '%')
            </if>
            <if test="vo.debtStatus != null and vo.debtStatus != ''">
                AND tb.debt_status = #{vo.debtStatus}
            </if>
        </where>
        ORDER BY
        CASE
            WHEN d.name like '宁波办%' THEN 1
            WHEN d.name like '温州办%' THEN 2
            WHEN d.name like '东莞办%' THEN 3
            WHEN d.name like '佛山办%' THEN 4
            WHEN d.name like '苏州办%' THEN 5
            WHEN d.name like '常州办%' THEN 6
            WHEN d.name like '北方办%' THEN 7
            WHEN d.name like '紫铜办%' THEN 8
            WHEN d.name like '外贸办%' THEN 9
        ELSE 10  -- 其他办事处按字母顺序排在后面
        END,
        d.name ASC,
        CASE WHEN r.name IS NULL THEN 1 ELSE 0 END,
        r.name ASC,
        CASE WHEN cs.short_name IS NULL THEN 1 ELSE 0 END,
        cs.short_name ASC,
        CASE WHEN oc.name IS NULL THEN 1 ELSE 0 END,
        oc.name ASC,
        CASE WHEN tb.shipment_date IS NULL THEN 1 ELSE 0 END,
        tb.shipment_date ASC
    </select>

    <select id="queryByCustomerShortName" resultMap="ReceiptLedgerInfo">
        <include refid="ReceiptLedgerInfo_sql"/>
        <where>
            AND tb.del_flag = false
            AND tb.end_account_receivable >0
            <if test="customerShortName != null and customerShortName != ''">
                AND cs.short_name = #{customerShortName}
            </if>
        </where>
    </select>

    <insert id="batchAdd">
        INSERT INTO receipt_ledger_info (
        id,
        type,
        parent_id,
        customer_short_id,
        quota,
        settle_term,
        dept_id,
        region,
        stock_up_company_id,
        customer_id,
        factory_type,
        shipment_date,
        start_account_receivable,
        arrival_date,
        processed_date,
        actual_returned_date,
        returned_amount,
        end_account_receivable,
        apply_status,
        debt_status,
        coordinate_date,
        remark,
        second_coordinate_date,
        third_coordinate_date,
        fourth_coordinate_date,
        fifth_coordinate_date,
        description,
        shipment_order_id,
        create_by_id,
        update_by_id,
        create_time,
        update_time
        ) VALUES
        <foreach collection="list" item="item" separator=",">
            (
            #{item.id},
            #{item.type},
            #{item.parentId},
            #{item.customerShortId},
            #{item.quota},
            #{item.settleTerm},
            #{item.deptId},
            #{item.region},
            #{item.stockUpCompanyId},
            #{item.customerId},
            #{item.factoryType},
            #{item.shipmentDate},
            #{item.startAccountReceivable},
            #{item.arrivalDate},
            #{item.processedDate},
            #{item.actualReturnedDate},
            #{item.returnedAmount},
            #{item.endAccountReceivable},
            #{item.applyStatus},
            #{item.debtStatus},
            #{item.coordinateDate},
            #{item.remark},
            #{item.secondCoordinateDate},
            #{item.thirdCoordinateDate},
            #{item.fourthCoordinateDate},
            #{item.fifthCoordinateDate},
            #{item.description},
            #{item.shipmentOrderId},
            #{item.createById},
            #{item.updateById},
            #{item.createTime},
            #{item.updateTime}
            )
        </foreach>
    </insert>

    <select id="report" resultType="com.lframework.xingyun.sc.bo.ledger.receipt.ReceiptLedgerReportBo">
        select tb.short_name as customer_short_name,
               case
               when tb.type = 'DEALER' then '经销商'
               when tb.type = 'TERMINAL' then '终端'
               when tb.type = 'FOREIGN' then '外贸'
               else tb.type
               end as customer_type,
               tb.dept_id,
               d.name as dept_name,
               tb.region,
               r.name as region_name,
               max(cc.company_credit_limit) as quota,
               max(cc.company_settlement_period) as settle_term,
               sum(distinct rl.end_account_receivable) as end_account_total
        from base_data_customer_short tb
        left join sys_dept d on tb.dept_id = d.id
        left join sys_dept r on tb.region = r.id
        left join customer_credit cc on tb.customer_id = cc.company_id
        left join receipt_ledger_info rl on tb.id = rl.customer_short_id and rl.del_flag = false
        <where>
            and rl.type = 'INSIDE'
            -- 只统计当月数据
            and rl.create_time >= #{vo.startTime} and rl.create_time &lt;= #{vo.endTime}
            <if test="vo.customerType != null and vo.customerType != ''">
                and tb.type = #{vo.customerType}
            </if>
            <if test="vo.debtStatus != null and vo.debtStatus != ''">
                and rl.debt_status = #{vo.debtStatus}
            </if>
            <if test="vo.deptName != null and vo.deptName != ''">
                and d.name like concat('%', #{vo.deptName}, '%')
            </if>
        </where>
        group by tb.short_name,tb.type,tb.dept_id,tb.region
        having 1=1
        <if test="vo.debtStartValue != null">
            and sum(distinct rl.end_account_receivable) >= #{vo.debtStartValue}
        </if>
        <if test="vo.debtEndValue != null">
            and sum(distinct rl.end_account_receivable) &lt;= #{vo.debtEndValue}
        </if>
        order by
        case
            when d.name like '宁波办%' then 1
            when d.name like '温州办%' then 2
            when d.name like '东莞办%' then 3
            when d.name like '佛山办%' then 4
            when d.name like '苏州办%' then 5
            when d.name like '常州办%' then 6
            when d.name like '北方办%' then 7
            when d.name like '紫铜办%' then 8
            when d.name like '外贸办%' then 9
        else 10  -- 其他办事处按字母顺序排在后面
        end,
        d.name asc,
        case when r.name is null then 1 else 0 end,
        r.name asc,
        sum(distinct rl.end_account_receivable) desc
    </select>

    <select id="statisticsDebtByShortName" resultType="java.util.Map">
        select c.name,
               cs.short_name,
               tb.debt_status,
               sum(tb.end_account_receivable) as debt_amount
        from receipt_ledger_info tb
        inner join base_data_customer_short cs on tb.customer_id = cs.customer_id
        inner join base_data_customer c on tb.customer_id = c.id
        <where>
            and tb.del_flag = false
            -- 只统计当月数据
            and tb.create_time >= #{startTime} and tb.create_time &lt;= #{endTime}
            <if test="type != null and type != ''">
                and tb.type = #{type}
            </if>
            and cs.short_name in
            <foreach collection="shortNames" open="(" separator="," close=")" item="item">
                #{item}
            </foreach>
            <if test="debtStatusList != null and debtStatusList.size() > 0">
                and tb.debt_status in
                <foreach collection="debtStatusList" open="(" separator="," close=")" item="item">
                    #{item}
                </foreach>
            </if>
        </where>
        group by c.name,cs.short_name,tb.debt_status
    </select>

    <select id="queryByShortName" resultType="com.lframework.xingyun.sc.entity.ReceiptLedgerInfo">
        select tb.*,
               cs.short_name as customer_short_name
        from receipt_ledger_info tb
        left join base_data_customer_short cs on tb.customer_id = cs.customer_id
        <where>
            and tb.del_flag = false
            <if test="type != null and type != ''">
                and tb.type = #{type}
            </if>
            <if test="shortNames != null and shortNames.size() > 0">
                and cs.short_name in
                <foreach collection="shortNames" open="(" separator="," close=")" item="item">
                    #{item}
                </foreach>
            </if>
            <if test="overdue != null">
                <choose>
                    <when test="overdue == true">
                        and tb.processed_date &lt; curdate()
                        order by tb.processed_date desc,tb.start_account_receivable asc
                    </when>
                    <otherwise>
                        and (tb.processed_date >= curdate() or tb.end_account_receivable &lt; 0)
                        order by
                            case when tb.processed_date is null then 1 else 0 end,
                            tb.processed_date,
                            tb.start_account_receivable
                    </otherwise>
                </choose>
            </if>
        </where>
    </select>
</mapper>