242 lines
8.6 KiB
SQL
242 lines
8.6 KiB
SQL
-- zoneGetAgency-----------------------------------------------------------------------
|
|
|
|
USE `vn`;
|
|
DROP procedure IF EXISTS `zoneGetAgency`;
|
|
|
|
DELIMITER $$
|
|
USE `vn`$$
|
|
CREATE DEFINER=`root`@`%` PROCEDURE `zoneGetAgency`(vAddress INT, vLanded DATE)
|
|
BEGIN
|
|
/**
|
|
* Devuelve el listado de agencias disponibles para la fecha
|
|
* y dirección pasadas.
|
|
*
|
|
* @param vAddress Id de dirección de envío, %NULL si es recogida
|
|
* @param vDate Fecha de recogida
|
|
* @select Listado de agencias disponibles
|
|
*/
|
|
|
|
DECLARE vPostalCode varchar(10);
|
|
|
|
SELECT postalCode INTO vPostalCode
|
|
FROM address WHERE id = vAddress;
|
|
|
|
SELECT * FROM (
|
|
SELECT am.id agencyModeFk,
|
|
am.name agencyMode,
|
|
am.description,
|
|
am.deliveryMethodFk,
|
|
TIMESTAMPADD(DAY,-z.travelingDays, vLanded) shipped,
|
|
zi.isIncluded
|
|
FROM zoneGeo zgSon
|
|
JOIN zoneGeo zgFather ON zgSon.lft BETWEEN zgFather.lft AND zgFather.rgt
|
|
JOIN zoneIncluded zi ON zi.geoFk = zgFather.id
|
|
JOIN zone z ON z.id = zi.zoneFk
|
|
JOIN zoneCalendar zc ON zc.zoneFk = z.id
|
|
JOIN agencyMode am ON am.id = z.agencyModeFk
|
|
WHERE zgSon.`name` LIKE vPostalCode
|
|
AND zc.delivered = vLanded
|
|
AND IF(TIMESTAMPADD(DAY,-z.travelingDays, vLanded) = CURDATE(), hour(now()) < hour(z.`hour`),TRUE)
|
|
ORDER BY zgFather.depth DESC) t
|
|
GROUP BY agencyModeFk
|
|
HAVING isIncluded > 0;
|
|
|
|
END$$
|
|
|
|
DELIMITER ;
|
|
-- zoneGetFirstShipped-----------------------------------------------------------------------
|
|
|
|
|
|
USE `vn`;
|
|
DROP procedure IF EXISTS `zoneGetFirstShipped`;
|
|
|
|
DELIMITER $$
|
|
USE `vn`$$
|
|
CREATE DEFINER=`root`@`%` PROCEDURE `zoneGetFirstShipped`(vAgencyModeFk INT, vAddress INT, vWarehouseFk INT)
|
|
BEGIN
|
|
/**
|
|
* Devuelve la primera fecha de envio disponible para una agencia en una direccion y un warehouse
|
|
*
|
|
* @param vAgencyMode id de la agencia en vn.agencyMode
|
|
* @param vAddress id de la direccion
|
|
* @param vWarehouse id del warehouse
|
|
* @return vShipped la primera fecha disponible y vLanded la fecha de llegada/recojida
|
|
*/
|
|
DECLARE vPostalCode varchar(10);
|
|
|
|
SELECT postalCode INTO vPostalCode
|
|
FROM address WHERE id = vAddress;
|
|
|
|
SELECT * FROM (
|
|
SELECT TIMESTAMPADD(DAY,-z.travelingDays, zc.delivered) shipped,
|
|
zc.delivered landed
|
|
FROM zoneGeo zgSon
|
|
JOIN zoneGeo zgFather ON zgSon.lft BETWEEN zgFather.lft AND zgFather.rgt
|
|
JOIN zoneIncluded zi ON zi.geoFk = zgFather.id
|
|
JOIN zone z ON z.id = zi.zoneFk
|
|
JOIN zoneCalendar zc ON zc.zoneFk = z.id
|
|
WHERE zgSon.`name` LIKE vPostalCode
|
|
AND z.agencyModeFk = vAgencyModeFk
|
|
AND z.warehouseFk = vWarehouseFk
|
|
AND IF(TIMESTAMPADD(DAY,-z.travelingDays, zc.delivered) = CURDATE(), hour(now()) < hour(z.`hour`),TRUE)
|
|
ORDER BY landed ASC, zgFather.depth DESC) t
|
|
HAVING isIncluded > 0 LIMIT 1;
|
|
END$$
|
|
|
|
DELIMITER ;
|
|
-- zoneGetLanded-----------------------------------------------------------------------
|
|
|
|
|
|
USE `vn`;
|
|
DROP procedure IF EXISTS `zoneGetLanded`;
|
|
|
|
DELIMITER $$
|
|
USE `vn`$$
|
|
CREATE DEFINER=`root`@`%` PROCEDURE `zoneGetLanded`(vShipped DATE, vAddress INT, vAgencyMode INT, vWarehouse INT)
|
|
BEGIN
|
|
/**
|
|
* Devuelve una tabla temporal con el dia de recepcion para vShipped.
|
|
*
|
|
* @param vShipped Fecha de preparacion de mercancia
|
|
* @param vAddress Id de consignatario, %NULL para recogida
|
|
* @param vAgencyMode Id agencia
|
|
* @table tmp.zoneGetLanded Datos de recepción
|
|
*/
|
|
|
|
DECLARE vPostalCode varchar(10);
|
|
|
|
SELECT postalCode INTO vPostalCode
|
|
FROM address WHERE id = vAddress;
|
|
|
|
DROP TEMPORARY TABLE IF EXISTS tmp.zoneGetLanded;
|
|
CREATE TEMPORARY TABLE tmp.zoneGetLanded
|
|
ENGINE = MEMORY
|
|
SELECT vWarehouse warehouseFk,delivered landed, isIncluded FROM (
|
|
SELECT zi.*, zc.delivered
|
|
FROM vn.zoneGeo zgSon
|
|
JOIN vn.zoneGeo zgFather ON zgSon.lft BETWEEN zgFather.lft AND zgFather.rgt
|
|
JOIN zoneIncluded zi ON zi.geoFk = zgFather.id
|
|
JOIN zone z ON z.id = zi.zoneFk
|
|
JOIN zoneCalendar zc ON zc.zoneFk = z.id
|
|
WHERE zgSon.`name` LIKE vPostalCode
|
|
AND zc.delivered = TIMESTAMPADD(DAY,z.travelingDays, vShipped)
|
|
AND IF(vShipped = CURDATE(), hour(now()) < hour(z.`hour`),TRUE)
|
|
AND z.agencyModeFk = vAgencyMode
|
|
ORDER BY zgFather.depth DESC) t
|
|
GROUP BY zoneFk
|
|
HAVING isIncluded > 0
|
|
LIMIT 1;
|
|
END$$
|
|
|
|
DELIMITER ;
|
|
-- zoneGetShipped-----------------------------------------------------------------------
|
|
|
|
|
|
USE `vn`;
|
|
DROP procedure IF EXISTS `zoneGetShipped`;
|
|
|
|
DELIMITER $$
|
|
USE `vn`$$
|
|
DROP procedure IF EXISTS `zoneGetShipped`;
|
|
|
|
CREATE DEFINER=`root`@`%` PROCEDURE `zoneGetShipped`(vLanded DATE, vAddressFk INT, vAgencyModeFk INT, vWarehouseFk INT)
|
|
BEGIN
|
|
/**
|
|
* Devuelve la mínima fecha de envía para cada warehouse
|
|
*
|
|
* @param vLanded La fecha de recepcion
|
|
* @param vAddressFk Id del consignatario
|
|
* @param vAgencyModeFk Id de la agencia
|
|
* @return tmp.zoneGetShipped
|
|
*/
|
|
|
|
DECLARE vPostalCode varchar(10);
|
|
|
|
SELECT postalCode INTO vPostalCode
|
|
FROM address WHERE id = vAddressFk;
|
|
|
|
SELECT * FROM (
|
|
SELECT z.id,
|
|
TIMESTAMPADD(DAY,-z.travelingDays, vLanded) shipped,
|
|
vLanded landed,
|
|
zi.isIncluded
|
|
FROM zoneGeo zgSon
|
|
JOIN zoneGeo zgFather ON zgSon.lft BETWEEN zgFather.lft AND zgFather.rgt
|
|
JOIN zoneIncluded zi ON zi.geoFk = zgFather.id
|
|
JOIN zone z ON z.id = zi.zoneFk
|
|
JOIN zoneCalendar zc ON zc.zoneFk = z.id
|
|
WHERE zgSon.`name` LIKE vPostalCode
|
|
AND zc.delivered = vLanded
|
|
AND z.agencyModeFk = vAgencyModeFk
|
|
AND z.warehouseFk = vWarehouseFk
|
|
AND IF(TIMESTAMPADD(DAY,-z.travelingDays, vLanded) = CURDATE(), hour(now()) < hour(z.`hour`),TRUE)
|
|
ORDER BY z.id, landed ASC, zgFather.depth DESC) t
|
|
GROUP BY id
|
|
HAVING isIncluded > 0;
|
|
END$$
|
|
|
|
DELIMITER ;
|
|
|
|
-- zoneGetWarehouse-----------------------------------------------------------------------
|
|
|
|
USE `vn`;
|
|
DROP procedure IF EXISTS `zoneGetWarehouse`;
|
|
|
|
DELIMITER $$
|
|
USE `vn`$$
|
|
CREATE DEFINER=`root`@`%` PROCEDURE `zoneGetWarehouse`(vAddress INT, vLanded DATE, vWarehouse INT)
|
|
BEGIN
|
|
/**
|
|
* Devuelve el listado de agencias disponibles para la fecha,
|
|
* dirección y warehouse pasadas
|
|
*
|
|
* @param vAddress
|
|
* @param vWarehouse warehouse
|
|
* @param vLanded Fecha de recogida
|
|
* @select Listado de agencias disponibles
|
|
*/
|
|
DECLARE vPostalCode varchar(10);
|
|
|
|
SELECT postalCode INTO vPostalCode
|
|
FROM address WHERE id = vAddress;
|
|
|
|
SELECT * FROM (
|
|
SELECT am.id,
|
|
am.name agencyMode,
|
|
am.description,
|
|
am.deliveryMethodFk,
|
|
TIMESTAMPADD(DAY,-z.travelingDays, vLanded) shipped,
|
|
z.warehouseFk,
|
|
zi.isIncluded
|
|
FROM zoneGeo zgSon
|
|
JOIN zoneGeo zgFather ON zgSon.lft BETWEEN zgFather.lft AND zgFather.rgt
|
|
JOIN zoneIncluded zi ON zi.geoFk = zgFather.id
|
|
JOIN zone z ON z.id = zi.zoneFk
|
|
JOIN zoneCalendar zc ON zc.zoneFk = z.id
|
|
JOIN agencyMode am ON am.id = z.agencyModeFk
|
|
WHERE zgSon.`name` LIKE vPostalCode
|
|
AND delivered = vLanded
|
|
AND z.warehouseFk = vWarehouse
|
|
AND IF(TIMESTAMPADD(DAY,-z.travelingDays, vLanded) = CURDATE(), hour(now()) < hour(z.`hour`),TRUE)
|
|
ORDER BY zgFather.depth DESC) t
|
|
GROUP BY id
|
|
HAVING isIncluded > 0;
|
|
|
|
END$$
|
|
DELIMITER ;
|
|
|
|
-- VIEW `vn`.`item`-----------------------------------------------------------------------
|
|
|
|
CREATE OR REPLACE ALGORITHM=UNDEFINED DEFINER=`root`@`%` SQL SECURITY DEFINER VIEW `vn`.`item` AS select `t`.`Id_Article` AS `id`,`t`.`Article` AS `name`,`t`.`tipo_id` AS `typeFk`,`t`.`Medida` AS `size`,`t`.`Color` AS `inkFk`,`t`.`Categoria` AS `category`,`t`.`Tallos` AS `stems`,`t`.`id_origen` AS `originFk`,`t`.`description` AS `description`,`t`.`producer_id` AS `producerFk`,`t`.`Codintrastat` AS `intrastatFk`,`t`.`offer` AS `isOnOffer`,`t`.`caja` AS `box`,`t`.`expenceFk` AS `expenceFk`,`t`.`bargain` AS `isBargain`,`t`.`comments` AS `comment`,`t`.`relevancy` AS `relevancy`,`t`.`Foto` AS `image`,`t`.`generic` AS `generic`,`t`.`density` AS `density`,`t`.`iva_group_id` AS `taxClassFk`,`t`.`PVP` AS `minPrice`,`t`.`Min` AS `hasMinPrice`,`t`.`isActive` AS `isActive`,`t`.`longName` AS `longName`,`t`.`subName` AS `subName`,`t`.`tag5` AS `tag5`,`t`.`value5` AS `value5`,`t`.`tag6` AS `tag6`,`t`.`value6` AS `value6`,`t`.`tag7` AS `tag7`,`t`.`value7` AS `value7`,`t`.`tag8` AS `tag8`,`t`.`value8` AS `value8`,`t`.`tag9` AS `tag9`,`t`.`value9` AS `value9`,`t`.`tag10` AS `tag10`,`t`.`value10` AS `value10`,`t`.`minimum` AS `minimum`,`t`.`upToDown` AS `upToDown`,`t`.`compression` AS `compression` from `vn2008`.`Articles` `t`;
|
|
|
|
-- TABLE `vn`.`zone`-----------------------------------------------------------------------
|
|
|
|
ALTER TABLE `vn`.`zone`
|
|
ADD COLUMN `isVolumetric` TINYINT(1) NULL DEFAULT 0 AFTER `bonus`;
|
|
|
|
-- TABLE `vn`.`zone`-----------------------------------------------------------------------
|
|
|
|
ALTER TABLE `vn`.`zoneGeo`
|
|
ADD PRIMARY KEY (`id`);
|
|
;
|