refs #6493 refactorizar-procedimientos-vn2008-parte_2 #2235
|
@ -1,9 +1,16 @@
|
|||
DELIMITER $$
|
||||
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn2008`.`availableTraslate`(
|
||||
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`available_traslate`(
|
||||
vWarehouseLanding INT,
|
||||
vDated DATE,
|
||||
vWarehouseShipment INT)
|
||||
proc: BEGIN
|
||||
/**
|
||||
* Calcular la disponibilidad dependiendo del almacen de origen y destino según la fecha
|
||||
jbreso marked this conversation as resolved
Outdated
|
||||
*
|
||||
* @param vWarehouseLanding almacén de llegada.
|
||||
jbreso marked this conversation as resolved
guillermo
commented
Falta poner un espacio entre vWarehouse y Landing. Además de que cuando se ponen los params, ninguna descripción del param debe de tener punto (viendo otros procs se puede comprobar) Falta poner un espacio entre vWarehouse y Landing.
Además de que cuando se ponen los params, ninguna descripción del param debe de tener punto (viendo otros procs se puede comprobar)
jbreso
commented
vWarehouseLanding no se porque quieres el espacio la variable se llama asi, si pongo el espacio en esa también tendía que ponerlo en vWarehouseShipment? vWarehouseLanding no se porque quieres el espacio la variable se llama asi, si pongo el espacio en esa también tendía que ponerlo en vWarehouseShipment?
guillermo
commented
Vale no sorry, queria decir que la primera letra del comentario de la variable debe de estár en mayuscula, así en todos los del PR Vale no sorry, queria decir que la primera letra del comentario de la variable debe de estár en mayuscula, así en todos los del PR
|
||||
* @param vDated la fecha para la cual se está calculando la disponibilidad de articulos.
|
||||
jbreso marked this conversation as resolved
Outdated
guillermo
commented
Aquí hay doble espacio, y sobrepasa los carácteres máximos, acortar Aquí hay doble espacio, y sobrepasa los carácteres máximos, acortar
guillermo
commented
lA primera letra del comentario de la variable debe de estar en mayúscula, así en todos los del PR lA primera letra del comentario de la variable debe de estar en mayúscula, así en todos los del PR
|
||||
* @param vWarehouseShipment almacén de destino.
|
||||
*/
|
||||
DECLARE vDatedFrom DATE;
|
||||
DECLARE vDatedTo DATETIME;
|
||||
DECLARE vDatedReserve DATETIME;
|
||||
|
@ -13,7 +20,8 @@ proc: BEGIN
|
|||
LEAVE proc;
|
||||
END IF;
|
||||
|
||||
CALL vn.item_getStock (vWarehouseLanding, vDated, NULL);
|
||||
CALL item_getStock (vWarehouseLanding, vDated, NULL);
|
||||
|
||||
jbreso marked this conversation as resolved
carlosap
commented
Salto de línea innecesario Salto de línea innecesario
|
||||
|
||||
-- Calcula algunos parámetros necesarios
|
||||
SET vDatedFrom = TIMESTAMP(vDated, '00:00:00');
|
||||
|
@ -23,15 +31,14 @@ proc: BEGIN
|
|||
FROM hedera.orderConfig;
|
||||
|
||||
-- Calcula el ultimo dia de vida para cada producto
|
||||
DROP TEMPORARY TABLE IF EXISTS itemRange;
|
||||
CREATE TEMPORARY TABLE itemRange
|
||||
CREATE OR REPLACE TEMPORARY TABLE tItemRange
|
||||
(PRIMARY KEY (itemFk))
|
||||
ENGINE = MEMORY
|
||||
SELECT c.itemFk, MAX(t.landed) dated
|
||||
FROM vn.buy c
|
||||
JOIN vn.entry e ON c.entryFk = e.id
|
||||
JOIN vn.travel t ON t.id = e.travelFk
|
||||
JOIN vn.warehouse w ON w.id = t.warehouseInFk
|
||||
FROM buy c
|
||||
JOIN entry e ON c.entryFk = e.id
|
||||
JOIN travel t ON t.id = e.travelFk
|
||||
JOIN warehouse w ON w.id = t.warehouseInFk
|
||||
WHERE t.landed BETWEEN vDatedInventory AND vDatedFrom
|
||||
AND t.warehouseInFk = vWarehouseLanding
|
||||
AND NOT e.isExcludedFromAvailable
|
||||
|
@ -39,46 +46,44 @@ proc: BEGIN
|
|||
GROUP BY c.itemFk;
|
||||
|
||||
jbreso marked this conversation as resolved
guillermo
commented
Sobrepasa los carácteres máximos x linea Sobrepasa los carácteres máximos x linea
|
||||
-- Tabla con el ultimo dia de last_buy para cada producto que hace un replace de la anterior
|
||||
CALL vn.buyUltimate(vWarehouseShipment, util.VN_CURDATE());
|
||||
CALL buyUltimate(vWarehouseShipment, util.VN_CURDATE());
|
||||
|
||||
INSERT INTO itemRange
|
||||
INSERT INTO tItemRange
|
||||
SELECT t.itemFk, tr.landed
|
||||
FROM tmp.buyUltimate t
|
||||
JOIN vn.buy b ON b.id = t.buyFk
|
||||
JOIN vn.entry e ON e.id = b.entryFk
|
||||
JOIN vn.travel tr ON tr.id = e.travelFk
|
||||
LEFT JOIN itemRange i ON t.itemFk = i.itemFk
|
||||
JOIN buy b ON b.id = t.buyFk
|
||||
JOIN entry e ON e.id = b.entryFk
|
||||
JOIN travel tr ON tr.id = e.travelFk
|
||||
LEFT JOIN tItemRange i ON t.itemFk = i.itemFk
|
||||
WHERE t.warehouseFk = vWarehouseShipment
|
||||
AND NOT e.isRaid
|
||||
jbreso marked this conversation as resolved
guillermo
commented
Sobrepasa los carácteres máximos x linea Sobrepasa los carácteres máximos x linea
|
||||
ON DUPLICATE KEY UPDATE itemRange.dated = GREATEST(itemRange.dated, tr.landed);
|
||||
ON DUPLICATE KEY UPDATE tItemRange.dated = GREATEST(tItemRange.dated, tr.landed);
|
||||
|
||||
DROP TEMPORARY TABLE IF EXISTS itemRangeLive;
|
||||
CREATE TEMPORARY TABLE itemRangeLive
|
||||
CREATE OR REPLACE TEMPORARY TABLE tItemRangeLive
|
||||
(PRIMARY KEY (itemFk))
|
||||
ENGINE = MEMORY
|
||||
jbreso marked this conversation as resolved
Outdated
carlosap
commented
No utilizar hacer uso de TIMESTAMP(ir.dated + INTERVAL it.life DAY, '23:59:59') , tenemos una función que hace eso util.dayEnd No utilizar hacer uso de TIMESTAMP(ir.dated + INTERVAL it.life DAY, '23:59:59') , tenemos una función que hace eso util.dayEnd
|
||||
SELECT ir.itemFk, TIMESTAMP(TIMESTAMPADD(DAY, it.life, ir.dated), '23:59:59') dated
|
||||
jbreso marked this conversation as resolved
carlosap
commented
TIMESTAMPADD substituir por INTERVAL TIMESTAMPADD substituir por INTERVAL
|
||||
FROM itemRange ir
|
||||
JOIN vn.item i ON i.id = ir.itemFk
|
||||
JOIN vn.itemType it ON it.id = i.typeFk
|
||||
FROM tItemRange ir
|
||||
JOIN item i ON i.id = ir.itemFk
|
||||
JOIN itemType it ON it.id = i.typeFk
|
||||
HAVING dated >= vDatedFrom OR dated IS NULL;
|
||||
|
||||
-- Calcula el ATP
|
||||
DROP TEMPORARY TABLE IF EXISTS tmp.itemCalc;
|
||||
CREATE TEMPORARY TABLE tmp.itemCalc
|
||||
CREATE OR REPLACE TEMPORARY TABLE tmp.itemCalc
|
||||
(INDEX (itemFk,warehouseFk))
|
||||
ENGINE = MEMORY
|
||||
jbreso marked this conversation as resolved
Outdated
guillermo
commented
Sobrepasa los carácteres máximos x linea, tabular Sobrepasa los carácteres máximos x linea, tabular
|
||||
SELECT i.itemFk, vWarehouseLanding warehouseFk, i.shipped dated, i.quantity
|
||||
FROM vn.itemTicketOut i
|
||||
jbreso marked this conversation as resolved
Outdated
carlosap
commented
eliminar esquema vn, no es necesario eliminar esquema vn, no es necesario
|
||||
JOIN itemRangeLive ir ON ir.itemFK = i.itemFk
|
||||
JOIN tItemRangeLive ir ON ir.itemFK = i.item_id
|
||||
jbreso marked this conversation as resolved
Outdated
carlosap
commented
porque se ha cambiado a item_id? porque se ha cambiado a item_id?
|
||||
WHERE i.shipped >= vDatedFrom
|
||||
jbreso marked this conversation as resolved
Outdated
guillermo
commented
Tab Tab
|
||||
AND (ir.dated IS NULL OR i.shipped <= ir.dated)
|
||||
AND i.warehouseFk = vWarehouseLanding
|
||||
UNION ALL
|
||||
SELECT b.itemFk, vWarehouseLanding, t.landed, b.quantity
|
||||
FROM vn.buy b
|
||||
JOIN vn.entry e ON b.entryFk = e.id
|
||||
JOIN vn.travel t ON t.id = e.travelFk
|
||||
JOIN itemRangeLive ir ON ir.itemFk = b.itemFk
|
||||
FROM buy b
|
||||
JOIN entry e ON b.entryFk = e.id
|
||||
JOIN travel t ON t.id = e.travelFk
|
||||
JOIN tItemRangeLive ir ON ir.itemFk = b.itemFk
|
||||
WHERE NOT e.isExcludedFromAvailable
|
||||
AND b.quantity <> 0
|
||||
jbreso marked this conversation as resolved
Outdated
guillermo
commented
Tab Tab
|
||||
AND NOT e.isRaid
|
||||
|
@ -88,7 +93,7 @@ proc: BEGIN
|
|||
UNION ALL
|
||||
SELECT i.itemFk, vWarehouseLanding, i.shipped, i.quantity
|
||||
FROM vn.itemEntryOut i
|
||||
jbreso marked this conversation as resolved
Outdated
carlosap
commented
eliminar esquema innecesario eliminar esquema innecesario
|
||||
JOIN itemRangeLive ir ON ir.itemFk = i.itemFk
|
||||
JOIN tItemRangeLive ir ON ir.itemFk = i.itemFk
|
||||
WHERE i.shipped >= vDatedFrom
|
||||
AND (ir.dated IS NULL OR i.shipped <= ir.dated)
|
||||
AND i.warehouseOutFk = vWarehouseLanding
|
||||
|
@ -96,24 +101,23 @@ proc: BEGIN
|
|||
SELECT r.item_id, vWarehouseLanding, r.shipment, -r.amount
|
||||
FROM hedera.order_row r
|
||||
JOIN hedera.`order` o ON o.id = r.order_id
|
||||
JOIN itemRangeLive ir ON ir.itemFk = r.item_id
|
||||
JOIN tItemRangeLive ir ON ir.itemFk = r.item_id
|
||||
WHERE r.shipment >= vDatedFrom
|
||||
AND (ir.dated IS NULL OR r.shipment <= ir.dated)
|
||||
AND r.warehouse_id = vWarehouseLanding
|
||||
AND r.created >= vDatedReserve
|
||||
AND NOT o.confirmed;
|
||||
|
||||
CALL vn.item_getAtp(vDated);
|
||||
CALL item_getAtp(vDated);
|
||||
|
||||
DROP TEMPORARY TABLE IF EXISTS availableTraslate;
|
||||
CREATE TEMPORARY TABLE availableTraslate
|
||||
CREATE OR REPLACE TEMPORARY TABLE tmp.availableTraslate
|
||||
(PRIMARY KEY (item_id))
|
||||
ENGINE = MEMORY
|
||||
SELECT t.item_id, SUM(stock) available
|
||||
FROM (
|
||||
SELECT ti.itemFk item_id, stock
|
||||
FROM tmp.itemList ti
|
||||
JOIN itemRange ir ON ir.itemFk = ti.itemFk
|
||||
JOIN tItemRange ir ON ir.itemFk = ti.itemFk
|
||||
UNION ALL
|
||||
SELECT itemFk, quantity
|
||||
FROM tmp.itemAtp
|
||||
|
@ -121,6 +125,6 @@ proc: BEGIN
|
|||
GROUP BY t.item_id
|
||||
HAVING available <> 0;
|
||||
|
||||
DROP TEMPORARY TABLE tmp.itemList, itemRange, itemRangeLive;
|
||||
DROP TEMPORARY TABLE tmp.itemList, tItemRange, tItemRangeLive;
|
||||
END$$
|
||||
DELIMITER ;
|
||||
DELIMITER ;
|
|
@ -1,11 +1,20 @@
|
|||
DELIMITER $$
|
||||
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn2008`.`balance_create`(
|
||||
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`balance_create`(
|
||||
IN vStartingMonth INT,
|
||||
IN vEndingMonth INT,
|
||||
IN vCompany INT,
|
||||
IN vIsConsolidated BOOLEAN,
|
||||
IN vInterGroupSalesIncluded BOOLEAN)
|
||||
BEGIN
|
||||
/**
|
||||
* Crea un balance financiero para una empresa durante un período de tiempo determinado
|
||||
jbreso marked this conversation as resolved
Outdated
guillermo
commented
Sobrepasa los carácteres máximos x linea, a parte que al final va un punto Sobrepasa los carácteres máximos x linea, a parte que al final va un punto
|
||||
*
|
||||
* @param vStartingMonth Mes de inicio del período
|
||||
* @param vEndingMonth Mes de finalización del período
|
||||
* @param vCompany Identificador de la empresa
|
||||
* @param vIsConsolidated Indica si se trata de un balance consolidado
|
||||
* @param vInterGroupSalesIncluded Indica si se incluyen las ventas dentro del grupo
|
||||
jbreso marked this conversation as resolved
guillermo
commented
Sobrepasa los caracteres máximos, acortar Sobrepasa los caracteres máximos, acortar
|
||||
*/
|
||||
DECLARE intGAP INT DEFAULT 7;
|
||||
DECLARE vYears INT DEFAULT 2;
|
||||
DECLARE vYear TEXT;
|
||||
|
@ -18,7 +27,7 @@ BEGIN
|
|||
DECLARE vStartingYear INT DEFAULT vCurYear - 2;
|
||||
DECLARE vTable TEXT;
|
||||
|
||||
SET vTable = util.quoteIdentifier('balance_nest_tree');
|
||||
SET vTable = util.quoteIdentifier('balanceNestTree');
|
||||
SET vYear = util.quoteIdentifier(vCurYear);
|
||||
SET vOneYearAgo = util.quoteIdentifier(vCurYear-1);
|
||||
SET vTwoYearsAgo = util.quoteIdentifier(vCurYear-2);
|
||||
jbreso marked this conversation as resolved
guillermo
commented
En el string donde hay una consulta SQL, linea 38, no poner la coma al principio, sino al final: SELECT node.id, A parte de quitar los AS (Menos el del CAST que es necesario). Cast va en mayuscula. Cambiar En el string donde hay una consulta SQL, linea 38, no poner la coma al principio, sino al final:
SELECT node.id,
CONCAT( REPEA...
A parte de quitar los AS (Menos el del CAST que es necesario).
Cast va en mayuscula.
Cambiar `CONCAT( REPE...` por `CONCAT(REPE...`
|
||||
|
@ -41,72 +50,68 @@ BEGIN
|
|||
ORDER BY node.lft')
|
||||
USING intGAP;
|
||||
|
||||
DROP TEMPORARY TABLE IF EXISTS tmp.balance;
|
||||
CREATE TEMPORARY TABLE tmp.balance
|
||||
CREATE OR REPLACE TEMPORARY TABLE tmp.balance
|
||||
SELECT * FROM tmp.nest;
|
||||
|
||||
DROP TEMPORARY TABLE IF EXISTS tmp.empresas_receptoras;
|
||||
DROP TEMPORARY TABLE IF EXISTS tmp.empresas_emisoras;
|
||||
|
||||
SELECT empresa_grupo INTO vConsolidatedGroup
|
||||
FROM empresa
|
||||
SELECT companyGroupFk INTO vConsolidatedGroup
|
||||
jbreso marked this conversation as resolved
Outdated
carlosap
commented
tabulación tabulación
|
||||
FROM company
|
||||
WHERE id = vCompany;
|
||||
|
||||
CREATE TEMPORARY TABLE tmp.empresas_receptoras
|
||||
SELECT id as empresa_id
|
||||
FROM vn2008.empresa
|
||||
CREATE OR REPLACE TEMPORARY TABLE tCompanyReceiving
|
||||
SELECT id companyId
|
||||
jbreso marked this conversation as resolved
Outdated
carlosap
commented
companyFk companyFk
|
||||
FROM company
|
||||
WHERE id = vCompany
|
||||
OR empresa_grupo = IF(vIsConsolidated, vConsolidatedGroup, NULL);
|
||||
OR companyGroupFk = IF(vIsConsolidated, vConsolidatedGroup, NULL);
|
||||
|
||||
CREATE TEMPORARY TABLE tmp.empresas_emisoras
|
||||
SELECT Id_Proveedor as empresa_id FROM vn2008.Proveedores p;
|
||||
CREATE OR REPLACE TEMPORARY TABLE tCompanyIssuing
|
||||
SELECT id companyId
|
||||
FROM supplier p;
|
||||
|
||||
IF vInterGroupSalesIncluded = FALSE THEN
|
||||
|
||||
DELETE ee.*
|
||||
FROM tmp.empresas_emisoras ee
|
||||
JOIN vn2008.empresa e on e.id = ee.empresa_id
|
||||
WHERE e.empresa_grupo = vConsolidatedGroup;
|
||||
DELETE ci.*
|
||||
jbreso marked this conversation as resolved
Outdated
carlosap
commented
NOT NOT
|
||||
FROM tCompanyIssuing ci
|
||||
JOIN company e on e.id = ci.companyId
|
||||
jbreso marked this conversation as resolved
Outdated
carlosap
commented
companyFk companyFk
carlosap
commented
'*' no es necesario '*' no es necesario
|
||||
WHERE e.companyGroupFk = vConsolidatedGroup;
|
||||
|
||||
END IF;
|
||||
|
||||
-- Se calculan las facturas que intervienen, para luego poder servir el desglose desde aqui
|
||||
jbreso marked this conversation as resolved
guillermo
commented
Sobrepasa los caracteres máximos x linea Sobrepasa los caracteres máximos x linea
|
||||
DROP TEMPORARY TABLE IF EXISTS tmp.balance_desglose;
|
||||
CREATE TEMPORARY TABLE tmp.balance_desglose
|
||||
SELECT er.empresa_id receptora_id,
|
||||
ee.empresa_id emisora_id,
|
||||
year(IFNULL(r.bookEntried,IFNULL(r.dateBooking, r.Fecha))) `year`,
|
||||
month(IFNULL(r.bookEntried,IFNULL(r.dateBooking, r.Fecha))) `month`,
|
||||
gastos_id Id_Gasto,
|
||||
SUM(bi) importe
|
||||
FROM recibida r
|
||||
JOIN recibida_iva ri on ri.recibida_id = r.id
|
||||
JOIN tmp.empresas_receptoras er on er.empresa_id = r.empresa_id
|
||||
JOIN tmp.empresas_emisoras ee ON ee.empresa_id = r.proveedor_id
|
||||
WHERE IFNULL(r.bookEntried,IFNULL(r.dateBooking, r.Fecha)) >= vStartingDate
|
||||
AND r.contabilizada
|
||||
GROUP BY Id_Gasto, year, month, emisora_id, receptora_id;
|
||||
CREATE OR REPLACE TEMPORARY TABLE tmp.balanceDetail
|
||||
SELECT cr.companyId receivingId,
|
||||
ci.companyId issuingId,
|
||||
YEAR(IFNULL(r.bookEntried,IFNULL(r.booked, r.issued))) `year`,
|
||||
MONTH(IFNULL(r.bookEntried,IFNULL(r.booked, r.issued))) `month`,
|
||||
expenseFk,
|
||||
SUM(taxableBase) amount
|
||||
FROM invoiceIn r
|
||||
JOIN invoiceInTax ri on ri.invoiceInFk = r.id
|
||||
JOIN tCompanyReceiving cr on cr.companyId = r.companyFk
|
||||
jbreso marked this conversation as resolved
Outdated
carlosap
commented
companyFk companyFk
|
||||
JOIN tCompanyIssuing ci ON ci.companyId = r.supplierFk
|
||||
WHERE IFNULL(r.bookEntried,IFNULL(r.booked, r.issued)) >= vStartingDate
|
||||
jbreso marked this conversation as resolved
Outdated
carlosap
commented
utilizar en este casi COALESCE utilizar en este casi COALESCE
|
||||
AND r.isBooked
|
||||
GROUP BY expenseFk, year, month, ci.companyId, cr.companyId;
|
||||
jbreso marked this conversation as resolved
Outdated
carlosap
commented
companyFk companyFk
|
||||
|
||||
INSERT INTO tmp.balance_desglose(
|
||||
receptora_id,
|
||||
emisora_id,
|
||||
INSERT INTO tmp.balanceDetail(
|
||||
receivingId,
|
||||
issuingId,
|
||||
year,
|
||||
jbreso marked this conversation as resolved
Outdated
guillermo
commented
Year y month son palabras reservadas, poner entre ` Revisa todo el PR aplicandolo Year y month son palabras reservadas, poner entre `
Revisa todo el PR aplicandolo
|
||||
month,
|
||||
Id_Gasto,
|
||||
importe)
|
||||
SELECT gr.empresa_id,
|
||||
gr.empresa_id,
|
||||
expenseFk,
|
||||
amount)
|
||||
SELECT em.companyFk,
|
||||
em.companyFk,
|
||||
year,
|
||||
month,
|
||||
Id_Gasto,
|
||||
SUM(importe)
|
||||
FROM gastos_resumen gr
|
||||
JOIN tmp.empresas_receptoras er on gr.empresa_id = er.empresa_id
|
||||
expenseFk,
|
||||
SUM(amount)
|
||||
FROM expenseManual em
|
||||
JOIN tCompanyReceiving er on em.companyFk = em.companyFk
|
||||
jbreso marked this conversation as resolved
Outdated
carlosap
commented
ON en mayúsculas ON en mayúsculas
el JOIN está mal em.companyFk = em.companyFk enlazará todos los registros
|
||||
WHERE year >= vStartingYear
|
||||
AND month BETWEEN vStartingMonth AND vEndingMonth
|
||||
GROUP BY Id_Gasto, year, month, gr.empresa_id;
|
||||
GROUP BY expenseFk, year, month, em.companyFk;
|
||||
|
||||
DELETE FROM tmp.balance_desglose
|
||||
DELETE FROM tmp.balanceDetail
|
||||
WHERE month < vStartingMonth
|
||||
OR month > vEndingMonth;
|
||||
|
||||
|
@ -116,29 +121,29 @@ BEGIN
|
|||
ADD COLUMN ', vTwoYearsAgo ,' INT(10) NULL ,
|
||||
ADD COLUMN ', vOneYearAgo ,' INT(10) NULL ,
|
||||
ADD COLUMN ', vYear,' INT(10) NULL ,
|
||||
ADD COLUMN Id_Gasto VARCHAR(10) NULL,
|
||||
ADD COLUMN Gasto VARCHAR(45) NULL');
|
||||
ADD COLUMN expenseFk VARCHAR(10) NULL,
|
||||
ADD COLUMN expenseName VARCHAR(45) NULL');
|
||||
|
||||
-- Añadimos los gastos, para facilitar el formulario
|
||||
UPDATE tmp.balance b
|
||||
JOIN vn2008.balance_nest_tree bnt on bnt.id = b.id
|
||||
JOIN (SELECT id Id_Gasto, name Gasto
|
||||
FROM vn.expense
|
||||
GROUP BY id) g ON g.Id_Gasto = bnt.Id_Gasto COLLATE utf8_general_ci
|
||||
SET b.Id_Gasto = g.Id_Gasto COLLATE utf8_general_ci
|
||||
, b.Gasto = g.Gasto COLLATE utf8_general_ci ;
|
||||
JOIN balanceNestTree bnt on bnt.id = b.id
|
||||
JOIN (SELECT id, name
|
||||
FROM expense
|
||||
GROUP BY id) g ON g.id = bnt.expenseFk COLLATE utf8_general_ci
|
||||
SET b.expenseFk = g.id COLLATE utf8_general_ci
|
||||
jbreso marked this conversation as resolved
Outdated
guillermo
commented
JOIN ( JOIN (
(TAB) SELECT id, name
....
GROUP BY id
) g ON g.id = bnt.expenseFk COLLATE utf8_general_ci
|
||||
, b.expenseName = g.id COLLATE utf8_general_ci ;
|
||||
jbreso marked this conversation as resolved
Outdated
guillermo
commented
No poner la , al principio, sino al final en la linea anterior No poner la , al principio, sino al final en la linea anterior
carlosap
commented
El id de la tabla expense es PK no tiene sentido hacer subconsulta con el GROUP BY El id de la tabla expense es PK no tiene sentido hacer subconsulta con el GROUP BY
|
||||
|
||||
-- Rellenamos los valores de primer nivel, los que corresponden a los gastos simples
|
||||
WHILE vYears >= 0 DO
|
||||
SET vQuery = CONCAT(
|
||||
'UPDATE tmp.balance b
|
||||
JOIN
|
||||
(SELECT Id_Gasto, SUM(Importe) as Importe
|
||||
FROM tmp.balance_desglose
|
||||
(SELECT expenseFk, SUM(amount)
|
||||
FROM tmp.balanceDetail
|
||||
WHERE year = ?
|
||||
GROUP BY Id_Gasto
|
||||
) sub on sub.Id_Gasto = b.Id_Gasto COLLATE utf8_general_ci
|
||||
SET ', util.quoteIdentifier(vCurYear - vYears), ' = - Importe');
|
||||
GROUP BY expenseFk
|
||||
) sub on sub.expenseFk = b.expenseFk COLLATE utf8_general_ci
|
||||
SET ', util.quoteIdentifier(vCurYear - vYears), ' = - amount');
|
||||
|
||||
EXECUTE IMMEDIATE vQuery
|
||||
USING vCurYear - vYears;
|
||||
|
@ -155,10 +160,10 @@ BEGIN
|
|||
SUM(IF(year = ?, venta, 0)) y0,
|
||||
c.Gasto
|
||||
FROM bs.ventas_contables c
|
||||
JOIN tmp.empresas_receptoras er on er.empresa_id = c.empresa_id
|
||||
JOIN tCompanyReceiving cr ON cr.companyId = c.empresa_id
|
||||
WHERE month BETWEEN ? AND ?
|
||||
GROUP BY c.Gasto
|
||||
) sub ON sub.Gasto = b.Id_Gasto COLLATE utf8_general_ci
|
||||
) sub ON sub.gasto = b.expenseFk COLLATE utf8_general_ci
|
||||
SET b.', vTwoYearsAgo, '= IFNULL(b.', vTwoYearsAgo, ', 0) + sub.y2,
|
||||
jbreso marked this conversation as resolved
guillermo
commented
Sobra un espacio Sobra un espacio
|
||||
b.', vOneYearAgo, '= IFNULL(b.', vOneYearAgo, ', 0) + sub.y1,
|
||||
b.', vYear, '= IFNULL(b.', vYear, ', 0) + sub.y0')
|
||||
|
@ -182,8 +187,7 @@ BEGIN
|
|||
END IF;
|
||||
|
||||
-- Rellenamos el valor de los padres con la suma de los hijos
|
||||
DROP TEMPORARY TABLE IF EXISTS tmp.balance_aux;
|
||||
CREATE TEMPORARY TABLE tmp.balance_aux
|
||||
CREATE OR REPLACE TEMPORARY TABLE tmp.balance_aux
|
||||
SELECT * FROM tmp.balance;
|
||||
jbreso marked this conversation as resolved
Outdated
carlosap
commented
nombre de las variable en inglés si no se retornan nombre de las variable en inglés si no se retornan
|
||||
|
||||
EXECUTE IMMEDIATE
|
||||
|
@ -201,7 +205,11 @@ BEGIN
|
|||
b.', vOneYearAgo, ' = oneYearAgo,
|
||||
b.', vTwoYearsAgo, ' = twoYearsAgo');
|
||||
jbreso marked this conversation as resolved
Outdated
guillermo
commented
(Tab) GROUP BY b1.id) (Tab) GROUP BY b1.id)
sub ON sub.id = b.id
|
||||
|
||||
SELECT *, CONCAT('',ifnull(Id_Gasto,'')) newgasto
|
||||
SELECT *, CONCAT('',ifnull(expenseFk,'')) newgasto
|
||||
jbreso marked this conversation as resolved
Outdated
carlosap
commented
funciones en mayúsculas funciones en mayúsculas
|
||||
FROM tmp.balance;
|
||||
|
||||
DROP TEMPORARY TABLE IF EXISTS tCompanyReceiving;
|
||||
jbreso marked this conversation as resolved
Outdated
guillermo
commented
Utilizar un solo DROP para dropear las 2 tablas. Utilizar un solo DROP para dropear las 2 tablas.
|
||||
DROP TEMPORARY TABLE IF EXISTS tCompanyIssuing;
|
||||
|
||||
END$$
|
||||
DELIMITER ;
|
||||
DELIMITER ;
|
|
@ -68,19 +68,19 @@ BEGIN
|
|||
AND v.`visible`
|
||||
ON DUPLICATE KEY UPDATE visibleLanding = v.`visible`;
|
||||
|
||||
CALL vn2008.availableTraslate(vWarehouseOut, vDateShipped, NULL);
|
||||
CALL available_traslate(vWarehouseOut, vDateShipped, NULL);
|
||||
|
||||
INSERT INTO tItem(itemFk, available)
|
||||
SELECT a.item_id, a.available
|
||||
FROM vn2008.availableTraslate a
|
||||
FROM tmp.availableTraslate a
|
||||
WHERE a.available
|
||||
ON DUPLICATE KEY UPDATE available = a.available;
|
||||
|
||||
CALL vn2008.availableTraslate(vWarehouseIn, vDateLanded, vWarehouseOut);
|
||||
CALL available_traslate(vWarehouseIn, vDateLanded, vWarehouseOut);
|
||||
|
||||
INSERT INTO tItem(itemFk, availableLanding)
|
||||
SELECT a.item_id, a.available
|
||||
FROM vn2008.availableTraslate a
|
||||
FROM tmp.availableTraslate a
|
||||
WHERE a.available
|
||||
ON DUPLICATE KEY UPDATE availableLanding = a.available;
|
||||
ELSE
|
||||
|
|
|
@ -26,7 +26,7 @@ BEGIN
|
|||
LEAVE l;
|
||||
END IF;
|
||||
|
||||
CALL vn2008.buy_tarifas_entry(vEntryFk);
|
||||
CALL buy_recalcPricesByEntry(vEntryFk);
|
||||
END LOOP;
|
||||
|
||||
CLOSE vCur;
|
||||
|
|
|
@ -1,6 +0,0 @@
|
|||
DELIMITER $$
|
||||
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn2008`.`article_multiple_buy`(v_date DATETIME, wh INT)
|
||||
BEGIN
|
||||
CALL vn.item_multipleBuy(v_date, wh);
|
||||
END$$
|
||||
DELIMITER ;
|
|
@ -1,9 +0,0 @@
|
|||
DELIMITER $$
|
||||
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn2008`.`article_multiple_buy_date`(
|
||||
IN vDated DATETIME,
|
||||
IN vWarehouseFk TINYINT(3)
|
||||
)
|
||||
BEGIN
|
||||
CALL vn.item_multipleBuyByDate(vDated, vWarehouseFk);
|
||||
END$$
|
||||
DELIMITER ;
|
|
@ -1,6 +0,0 @@
|
|||
DELIMITER $$
|
||||
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn2008`.`buy_tarifas`(vBuyFk INT)
|
||||
BEGIN
|
||||
CALL vn.buy_recalcPricesByBuy(vBuyFk);
|
||||
END$$
|
||||
DELIMITER ;
|
|
@ -1,11 +0,0 @@
|
|||
DELIMITER $$
|
||||
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn2008`.`buy_tarifas_entry`(IN vEntryFk INT(11))
|
||||
BEGIN
|
||||
/**
|
||||
* Recalcula los precios de una entrada
|
||||
*
|
||||
* @param vEntryFk
|
||||
*/
|
||||
CALL vn.buy_recalcPricesByEntry(vEntryFk);
|
||||
END$$
|
||||
DELIMITER ;
|
|
@ -0,0 +1,15 @@
|
|||
CREATE OR REPLACE PROCEDURE `vn`.`balance_create`() BEGIN END;
|
||||
CREATE OR REPLACE PROCEDURE `vn`.`buy_recalcPricesByEntry`() BEGIN END;
|
||||
CREATE OR REPLACE PROCEDURE `vn`.`buy_recalcPricesByBuy`() BEGIN END;
|
||||
|
||||
GRANT EXECUTE ON PROCEDURE vn.balance_create TO `financialBoss`;
|
||||
jbreso marked this conversation as resolved
Outdated
guillermo
commented
Unificar GRANT EXECUTE ON PROCEDURE vn.balance_create TO Así con los demás grants, solo tiene que haber un GRANT EXECUTE para cada proc Unificar GRANT EXECUTE ON PROCEDURE vn.balance_create TO `financialBoss`, `hrBoss`;
Así con los demás grants, solo tiene que haber un GRANT EXECUTE para cada proc
|
||||
GRANT EXECUTE ON PROCEDURE vn.balance_create TO `hrBoss`;
|
||||
|
||||
GRANT EXECUTE ON PROCEDURE vn.buy_recalcPricesByEntry TO `buyer`;
|
||||
GRANT EXECUTE ON PROCEDURE vn.buy_recalcPricesByEntry TO `claimManager`;
|
||||
GRANT EXECUTE ON PROCEDURE vn.buy_recalcPricesByEntry TO `employee`;
|
||||
|
||||
GRANT EXECUTE ON PROCEDURE vn.buy_recalcPricesByBuy TO `buyer`;
|
||||
GRANT EXECUTE ON PROCEDURE vn.buy_recalcPricesByBuy TO `entryEditor`;
|
||||
GRANT EXECUTE ON PROCEDURE vn.buy_recalcPricesByBuy TO `claimManager`;
|
||||
GRANT EXECUTE ON PROCEDURE vn.buy_recalcPricesByBuy TO `employee`;
|
Sobrepasa los carácteres máximos x linea, a parte que al final va un punto