- Remove nfjson/nfjsonread.FXP from git tracking - Add Python cache patterns (__pycache__/, *.py[cod], *$py.class) - Add environment file patterns (.env, .env.local, .env.*.local) - Reorganize project structure with VFP files moved to vfp/ directory - Add comprehensive database scripts and documentation 🤖 Generated with [Claude Code](https://claude.ai/code) Co-Authored-By: Claude <noreply@anthropic.com>
2716 lines
103 KiB
Plaintext
2716 lines
103 KiB
Plaintext
create or replace package PACK_COMENZI is
|
|
|
|
-- Author : MARIUS.ATANASIU
|
|
-- Created : 18/08/2006
|
|
-- Purpose :
|
|
|
|
id_comanda COMENZI.ID_COMANDA%TYPE;
|
|
|
|
procedure adauga_masina(V_ID_MODEL_MASINA IN NUMBER,
|
|
V_NRINMAT IN VARCHAR2,
|
|
V_CULOARE IN VARCHAR2,
|
|
V_ID_UTIL IN NUMBER);
|
|
|
|
procedure modifica_masina(V_ID_MASINA IN NUMBER,
|
|
V_ID_MODEL_MASINA IN NUMBER,
|
|
V_NRINMAT IN VARCHAR2,
|
|
V_CULOARE IN VARCHAR2,
|
|
V_ID_UTIL IN NUMBER);
|
|
|
|
procedure sterge_masina(V_ID_MASINA IN NUMBER, V_ID_UTIL IN NUMBER);
|
|
|
|
procedure adauga_comanda(V_NR_COMANDA IN VARCHAR2,
|
|
V_DATA_COMANDA IN DATE,
|
|
V_ID IN NUMBER,
|
|
V_DATA_LIVRARE IN DATE,
|
|
V_PROC_DISCOUNT IN NUMBER,
|
|
V_INTERNA IN NUMBER,
|
|
V_ID_UTIL IN NUMBER,
|
|
V_ID_SECTIE IN NUMBER,
|
|
V_ID_ADRESA_FACTURARE in NUMBER,
|
|
V_ID_ADRESA_LIVRARE in NUMBER,
|
|
V_ID_CODCLIENT in number,
|
|
V_COMANDA_EXTERNA in varchar2,
|
|
V_ID_CTR IN NUMBER);
|
|
|
|
procedure modifica_comanda(V_ID_COMANDA IN NUMBER,
|
|
V_NR_COMANDA IN VARCHAR2,
|
|
V_DATA_COMANDA IN DATE,
|
|
V_ID IN NUMBER,
|
|
V_DATA_LIVRARE IN DATE,
|
|
V_PROC_DISCOUNT IN NUMBER,
|
|
V_INTERNA IN NUMBER,
|
|
V_ID_UTIL IN NUMBER,
|
|
V_ADRESA_FACTURARE in number,
|
|
V_ADRESA_LIVRARE in number,
|
|
V_ID_CODCLIENT in number,
|
|
V_COMANDA_EXTERNA in varchar2,
|
|
V_ID_CTR IN NUMBER);
|
|
|
|
procedure sterge_comanda(V_ID_COMANDA IN NUMBER, V_ID_UTIL IN NUMBER);
|
|
|
|
procedure cauta_contract_comanda(V_DATA_COMANDA IN DATE,
|
|
V_ID_PART IN NUMBER,
|
|
V_ID_SUCURSALA IN NUMBER,
|
|
V_ID_CTR OUT NUMBER,
|
|
V_NUMAR_CTR OUT VARCHAR2);
|
|
|
|
procedure adauga_articol_comanda(V_ID_COMANDA IN NUMBER,
|
|
V_ID_ARTICOL IN NUMBER,
|
|
V_ID_POL IN NUMBER,
|
|
V_CANTITATE IN NUMBER,
|
|
V_ID_UTIL IN NUMBER,
|
|
V_ID_SECTIE IN NUMBER);
|
|
|
|
procedure adauga_articol_comanda(V_ID_COMANDA IN NUMBER,
|
|
V_ID_ARTICOL IN NUMBER,
|
|
V_ID_POL IN NUMBER,
|
|
V_CANTITATE IN NUMBER,
|
|
V_PRET IN NUMBER,
|
|
V_ID_UTIL IN NUMBER,
|
|
V_ID_SECTIE IN NUMBER);
|
|
|
|
procedure modifica_articol_comanda(V_ID_COMANDA_ELEMENT IN NUMBER,
|
|
V_CANTITATE IN NUMBER,
|
|
V_ID_UTIL IN NUMBER);
|
|
|
|
procedure modifica_articol_comanda(V_ID_COMANDA_ELEMENT IN NUMBER,
|
|
V_CANTITATE IN NUMBER,
|
|
V_PRET IN NUMBER,
|
|
V_ID_UTIL IN NUMBER);
|
|
|
|
/* procedure sterge_articol_comanda(V_ID_COMANDA IN NUMBER,
|
|
V_ID_ARTICOL IN NUMBER,
|
|
V_ID_POL IN NUMBER,
|
|
V_ID_UTIL IN NUMBER);*/
|
|
|
|
procedure sterge_articol_comanda(V_ID_COMANDA_ELEMENT IN NUMBER,
|
|
V_ID_UTIL IN NUMBER);
|
|
|
|
procedure adauga_lucrare_pe_comanda(V_ID_COMANDA IN NUMBER,
|
|
V_ID_LUCRARE IN NUMBER,
|
|
V_ID_UTIL IN NUMBER,
|
|
V_ID_SECTIE IN NUMBER);
|
|
|
|
procedure adauga_lucrare_pe_comenzi(V_SIR_COMENZI IN VARCHAR2,
|
|
V_ID_LUCRARE IN NUMBER,
|
|
V_ID_UTIL IN NUMBER,
|
|
V_ID_SECTIE IN NUMBER);
|
|
|
|
procedure livreaza_comanda(V_ID_COMANDA IN NUMBER,
|
|
V_ID_AGENT IN NUMBER,
|
|
V_ID_DELEGAT IN NUMBER,
|
|
V_ID_MASINA IN NUMBER,
|
|
V_DATA_LIVRAT IN DATE,
|
|
V_ID_UTIL IN NUMBER,
|
|
V_NR_LIVRARE OUT VARCHAR2);
|
|
|
|
procedure genereaza_lucrare(V_DATA_LUCRARE IN DATE,
|
|
V_ORE_EXECUTIE IN NUMBER,
|
|
V_ID_UTIL IN NUMBER,
|
|
V_ID_SECTIE IN NUMBER,
|
|
V_NRORD OUT VARCHAR2,
|
|
V_ID_LUCRARE OUT NUMBER);
|
|
|
|
procedure adauga_lucrare(V_NRORD IN VARCHAR2,
|
|
V_DATA_LUCRARE IN DATE,
|
|
V_EXPLICATIE IN VARCHAR2,
|
|
V_TERMEN_EXECUTIE IN DATE,
|
|
V_ID_UTIL IN NUMBER,
|
|
V_ID_SECTIE IN NUMBER);
|
|
|
|
procedure modifica_lucrare(V_ID_LUCRARE IN NUMBER,
|
|
V_NRORD IN VARCHAR2,
|
|
V_DATA_LUCRARE IN DATE,
|
|
V_EXPLICATIE IN VARCHAR2,
|
|
V_TERMEN_EXECUTIE IN DATE,
|
|
V_ID_UTIL IN NUMBER);
|
|
|
|
procedure sterge_lucrare(V_ID_LUCRARE IN NUMBER, V_ID_UTIL IN NUMBER);
|
|
|
|
procedure actualizeaza_lucrare(V_ID_COMANDA IN NUMBER,
|
|
V_ID_UTIL IN NUMBER,
|
|
V_ID_SECTIE IN NUMBER);
|
|
|
|
procedure actualizeaza_articole_lucrare(V_ID_LUCRARE IN NUMBER,
|
|
V_ID_UTIL IN NUMBER,
|
|
V_ID_SECTIE IN NUMBER);
|
|
|
|
procedure adauga_loturi(V_ID_LUCRARE IN NUMBER, V_ID_UTIL IN NUMBER);
|
|
|
|
procedure sterge_loturi(V_ID_LUCRARE IN NUMBER, V_ID_UTIL IN NUMBER);
|
|
|
|
-- function citeste_ore_inchidere return number;
|
|
|
|
function genereaza_nr_comanda return varchar2;
|
|
|
|
function genereaza_nr_lucrare return varchar2;
|
|
|
|
function genereaza_nr_livrare return varchar2;
|
|
|
|
procedure copiaza_comanda(V_ID_COMANDA IN NUMBER,
|
|
V_OPTIUNE_CANT IN NUMBER,
|
|
V_ID_UTIL IN NUMBER,
|
|
V_ID_COMANDA_NOU OUT NUMBER);
|
|
|
|
procedure copiaza_comenzi(V_SIR_ID_COMANDA IN VARCHAR2,
|
|
V_SEPARATOR_PARAM IN VARCHAR2,
|
|
V_ID_UTIL IN NUMBER);
|
|
procedure sectii_utilizator(V_ID_UTIL IN NUMBER,
|
|
V_ID_SUCURSALA IN NUMBER,
|
|
p_cursor OUT pack_types.tip_cursor);
|
|
function extrage_optiuni(tcLista varchar2, tnId number) return varchar2;
|
|
function citeste_ore_inchidere(tnId number) return number;
|
|
|
|
procedure raport_proc_vanzari_sterge(V_ID_COMRAPVANZ IN NUMBER);
|
|
procedure raport_proc_vanzari(V_DATAORA_I IN TIMESTAMP,
|
|
V_DATAORA_S IN TIMESTAMP,
|
|
V_ID_GRUPA_GEST IN NUMBER,
|
|
V_PROCENT IN NUMBER,
|
|
V_ID_SECTIE IN NUMBER,
|
|
V_ID_UTIL IN NUMBER,
|
|
V_ID_SUCURSALA IN NUMBER,
|
|
V_CURSOR OUT pack_cursor.tip_ref_cursor);
|
|
|
|
procedure completeaza_raport(V_ID_COMRAPVANZ IN NUMBER,
|
|
V_LISTA_ARTICOLE IN VARCHAR,
|
|
V_LISTA_GESTIUNI IN VARCHAR,
|
|
V_CURSOR OUT pack_cursor.tip_ref_cursor);
|
|
|
|
procedure raport_proc_vanzari_viz(V_ID_COMRAPVANZ IN NUMBER,
|
|
V_CURSOR OUT pack_cursor.tip_ref_cursor);
|
|
|
|
procedure actualizeaza_raport(V_ID_COMRAPVANZ IN NUMBER,
|
|
V_LISTA_ACTUALIZARI IN CLOB,
|
|
V_NR_COMENZI_GENERATE OUT NUMBER,
|
|
V_CURSOR OUT pack_cursor.tip_ref_cursor);
|
|
|
|
procedure centralizator_rapoarte(V_LUNA IN NUMBER,
|
|
V_AN IN NUMBER,
|
|
V_ID_SECTIE IN NUMBER,
|
|
V_CURSOR OUT pack_cursor.tip_ref_cursor);
|
|
|
|
procedure listeaza_raport(V_ID_COMRAPVANZ IN NUMBER,
|
|
V_DATA OUT DATE,
|
|
V_CURSOR OUT pack_cursor.tip_ref_cursor);
|
|
|
|
procedure listeaza_raport_vz_fz(V_ID_COMRAPVANZ IN NUMBER,
|
|
V_CANTITATE IN NUMBER,
|
|
V_DATA OUT DATE,
|
|
V_DATAI OUT DATE,
|
|
V_DATAS OUT DATE,
|
|
V_CURSOR OUT pack_cursor.tip_ref_cursor);
|
|
|
|
procedure rap_vanz_per_detaliu(V_ID_COMRAPVANZELEM IN NUMBER,
|
|
V_CURSOR OUT pack_cursor.tip_ref_cursor);
|
|
|
|
function verifica_acces_comanda(V_ID_COMANDA IN NUMBER) return varchar2;
|
|
|
|
procedure deblocheaza_acces_comanda(V_ID_COMANDA IN NUMBER);
|
|
|
|
procedure factureaza_comanda(tnIdComanda IN comenzi.id_comanda%type,
|
|
tnAn IN act.an%type DEFAULT EXTRACT(YEAR FROM
|
|
SYSDATE),
|
|
tnLuna IN act.luna%type DEFAULT EXTRACT(MONTH FROM
|
|
SYSDATE),
|
|
tnNrAct IN vanzari.numar_act%type DEFAULT NULL,
|
|
tdDataAct IN vanzari.data_act%type DEFAULT TRUNC(SYSDATE),
|
|
tnIncasat IN NUMBER DEFAULT 0,
|
|
tnSumaIncasat IN NUMBER DEFAULT 0,
|
|
tcTipIncasare IN VARCHAR2 DEFAULT 'CHITANTA',
|
|
tnIdDelegat IN VANZARI.ID_DELEGAT%TYPE DEFAULT NULL,
|
|
tnIdMasina IN vanzari.id_masina%type DEFAULT NULL,
|
|
tnIdAgent IN vanzari.id_agent%type DEFAULT NULL,
|
|
tcTextAditional IN vanzari.text_aditional%type DEFAULT NULL,
|
|
tnIdUtil IN vanzari.id_util%type DEFAULT -3,
|
|
tcMesaj OUT VARCHAR2,
|
|
tnIdVanzare OUT VANZARI.ID_VANZARE%TYPE);
|
|
|
|
end PACK_COMENZI;
|
|
|
|
/
|
|
create or replace package body PACK_COMENZI is
|
|
-- ultima eroare atribuita : COM-001
|
|
|
|
-- 18.10.2013
|
|
-- marius.mutu
|
|
-- raport_proc_vanzari
|
|
-- se iau in considerare si articolele fara stoc initial, dar cu rulaje
|
|
|
|
-- 13.08.2015
|
|
-- marius.mutu
|
|
-- centralizator_rapoarte - adaugare parametru V_TIP: 1/2 (completat/necompletat)
|
|
-- raport_proc_vanzari: se iau in considerare articolele din urma cu 2 luni din rulaje. nu intrau in raport articolele care nu aveau stoc initial sau rulaje in perioada de 24 ore de ex.
|
|
-- raport_proc_vanzari: adaugare coloana STOCDEP (stoc depozit pe articol - pentru raportul vanzari perioada pe furnizori + stoc depozit)
|
|
-- completeaza_raport: adaugare coloana STOCDEP
|
|
|
|
-- 22.10.2015
|
|
-- marius.mutu
|
|
-- + raport_proc_vanzari_viz - vizualizare raport comenzi din vanzari in perioada
|
|
-- + raport_proc_vanzari_sterge - stergerea raport comenzi din vanzari in perioada
|
|
-- raport_proc_vanzari - se iau toate articolele din rulajul ultimelor 3 luni, nu numai cele care au vanzari. nu se mai tine cont de procentul de vanzari
|
|
-- nu se afisau articole care nu avusesera vanzari in perioada, desi aveau rulaje in ultimele 3 luni
|
|
|
|
-- 27.10.2015
|
|
-- marius.mutu
|
|
-- raport_proc_vanzari - stocul din depozit se afiseaza pentru toate articolele din raport, nu numai pentru cele care au stoc final
|
|
|
|
-- 21.12.2015
|
|
-- marius.mutu
|
|
-- raport_proc_vanzari - se iau numai gestiunile active. unele chioscuri nu au activitate si nu ar trebui sa intre in raport
|
|
-- raport_proc_vanzari: se iau toate articolele din rulajul ultimelor 1 luni, in loc de 3 luni
|
|
|
|
--08.02.2016
|
|
-- marius.mutu
|
|
-- raport_proc_vanzari - se iau articolele din rulajul ultimelor 1 luni + articolele din stocul initial
|
|
|
|
-- 11.03.2016
|
|
-- marius.mutu
|
|
-- PACK_COMENZI.raport_proc_vanzari - am corectat join-ul cu stoc depozit
|
|
|
|
-- 28.03.2016
|
|
-- marius.mutu
|
|
-- factureaza_comanda - adaugare parametru "nract"
|
|
|
|
-- 05.04.2016
|
|
-- marius.mutu
|
|
-- factureaza_comanda - tratare parametru nract 0
|
|
|
|
-- 29.06.2018
|
|
-- marius.mutu
|
|
-- copiaza_comanda - corectare selectare optiune COPIECANTITATE
|
|
|
|
-- 26.03.2021
|
|
-- marius.mutu
|
|
-- adauga_articol_comanda, modifica_articol_comanda - se poate modifica si pretul, in loc sa il ia din politica de preturi
|
|
----------------------------------------------------------------------------------
|
|
procedure adauga_masina(V_ID_MODEL_MASINA IN NUMBER,
|
|
V_NRINMAT IN VARCHAR2,
|
|
V_CULOARE IN VARCHAR2,
|
|
V_ID_UTIL IN NUMBER) is
|
|
V_EXISTA NUMBER(10);
|
|
begin
|
|
SELECT COUNT(*)
|
|
INTO V_EXISTA
|
|
FROM NOM_MASINI
|
|
WHERE NRINMAT = V_NRINMAT
|
|
AND STERS = 0;
|
|
|
|
IF V_EXISTA > 0 THEN
|
|
RAISE_APPLICATION_ERROR(-20000,
|
|
'Mai exista o masina cu acest numar de inmatriculare!');
|
|
ELSE
|
|
INSERT INTO NOM_MASINI
|
|
(ID_MODEL_MASINA, NRINMAT, CULOARE)
|
|
VALUES
|
|
(V_ID_MODEL_MASINA, V_NRINMAT, V_CULOARE);
|
|
END IF;
|
|
end adauga_masina;
|
|
----------------------------------------------------------------------------------
|
|
procedure modifica_masina(V_ID_MASINA IN NUMBER,
|
|
V_ID_MODEL_MASINA IN NUMBER,
|
|
V_NRINMAT IN VARCHAR2,
|
|
V_CULOARE IN VARCHAR2,
|
|
V_ID_UTIL IN NUMBER) is
|
|
V_EXISTA NUMBER(10);
|
|
begin
|
|
SELECT COUNT(*)
|
|
INTO V_EXISTA
|
|
FROM NOM_MASINI
|
|
WHERE NRINMAT = V_NRINMAT
|
|
AND STERS = 0
|
|
AND ID_MASINA <> V_ID_MASINA;
|
|
|
|
IF V_EXISTA > 0 THEN
|
|
RAISE_APPLICATION_ERROR(-20000,
|
|
'Mai exista o masina cu acest numar de inmatriculare!');
|
|
ELSE
|
|
UPDATE NOM_MASINI
|
|
SET ID_MODEL_MASINA = V_ID_MODEL_MASINA,
|
|
NRINMAT = V_NRINMAT,
|
|
CULOARE = V_CULOARE
|
|
WHERE ID_MASINA = V_ID_MASINA;
|
|
END IF;
|
|
end modifica_masina;
|
|
----------------------------------------------------------------------------------
|
|
procedure sterge_masina(V_ID_MASINA IN NUMBER, V_ID_UTIL IN NUMBER) is
|
|
begin
|
|
-- de adaugat verificari
|
|
UPDATE NOM_MASINI SET STERS = 1 WHERE ID_MASINA = V_ID_MASINA;
|
|
end sterge_masina;
|
|
----------------------------------------------------------------------------------
|
|
procedure adauga_comanda(V_NR_COMANDA IN VARCHAR2,
|
|
V_DATA_COMANDA IN DATE,
|
|
V_ID IN NUMBER,
|
|
V_DATA_LIVRARE IN DATE,
|
|
V_PROC_DISCOUNT IN NUMBER,
|
|
V_INTERNA IN NUMBER,
|
|
V_ID_UTIL IN NUMBER,
|
|
V_ID_SECTIE IN NUMBER,
|
|
V_ID_ADRESA_FACTURARE in NUMBER,
|
|
V_ID_ADRESA_LIVRARE in NUMBER,
|
|
V_ID_CODCLIENT in number,
|
|
V_COMANDA_EXTERNA in varchar2,
|
|
V_ID_CTR IN NUMBER) is
|
|
V_NR_INREGISTRARI NUMBER(10);
|
|
V_NESTERS NUMBER(1) := 0;
|
|
V_ID_PART NOM_PARTENERI.ID_PART%TYPE;
|
|
V_ID_GESTIUNE NOM_GESTIUNI.ID_GESTIUNE%TYPE;
|
|
V_ID_SECTIE2 NOM_SECTII.ID_SECTIE%TYPE;
|
|
V_DATA_LIVRARE2 DATE;
|
|
V_ID_ADRESA_FACTURARE1 NUMBER(10);
|
|
V_ID_ADRESA_LIVRARE1 NUMBER(10);
|
|
V_ID_CODCLIENT1 comenzi.id_codclient%TYPE;
|
|
V_COMANDA_EXTERNA1 comenzi.COMANDA_EXTERNA%TYPE;
|
|
|
|
begin
|
|
SELECT COUNT(*)
|
|
INTO V_NR_INREGISTRARI
|
|
FROM COMENZI
|
|
WHERE STERS = V_NESTERS
|
|
AND NR_COMANDA = V_NR_COMANDA;
|
|
|
|
IF V_NR_INREGISTRARI > 0 THEN
|
|
RAISE_APPLICATION_ERROR(-20000,
|
|
'Mai exista o comanda cu acest numar!');
|
|
END IF;
|
|
|
|
IF V_ID_CTR IS NOT NULL THEN
|
|
SELECT COUNT(*)
|
|
INTO V_NR_INREGISTRARI
|
|
FROM CONTRACTE
|
|
WHERE STERS = 0
|
|
AND INCETAT = 0
|
|
AND NVL(DATA_SFARSIT, V_DATA_COMANDA) < V_DATA_COMANDA
|
|
AND ID_CTR = V_ID_CTR
|
|
AND NVL(ID_SUCURSALA, -99) IN
|
|
(SELECT NVL(ID_SUCURSALA, -99)
|
|
FROM NOM_SECTII
|
|
WHERE ID_SECTIE = V_ID_SECTIE);
|
|
|
|
IF V_NR_INREGISTRARI > 0 THEN
|
|
RAISE_APPLICATION_ERROR(-20000,
|
|
'Contractul ales nu este activ la data comenzii!');
|
|
END IF;
|
|
END IF;
|
|
|
|
CASE
|
|
WHEN V_INTERNA = 1 THEN
|
|
V_ID_GESTIUNE := NULL;
|
|
V_ID_PART := NULL;
|
|
V_DATA_LIVRARE2 := NULL;
|
|
V_ID_SECTIE2 := NULL;
|
|
V_ID_ADRESA_FACTURARE1 := NULL;
|
|
V_ID_ADRESA_LIVRARE1 := NULL;
|
|
V_ID_CODCLIENT1 := 3;
|
|
V_COMANDA_EXTERNA1 := '';
|
|
WHEN V_INTERNA IN (2, 5) THEN
|
|
V_ID_GESTIUNE := NULL;
|
|
V_ID_PART := V_ID;
|
|
V_DATA_LIVRARE2 := V_DATA_LIVRARE;
|
|
V_ID_SECTIE2 := NULL;
|
|
V_ID_ADRESA_FACTURARE1 := V_ID_ADRESA_FACTURARE;
|
|
V_ID_ADRESA_LIVRARE1 := V_ID_ADRESA_LIVRARE;
|
|
V_ID_CODCLIENT1 := V_ID_CODCLIENT;
|
|
V_COMANDA_EXTERNA1 := V_COMANDA_EXTERNA;
|
|
WHEN V_INTERNA = 3 THEN
|
|
V_ID_GESTIUNE := V_ID;
|
|
V_ID_PART := NULL;
|
|
V_DATA_LIVRARE2 := V_DATA_LIVRARE;
|
|
V_ID_SECTIE2 := NULL;
|
|
V_ID_ADRESA_FACTURARE1 := NULL;
|
|
V_ID_ADRESA_LIVRARE1 := NULL;
|
|
V_ID_CODCLIENT1 := NULL;
|
|
V_COMANDA_EXTERNA1 := '';
|
|
WHEN V_INTERNA = 4 THEN
|
|
V_ID_SECTIE2 := V_ID;
|
|
V_ID_PART := NULL;
|
|
V_ID_GESTIUNE := NULL;
|
|
V_DATA_LIVRARE2 := V_DATA_LIVRARE;
|
|
V_ID_ADRESA_FACTURARE1 := NULL;
|
|
V_ID_ADRESA_LIVRARE1 := NULL;
|
|
V_ID_CODCLIENT1 := NULL;
|
|
V_COMANDA_EXTERNA1 := '';
|
|
END CASE;
|
|
|
|
--dbms_output.put_line(V_ID_SECTIE);
|
|
--dbms_output.put_line(V_ID_SECTIE2);
|
|
INSERT INTO COMENZI
|
|
(NR_COMANDA,
|
|
DATA_COMANDA,
|
|
ID_GESTIUNE,
|
|
ID_PART,
|
|
DATA_LIVRARE,
|
|
INTERNA,
|
|
ID_UTIL,
|
|
ID_SECTIE,
|
|
ID_SECTIE2,
|
|
ID_FACTURARE,
|
|
ID_LIVRARE,
|
|
ID_CODCLIENT,
|
|
PROC_DISCOUNT,
|
|
COMANDA_EXTERNA,
|
|
ID_SUCURSALA,
|
|
ID_CTR)
|
|
SELECT V_NR_COMANDA,
|
|
V_DATA_COMANDA,
|
|
V_ID_GESTIUNE,
|
|
V_ID_PART,
|
|
V_DATA_LIVRARE2,
|
|
V_INTERNA,
|
|
V_ID_UTIL,
|
|
V_ID_SECTIE,
|
|
V_ID_SECTIE2,
|
|
V_ID_ADRESA_FACTURARE1,
|
|
V_ID_ADRESA_LIVRARE1,
|
|
V_ID_CODCLIENT1,
|
|
V_PROC_DISCOUNT,
|
|
V_COMANDA_EXTERNA1,
|
|
ID_SUCURSALA,
|
|
V_ID_CTR
|
|
FROM NOM_SECTII
|
|
WHERE ID_SECTIE = V_ID_SECTIE;
|
|
end adauga_comanda;
|
|
----------------------------------------------------------------------------------
|
|
procedure modifica_comanda(V_ID_COMANDA IN NUMBER,
|
|
V_NR_COMANDA IN VARCHAR2,
|
|
V_DATA_COMANDA IN DATE,
|
|
V_ID IN NUMBER,
|
|
V_DATA_LIVRARE IN DATE,
|
|
V_PROC_DISCOUNT IN NUMBER,
|
|
V_INTERNA IN NUMBER,
|
|
V_ID_UTIL IN NUMBER,
|
|
V_ADRESA_FACTURARE in number,
|
|
V_ADRESA_LIVRARE in number,
|
|
V_ID_CODCLIENT in number,
|
|
V_COMANDA_EXTERNA in varchar2,
|
|
V_ID_CTR IN NUMBER) is
|
|
V_NR_INREGISTRARI NUMBER(10);
|
|
V_NESTERS NUMBER(1) := 0;
|
|
V_ID_PART NOM_PARTENERI.ID_PART%TYPE;
|
|
V_ID_GESTIUNE NOM_GESTIUNI.ID_GESTIUNE%TYPE;
|
|
V_DATA_LIVRARE2 DATE;
|
|
V_ID_SECTIE NOM_SECTII.ID_SECTIE%TYPE;
|
|
V_ID_SECTIE2 NOM_SECTII.ID_SECTIE%TYPE;
|
|
V_ADRESA_FACTURARE1 number(5);
|
|
V_ADRESA_LIVRARE1 number(5);
|
|
V_ADRESA_FACTURAREold number(5);
|
|
V_ADRESA_LIVRAREold number(5);
|
|
V_ID_CODCLIENT1 number(5);
|
|
V_COMANDA_EXTERNA1 varchar(50);
|
|
begin
|
|
SELECT COUNT(*)
|
|
INTO V_NR_INREGISTRARI
|
|
FROM COMENZI
|
|
WHERE STERS = V_NESTERS
|
|
AND NR_COMANDA = V_NR_COMANDA
|
|
AND ID_COMANDA <> V_ID_COMANDA;
|
|
|
|
IF V_NR_INREGISTRARI > 0 THEN
|
|
RAISE_APPLICATION_ERROR(-20000,
|
|
'Mai exista o comanda cu acest numar!');
|
|
END IF;
|
|
|
|
IF V_ID_CTR IS NOT NULL THEN
|
|
SELECT COUNT(*)
|
|
INTO V_NR_INREGISTRARI
|
|
FROM CONTRACTE
|
|
WHERE STERS = 0
|
|
AND INCETAT = 0
|
|
AND NVL(DATA_SFARSIT, V_DATA_COMANDA) < V_DATA_COMANDA
|
|
AND ID_CTR = V_ID_CTR
|
|
AND NVL(ID_SUCURSALA, -99) IN
|
|
(SELECT NVL(ID_SUCURSALA, -99)
|
|
FROM NOM_SECTII
|
|
WHERE ID_SECTIE = V_ID_SECTIE);
|
|
|
|
IF V_NR_INREGISTRARI > 0 THEN
|
|
RAISE_APPLICATION_ERROR(-20000,
|
|
'Contractul ales nu este activ la data comenzii!');
|
|
END IF;
|
|
END IF;
|
|
|
|
SELECT ID_SECTIE
|
|
INTO V_ID_SECTIE
|
|
FROM COMENZI
|
|
WHERE STERS = V_NESTERS
|
|
AND ID_COMANDA = V_ID_COMANDA;
|
|
|
|
SELECT ID_FACTURARE, ID_LIVRARE, ID_CODCLIENT, COMANDA_EXTERNA
|
|
INTO V_ADRESA_FACTURAREold,
|
|
V_ADRESA_LIVRAREold,
|
|
V_ID_CODCLIENT1,
|
|
V_COMANDA_EXTERNA1
|
|
FROM COMENZI
|
|
WHERE STERS = V_NESTERS
|
|
AND ID_COMANDA = V_ID_COMANDA;
|
|
|
|
CASE
|
|
WHEN V_INTERNA = 1 THEN
|
|
V_ID_GESTIUNE := NULL;
|
|
V_ID_PART := NULL;
|
|
V_DATA_LIVRARE2 := NULL;
|
|
V_ID_SECTIE2 := NULL;
|
|
V_ADRESA_FACTURARE1 := V_ADRESA_FACTURAREold;
|
|
V_ADRESA_LIVRARE1 := V_ADRESA_LIVRAREold;
|
|
WHEN V_INTERNA IN (2, 5) THEN
|
|
V_ID_GESTIUNE := NULL;
|
|
V_ID_PART := V_ID;
|
|
V_DATA_LIVRARE2 := V_DATA_LIVRARE;
|
|
V_ID_SECTIE2 := NULL;
|
|
V_ADRESA_FACTURARE1 := V_ADRESA_FACTURARE;
|
|
V_ADRESA_LIVRARE1 := V_ADRESA_LIVRARE;
|
|
V_ID_CODCLIENT1 := V_ID_CODCLIENT;
|
|
V_COMANDA_EXTERNA1 := V_COMANDA_EXTERNA;
|
|
|
|
WHEN V_INTERNA = 3 THEN
|
|
V_ID_GESTIUNE := V_ID;
|
|
V_ID_PART := NULL;
|
|
V_DATA_LIVRARE2 := V_DATA_LIVRARE;
|
|
V_ID_SECTIE2 := NULL;
|
|
V_ADRESA_FACTURARE1 := V_ADRESA_FACTURAREold;
|
|
V_ADRESA_LIVRARE1 := V_ADRESA_LIVRAREold;
|
|
WHEN V_INTERNA = 4 THEN
|
|
V_ID_SECTIE2 := V_ID;
|
|
V_ID_PART := NULL;
|
|
V_ID_GESTIUNE := NULL;
|
|
V_DATA_LIVRARE2 := V_DATA_LIVRARE;
|
|
V_ADRESA_FACTURARE1 := V_ADRESA_FACTURAREold;
|
|
V_ADRESA_LIVRARE1 := V_ADRESA_LIVRAREold;
|
|
END CASE;
|
|
|
|
UPDATE COMENZI
|
|
SET NR_COMANDA = V_NR_COMANDA,
|
|
DATA_COMANDA = V_DATA_COMANDA,
|
|
ID_PART = V_ID_PART,
|
|
ID_GESTIUNE = V_ID_GESTIUNE,
|
|
DATA_LIVRARE = V_DATA_LIVRARE2,
|
|
PROC_DISCOUNT = V_PROC_DISCOUNT,
|
|
INTERNA = V_INTERNA,
|
|
ID_SECTIE2 = V_ID_SECTIE2,
|
|
ID_FACTURARE = V_ADRESA_FACTURARE1,
|
|
ID_LIVRARE = V_ADRESA_LIVRARE1,
|
|
ID_CODCLIENT = V_ID_CODCLIENT1,
|
|
COMANDA_EXTERNA = V_COMANDA_EXTERNA1,
|
|
ID_CTR = V_ID_CTR,
|
|
ID_UTIL_UM = V_ID_UTIL,
|
|
DATAORA_UM = SYSDATE
|
|
WHERE ID_COMANDA = V_ID_COMANDA;
|
|
|
|
UPDATE COMENZI_ELEMENTE
|
|
SET DISCOUNT_UNITAR = ROUND(PRET * (V_PROC_DISCOUNT / 100),
|
|
pack_sesiune.getoptiunefirma('PPRETV'))
|
|
WHERE ID_COMANDA = V_ID_COMANDA;
|
|
|
|
pack_comenzi.actualizeaza_lucrare(V_ID_COMANDA, V_ID_UTIL, V_ID_SECTIE);
|
|
end modifica_comanda;
|
|
----------------------------------------------------------------------------------
|
|
procedure sterge_comanda(V_ID_COMANDA IN NUMBER, V_ID_UTIL IN NUMBER) is
|
|
V_DATAORAS DATE := SYSDATE;
|
|
V_STERS NUMBER(1) := 1;
|
|
V_NESTERS NUMBER(1) := 0;
|
|
V_ID_SECTIE NUMBER(5) := 0;
|
|
begin
|
|
UPDATE COMENZI_ELEMENTE
|
|
SET STERS = V_STERS, ID_UTILS = V_ID_UTIL, DATAORAS = V_DATAORAS
|
|
WHERE ID_COMANDA = V_ID_COMANDA
|
|
AND STERS = V_NESTERS;
|
|
|
|
SELECT ID_SECTIE
|
|
INTO V_ID_SECTIE
|
|
FROM COMENZI
|
|
WHERE STERS = V_NESTERS
|
|
AND ID_COMANDA = V_ID_COMANDA;
|
|
|
|
UPDATE COMENZI
|
|
SET STERS = V_STERS, ID_UTILS = V_ID_UTIL, DATAORAS = V_DATAORAS
|
|
WHERE ID_COMANDA = V_ID_COMANDA
|
|
AND STERS = V_NESTERS;
|
|
|
|
pack_comenzi.actualizeaza_lucrare(V_ID_COMANDA, V_ID_UTIL, V_ID_SECTIE);
|
|
end sterge_comanda;
|
|
----------------------------------------------------------------------------------
|
|
procedure cauta_contract_comanda(V_DATA_COMANDA IN DATE,
|
|
V_ID_PART IN NUMBER,
|
|
V_ID_SUCURSALA IN NUMBER,
|
|
V_ID_CTR OUT NUMBER,
|
|
V_NUMAR_CTR OUT VARCHAR2) is
|
|
begin
|
|
begin
|
|
select id_ctr as id,
|
|
numar || '/' || to_char(data, 'DD.MM.YYYY') as data
|
|
into V_ID_CTR, V_NUMAR_CTR
|
|
from contracte
|
|
where id_part = V_ID_PART
|
|
and incetat = 0
|
|
and sters = 0
|
|
and NVL(DATA_SFARSIT, V_DATA_COMANDA) >= V_DATA_COMANDA
|
|
and tip_istoric = 'C'
|
|
and NVL2(V_ID_SUCURSALA, ID_SUCURSALA, -99) =
|
|
NVL(V_ID_SUCURSALA, -99);
|
|
exception
|
|
when NO_DATA_FOUND then
|
|
V_NUMAR_CTR := NULL;
|
|
V_ID_CTR := NULL;
|
|
when TOO_MANY_ROWS then
|
|
V_NUMAR_CTR := NULL;
|
|
V_ID_CTR := NULL;
|
|
end;
|
|
|
|
end cauta_contract_comanda;
|
|
----------------------------------------------------------------------------------
|
|
procedure adauga_articol_comanda(V_ID_COMANDA IN NUMBER,
|
|
V_ID_ARTICOL IN NUMBER,
|
|
V_ID_POL IN NUMBER,
|
|
V_CANTITATE IN NUMBER,
|
|
V_ID_UTIL IN NUMBER,
|
|
V_ID_SECTIE IN NUMBER) is
|
|
V_PRET CRM_POLITICI_PRET_ART.PRET%TYPE;
|
|
begin
|
|
adauga_articol_comanda(V_ID_COMANDA,
|
|
V_ID_ARTICOL,
|
|
V_ID_POL,
|
|
V_CANTITATE,
|
|
V_PRET,
|
|
V_ID_UTIL,
|
|
V_ID_SECTIE);
|
|
end adauga_articol_comanda;
|
|
|
|
procedure adauga_articol_comanda(V_ID_COMANDA IN NUMBER,
|
|
V_ID_ARTICOL IN NUMBER,
|
|
V_ID_POL IN NUMBER,
|
|
V_CANTITATE IN NUMBER,
|
|
V_PRET IN NUMBER,
|
|
V_ID_UTIL IN NUMBER,
|
|
V_ID_SECTIE IN NUMBER) is
|
|
V_PRET2 CRM_POLITICI_PRET_ART.PRET%TYPE;
|
|
V_ID_VALUTA NOM_VALUTE.ID_VALUTA%TYPE;
|
|
V_PRET_CU_TVA CRM_POLITICI_PRETURI.PRETURI_CU_TVA%TYPE;
|
|
V_DISCOUNT_UNITAR COMENZI_ELEMENTE.DISCOUNT_UNITAR%TYPE := 0;
|
|
|
|
V_NR_INREG NUMBER(2);
|
|
V_DENUMIRE NOM_ARTICOLE.DENUMIRE%TYPE;
|
|
begin
|
|
begin
|
|
SELECT A.PRET, A.ID_VALUTA, B.PRETURI_CU_TVA
|
|
INTO V_PRET2, V_ID_VALUTA, V_PRET_CU_TVA
|
|
FROM CRM_POLITICI_PRET_ART A
|
|
LEFT JOIN CRM_POLITICI_PRETURI B
|
|
ON A.ID_POL = B.ID_POL
|
|
WHERE A.ID_POL = V_ID_POL
|
|
AND A.ID_ARTICOL = V_ID_ARTICOL;
|
|
exception
|
|
when NO_DATA_FOUND then
|
|
RAISE_APPLICATION_ERROR(-20000,
|
|
'Pretul pentru acest articol nu a fost gasit in lista de preturi! (COM-001)');
|
|
end;
|
|
|
|
IF V_PRET IS NOT NULL THEN
|
|
V_PRET2 := V_PRET;
|
|
END IF;
|
|
|
|
SELECT COUNT(*)
|
|
INTO V_NR_INREG
|
|
FROM COMENZI_ELEMENTE
|
|
WHERE ID_COMANDA = V_ID_COMANDA
|
|
AND ID_ARTICOL = V_ID_ARTICOL
|
|
AND STERS = 0;
|
|
|
|
IF V_NR_INREG > 0 THEN
|
|
SELECT DENUMIRE
|
|
INTO V_DENUMIRE
|
|
FROM NOM_ARTICOLE
|
|
WHERE ID_ARTICOL = V_ID_ARTICOL;
|
|
|
|
RAISE_APPLICATION_ERROR(-20000,
|
|
'Articolul ' || V_DENUMIRE ||
|
|
' a fost deja introdus pe aceasta comanda! Deschideti o alta instanta a programului de comenzi si verificati inainte sa reincercati salvarea datelor actuale!');
|
|
END IF;
|
|
|
|
INSERT INTO COMENZI_ELEMENTE
|
|
(ID_COMANDA,
|
|
ID_ARTICOL,
|
|
ID_POL,
|
|
PRET,
|
|
DISCOUNT_UNITAR,
|
|
CANTITATE,
|
|
ID_VALUTA,
|
|
PRET_CU_TVA,
|
|
ID_SECTIE)
|
|
VALUES
|
|
(V_ID_COMANDA,
|
|
V_ID_ARTICOL,
|
|
V_ID_POL,
|
|
V_PRET2,
|
|
V_DISCOUNT_UNITAR,
|
|
V_CANTITATE,
|
|
V_ID_VALUTA,
|
|
V_PRET_CU_TVA,
|
|
V_ID_SECTIE);
|
|
|
|
end adauga_articol_comanda;
|
|
----------------------------------------------------------------------------------
|
|
procedure modifica_articol_comanda(V_ID_COMANDA_ELEMENT IN NUMBER,
|
|
V_CANTITATE IN NUMBER,
|
|
V_ID_UTIL IN NUMBER) is
|
|
begin
|
|
UPDATE COMENZI_ELEMENTE
|
|
SET CANTITATE = V_CANTITATE
|
|
WHERE ID_COMANDA_ELEMENT = V_ID_COMANDA_ELEMENT;
|
|
end modifica_articol_comanda;
|
|
|
|
procedure modifica_articol_comanda(V_ID_COMANDA_ELEMENT IN NUMBER,
|
|
V_CANTITATE IN NUMBER,
|
|
V_PRET IN NUMBER,
|
|
V_ID_UTIL IN NUMBER) is
|
|
begin
|
|
UPDATE COMENZI_ELEMENTE
|
|
SET CANTITATE = V_CANTITATE, PRET = V_PRET
|
|
WHERE ID_COMANDA_ELEMENT = V_ID_COMANDA_ELEMENT;
|
|
end modifica_articol_comanda;
|
|
|
|
----------------------------------------------------------------------------------
|
|
/* procedure sterge_articol_comanda(V_ID_COMANDA IN NUMBER,
|
|
V_ID_ARTICOL IN NUMBER,
|
|
V_ID_POL IN NUMBER,
|
|
V_ID_UTIL IN NUMBER) is
|
|
V_STERS NUMBER(1) := 1;
|
|
V_DATAORAS DATE := SYSDATE;
|
|
begin
|
|
UPDATE COMENZI_ELEMENTE
|
|
SET STERS = V_STERS, DATAORAS = V_DATAORAS, ID_UTILS = V_ID_UTIL
|
|
WHERE ID_COMANDA = V_ID_COMANDA
|
|
AND ID_ARTICOL = V_ID_ARTICOL
|
|
AND ID_POL = V_ID_POL
|
|
AND STERS = 0;
|
|
end sterge_articol_comanda;*/
|
|
procedure sterge_articol_comanda(V_ID_COMANDA_ELEMENT IN NUMBER,
|
|
V_ID_UTIL IN NUMBER) is
|
|
V_STERS NUMBER(1) := 1;
|
|
V_DATAORAS DATE := SYSDATE;
|
|
begin
|
|
UPDATE COMENZI_ELEMENTE
|
|
SET STERS = V_STERS, DATAORAS = V_DATAORAS, ID_UTILS = V_ID_UTIL
|
|
WHERE ID_COMANDA_ELEMENT = V_ID_COMANDA_ELEMENT
|
|
AND STERS = 0;
|
|
end sterge_articol_comanda;
|
|
----------------------------------------------------------------------------------
|
|
procedure adauga_lucrare_pe_comanda(V_ID_COMANDA IN NUMBER,
|
|
V_ID_LUCRARE IN NUMBER,
|
|
V_ID_UTIL IN NUMBER,
|
|
V_ID_SECTIE IN NUMBER) is
|
|
V_ID_LUCRARE_VECHE NOM_LUCRARI.ID_LUCRARE%TYPE;
|
|
begin
|
|
SELECT ID_LUCRARE
|
|
INTO V_ID_LUCRARE_VECHE
|
|
FROM COMENZI
|
|
WHERE ID_COMANDA = V_ID_COMANDA;
|
|
|
|
UPDATE COMENZI
|
|
SET ID_LUCRARE = V_ID_LUCRARE
|
|
WHERE ID_COMANDA = V_ID_COMANDA;
|
|
|
|
IF V_ID_LUCRARE_VECHE IS NOT NULL THEN
|
|
pack_comenzi.actualizeaza_articole_lucrare(V_ID_LUCRARE_VECHE,
|
|
V_ID_UTIL,
|
|
V_ID_SECTIE);
|
|
END IF;
|
|
end;
|
|
----------------------------------------------------------------------------------
|
|
procedure adauga_lucrare_pe_comenzi(V_SIR_COMENZI IN VARCHAR2,
|
|
V_ID_LUCRARE IN NUMBER,
|
|
V_ID_UTIL IN NUMBER,
|
|
V_ID_SECTIE IN NUMBER) is
|
|
V_ID_COMANDA COMENZI.ID_COMANDA%TYPE;
|
|
V_LUNGIME_SIR NUMBER(10);
|
|
begin
|
|
V_LUNGIME_SIR := SIR_IN_SIR(V_SIR_COMENZI, ';');
|
|
|
|
FOR i IN 1 .. V_LUNGIME_SIR LOOP
|
|
V_ID_COMANDA := TO_NUMBER(ELEMENT_DIN_SIR(V_SIR_COMENZI, ';', i));
|
|
pack_comenzi.adauga_lucrare_pe_comanda(V_ID_COMANDA,
|
|
V_ID_LUCRARE,
|
|
V_ID_UTIL,
|
|
V_ID_SECTIE);
|
|
END LOOP;
|
|
|
|
pack_comenzi.actualizeaza_articole_lucrare(V_ID_LUCRARE,
|
|
V_ID_UTIL,
|
|
V_ID_SECTIE);
|
|
end;
|
|
----------------------------------------------------------------------------------
|
|
procedure livreaza_comanda(V_ID_COMANDA IN NUMBER,
|
|
V_ID_AGENT IN NUMBER,
|
|
V_ID_DELEGAT IN NUMBER,
|
|
V_ID_MASINA IN NUMBER,
|
|
V_DATA_LIVRAT IN DATE,
|
|
V_ID_UTIL IN NUMBER,
|
|
V_NR_LIVRARE OUT VARCHAR2) is
|
|
V_ID_PART NOM_PARTENERI.ID_PART%TYPE;
|
|
begin
|
|
V_NR_LIVRARE := genereaza_nr_livrare();
|
|
UPDATE COMENZI
|
|
SET ID_AGENT = V_ID_AGENT,
|
|
ID_DELEGAT = V_ID_DELEGAT,
|
|
ID_MASINA = V_ID_MASINA,
|
|
DATA_LIVRAT = V_DATA_LIVRAT,
|
|
NR_LIVRARE = V_NR_LIVRARE
|
|
WHERE ID_COMANDA = V_ID_COMANDA
|
|
RETURNING ID_PART INTO V_ID_PART;
|
|
|
|
IF V_ID_PART IS NOT NULL THEN
|
|
MERGE INTO CORESP_DELEGATI_PART A
|
|
USING dual
|
|
ON (A.ID_PART = V_ID_PART AND A.ID_DELEGAT = V_ID_DELEGAT)
|
|
WHEN NOT MATCHED THEN
|
|
INSERT (ID_PART, ID_DELEGAT) VALUES (V_ID_PART, V_ID_DELEGAT);
|
|
END IF;
|
|
end;
|
|
----------------------------------------------------------------------------------
|
|
procedure genereaza_lucrare(V_DATA_LUCRARE IN DATE,
|
|
V_ORE_EXECUTIE IN NUMBER,
|
|
V_ID_UTIL IN NUMBER,
|
|
V_ID_SECTIE IN NUMBER,
|
|
V_NRORD OUT VARCHAR2,
|
|
V_ID_LUCRARE OUT NUMBER) is
|
|
V_DATAORA DATE;
|
|
begin
|
|
pack_sesiune.set_id_sectie_comenzi(V_ID_SECTIE);
|
|
V_DATAORA := sysdate;
|
|
|
|
begin
|
|
select a.csectie || to_char(NVL(V_DATA_LUCRARE, V_DATAORA), 'DDMMYY') || '-' ||
|
|
(select count(*) + 1 as nr
|
|
from nom_lucrari
|
|
where nrord like
|
|
a.csectie ||
|
|
to_char(NVL(V_DATA_LUCRARE, V_DATAORA), 'DDMMYY') || '%'
|
|
and sters = 0)
|
|
INTO V_NRORD
|
|
from nom_sectii a
|
|
where a.id_sectie = V_ID_SECTIE;
|
|
exception
|
|
WHEN NO_DATA_FOUND THEN
|
|
select to_char(NVL(V_DATA_LUCRARE, V_DATAORA), 'DDMMYY') || '-' ||
|
|
(count(*) + 1)
|
|
INTO V_NRORD
|
|
from nom_lucrari
|
|
where nrord like
|
|
to_char(NVL(V_DATA_LUCRARE, V_DATAORA), 'DDMMYY') || '%'
|
|
and sters = 0;
|
|
end;
|
|
|
|
INSERT INTO NOM_LUCRARI
|
|
(NRORD)
|
|
VALUES
|
|
(V_NRORD)
|
|
RETURNING ID_LUCRARE INTO V_ID_LUCRARE;
|
|
|
|
INSERT INTO LUCRARI_DETALII
|
|
(ID_LUCRARE, DATA_LUCRARE, TERMEN_EXECUTIE, ID_UTIL, ID_SECTIE)
|
|
VALUES
|
|
(V_ID_LUCRARE,
|
|
NVL(V_DATA_LUCRARE, V_DATAORA),
|
|
NVL(V_DATA_LUCRARE, V_DATAORA) +
|
|
GREATEST((pack_comenzi.citeste_ore_inchidere(V_ID_SECTIE) / 24) + 0.5,
|
|
NVL(V_ORE_EXECUTIE, 1),
|
|
1),
|
|
V_ID_UTIL,
|
|
V_ID_SECTIE);
|
|
|
|
end genereaza_lucrare;
|
|
----------------------------------------------------------------------------------
|
|
procedure adauga_lucrare(V_NRORD IN VARCHAR2,
|
|
V_DATA_LUCRARE IN DATE,
|
|
V_EXPLICATIE IN VARCHAR2,
|
|
V_TERMEN_EXECUTIE IN DATE,
|
|
V_ID_UTIL IN NUMBER,
|
|
V_ID_SECTIE IN NUMBER) is
|
|
|
|
V_NR_LUCRARI NUMBER(10);
|
|
V_NESTERS NUMBER := 0;
|
|
V_ID_LUCRARE NOM_LUCRARI.ID_LUCRARE%TYPE;
|
|
V_DATA_LUCRARE_INCHISA DATE;
|
|
begin
|
|
pack_sesiune.set_id_sectie_comenzi(V_ID_SECTIE);
|
|
|
|
SELECT COUNT(*)
|
|
INTO V_NR_LUCRARI
|
|
FROM NOM_LUCRARI
|
|
WHERE STERS = V_NESTERS
|
|
AND NRORD = V_NRORD;
|
|
|
|
IF V_NR_LUCRARI > 0 THEN
|
|
RAISE_APPLICATION_ERROR(-20000,
|
|
'Mai exista o lucrare cu acest numar!');
|
|
END IF;
|
|
|
|
V_DATA_LUCRARE_INCHISA := sysdate +
|
|
(pack_comenzi.citeste_ore_inchidere(V_ID_SECTIE) / 24);
|
|
|
|
IF V_TERMEN_EXECUTIE <= V_DATA_LUCRARE_INCHISA THEN
|
|
RAISE_APPLICATION_ERROR(-20000,
|
|
'Termenul de executie trebuie sa fie mai mare de ' ||
|
|
to_char(V_DATA_LUCRARE_INCHISA,
|
|
'DD/MM/YYYY HH24:MI') ||
|
|
' pentru ca sa puteti adauga comenzi pe aceasta lucrare!');
|
|
END IF;
|
|
|
|
INSERT INTO NOM_LUCRARI
|
|
(NRORD)
|
|
VALUES
|
|
(V_NRORD)
|
|
RETURNING ID_LUCRARE INTO V_ID_LUCRARE;
|
|
|
|
INSERT INTO LUCRARI_DETALII
|
|
(ID_LUCRARE,
|
|
DATA_LUCRARE,
|
|
EXPLICATIE,
|
|
TERMEN_EXECUTIE,
|
|
ID_UTIL,
|
|
ID_SECTIE)
|
|
VALUES
|
|
(V_ID_LUCRARE,
|
|
V_DATA_LUCRARE,
|
|
V_EXPLICATIE,
|
|
V_TERMEN_EXECUTIE,
|
|
V_ID_UTIL,
|
|
V_ID_SECTIE);
|
|
end adauga_lucrare;
|
|
----------------------------------------------------------------------------------
|
|
procedure modifica_lucrare(V_ID_LUCRARE IN NUMBER,
|
|
V_NRORD IN VARCHAR2,
|
|
V_DATA_LUCRARE IN DATE,
|
|
V_EXPLICATIE IN VARCHAR2,
|
|
V_TERMEN_EXECUTIE IN DATE,
|
|
V_ID_UTIL IN NUMBER) is
|
|
V_NR_LUCRARI NUMBER(10);
|
|
V_NR_COMENZI NUMBER(10);
|
|
V_NESTERS NUMBER := 0;
|
|
begin
|
|
SELECT COUNT(*)
|
|
INTO V_NR_LUCRARI
|
|
FROM NOM_LUCRARI
|
|
WHERE STERS = V_NESTERS
|
|
AND NRORD = V_NRORD
|
|
AND ID_LUCRARE <> V_ID_LUCRARE;
|
|
|
|
IF V_NR_LUCRARI > 0 THEN
|
|
RAISE_APPLICATION_ERROR(-20000,
|
|
'Mai exista o lucrare cu acest numar!');
|
|
END IF;
|
|
|
|
SELECT COUNT(*)
|
|
INTO V_NR_COMENZI
|
|
FROM COMENZI
|
|
WHERE STERS = V_NESTERS
|
|
AND ID_LUCRARE = V_ID_LUCRARE
|
|
AND DATA_COMANDA > V_TERMEN_EXECUTIE;
|
|
|
|
IF V_NR_COMENZI > 0 THEN
|
|
RAISE_APPLICATION_ERROR(-20000,
|
|
'Exista ' || V_NR_COMENZI ||
|
|
' comenzi cu data mai mare decat termenul de executie al lucrarii!');
|
|
END IF;
|
|
|
|
UPDATE NOM_LUCRARI SET NRORD = V_NRORD WHERE ID_LUCRARE = V_ID_LUCRARE;
|
|
|
|
UPDATE LUCRARI_DETALII
|
|
SET DATA_LUCRARE = V_DATA_LUCRARE,
|
|
EXPLICATIE = V_EXPLICATIE,
|
|
TERMEN_EXECUTIE = V_TERMEN_EXECUTIE
|
|
WHERE ID_LUCRARE = V_ID_LUCRARE;
|
|
end modifica_lucrare;
|
|
----------------------------------------------------------------------------------
|
|
procedure sterge_lucrare(V_ID_LUCRARE IN NUMBER, V_ID_UTIL IN NUMBER) is
|
|
/* V_NR_COMENZI NUMBER(10);
|
|
V_STERS NUMBER(1) := 1;
|
|
V_NESTERS NUMBER(1) := 0;*/
|
|
V_STERS NUMBER(1) := 1;
|
|
V_LOOKUP VARCHAR2(100);
|
|
V_NR_INREGISTRARI NUMBER(5);
|
|
begin
|
|
/* V_LOOKUP := 'COMENZI.ID_LUCRARE;RUL.ID_LUCRARE;';
|
|
|
|
nomdelprocn(USER, 'NOM_LUCRARI', 'ID_LUCRARE', V_ID_LUCRARE, V_LOOKUP);*/
|
|
|
|
SELECT SUM(NR)
|
|
INTO V_NR_INREGISTRARI
|
|
FROM (SELECT COUNT(*) AS NR
|
|
FROM COMENZI
|
|
WHERE ID_LUCRARE = V_ID_LUCRARE
|
|
AND STERS = 0
|
|
/* UNION ALL
|
|
SELECT COUNT(*)
|
|
FROM RUL
|
|
WHERE ID_LUCRARE = V_ID_LUCRARE
|
|
AND STERS = 0
|
|
UNION ALL
|
|
SELECT COUNT(*)
|
|
FROM ACT
|
|
WHERE ID_LUCRARE = V_ID_LUCRARE
|
|
AND STERS = 0*/
|
|
);
|
|
|
|
IF V_NR_INREGISTRARI > 0 THEN
|
|
RAISE_APPLICATION_ERROR(-20000,
|
|
'Nu se pot sterge detaliile, deoarece mai exista comenzi pe lucrare!');
|
|
END IF;
|
|
|
|
UPDATE LUCRARI_DETALII
|
|
SET STERS = V_STERS
|
|
WHERE ID_LUCRARE = V_ID_LUCRARE;
|
|
/* SELECT COUNT(*)
|
|
INTO V_NR_COMENZI
|
|
FROM COMENZI
|
|
WHERE STERS = V_NESTERS
|
|
AND ID_LUCRARE = V_ID_LUCRARE;
|
|
|
|
IF V_NR_COMENZI > 0 THEN
|
|
RAISE_APPLICATION_ERROR(-20000, 'Pe aceasta lucrare exista comenzi!');
|
|
END IF;
|
|
|
|
UPDATE NOM_LUCRARI SET STERS = V_STERS WHERE ID_LUCRARE = V_ID_LUCRARE;
|
|
|
|
UPDATE LUCRARI_DETALII
|
|
SET STERS = V_STERS
|
|
WHERE ID_LUCRARE = V_ID_LUCRARE;*/
|
|
end sterge_lucrare;
|
|
----------------------------------------------------------------------------------
|
|
procedure actualizeaza_lucrare(V_ID_COMANDA IN NUMBER,
|
|
V_ID_UTIL IN NUMBER,
|
|
V_ID_SECTIE IN NUMBER) is
|
|
V_ID_LUCRARE NOM_LUCRARI.ID_LUCRARE%TYPE;
|
|
V_NESTERS NUMBER(1) := 0;
|
|
begin
|
|
SELECT ID_LUCRARE
|
|
INTO V_ID_LUCRARE
|
|
FROM COMENZI
|
|
WHERE ID_COMANDA = V_ID_COMANDA;
|
|
|
|
IF V_ID_LUCRARE IS NOT NULL THEN
|
|
pack_comenzi.actualizeaza_articole_lucrare(V_ID_LUCRARE,
|
|
V_ID_UTIL,
|
|
V_ID_SECTIE);
|
|
END IF;
|
|
|
|
end actualizeaza_lucrare;
|
|
----------------------------------------------------------------------------------
|
|
procedure actualizeaza_articole_lucrare(V_ID_LUCRARE IN NUMBER,
|
|
V_ID_UTIL IN NUMBER,
|
|
V_ID_SECTIE IN NUMBER) is
|
|
V_NESTERS NUMBER(1) := 0;
|
|
V_ID_POL NUMBER(10);
|
|
V_ACTIVA NUMBER(1);
|
|
V_EXISTA NUMBER(1);
|
|
V_ACTIVA_UTIL NUMBER(1);
|
|
V_OPTIUNE VARCHAR2(100);
|
|
begin
|
|
V_OPTIUNE := 'ID_LISTA_PRETURI_PV';
|
|
|
|
pack_preturi.optiune_polpret_utilizator_sec(V_ID_UTIL,
|
|
V_ID_SECTIE,
|
|
V_OPTIUNE,
|
|
V_ID_POL);
|
|
|
|
DELETE FROM LUCRARI_ELEMENTE WHERE ID_LUCRARE = V_ID_LUCRARE;
|
|
|
|
INSERT INTO LUCRARI_ELEMENTE
|
|
(ID_LUCRARE,
|
|
ID_ARTICOL,
|
|
ID_POL,
|
|
PRET,
|
|
DISCOUNT_UNITAR,
|
|
CANTITATE,
|
|
ID_SECTIE)
|
|
SELECT V_ID_LUCRARE AS ID_LUCRARE,
|
|
A.ID_ARTICOL,
|
|
V_ID_POL AS ID_POL,
|
|
B.PRET,
|
|
A.DISCOUNT_UNITAR,
|
|
SUM(A.CANTITATE) AS CANTITATE,
|
|
V_ID_SECTIE AS ID_SECTIE
|
|
FROM COMENZI_ELEMENTE A
|
|
LEFT JOIN CRM_POLITICI_PRET_ART B
|
|
ON A.ID_ARTICOL = B.ID_ARTICOL
|
|
AND B.ID_POL = V_ID_POL
|
|
LEFT JOIN NOM_ARTICOLE C
|
|
ON B.ID_ARTICOL = C.ID_ARTICOL
|
|
WHERE A.ID_COMANDA IN
|
|
(SELECT ID_COMANDA
|
|
FROM COMENZI
|
|
WHERE ID_LUCRARE = V_ID_LUCRARE
|
|
AND STERS = V_NESTERS
|
|
AND ID_SECTIE = V_ID_SECTIE)
|
|
AND A.STERS = V_NESTERS
|
|
AND C.IN_STOC = 1
|
|
GROUP BY A.ID_ARTICOL, B.ID_POL, B.PRET, A.DISCOUNT_UNITAR;
|
|
end actualizeaza_articole_lucrare;
|
|
----------------------------------------------------------------------------------
|
|
procedure adauga_loturi(V_ID_LUCRARE IN NUMBER, V_ID_UTIL IN NUMBER) is
|
|
cursor crs is
|
|
SELECT A.ID_ARTICOL,
|
|
A.CANTITATE,
|
|
A.ID_POL,
|
|
A.PRET,
|
|
A.DISCOUNT_UNITAR,
|
|
A.ID_SECTIE,
|
|
B.CODMAT
|
|
FROM LUCRARI_ELEMENTE A
|
|
LEFT JOIN NOM_ARTICOLE B
|
|
ON A.ID_ARTICOL = B.ID_ARTICOL
|
|
WHERE A.ID_LUCRARE = V_ID_LUCRARE;
|
|
|
|
crs_linie crs%rowtype;
|
|
V_ID_LOT NOM_LUCRARI.ID_LUCRARE%TYPE;
|
|
begin
|
|
UPDATE LUCRARI_ELEMENTE
|
|
SET CANTITATE = 0
|
|
WHERE ID_LUCRARE IN
|
|
(SELECT ID_LUCRARE FROM NOM_LUCRARI WHERE ID_TATA = V_ID_LUCRARE);
|
|
|
|
open crs;
|
|
loop
|
|
fetch crs
|
|
into crs_linie;
|
|
exit when crs%notfound;
|
|
|
|
begin
|
|
SELECT ID_LUCRARE
|
|
INTO V_ID_LOT
|
|
FROM NOM_LUCRARI
|
|
WHERE ID_TATA = V_ID_LUCRARE
|
|
AND NVL(NRORD, '~!') = NVL(crs_linie.codmat, '~!')
|
|
AND STERS = 0;
|
|
exception
|
|
when NO_DATA_FOUND then
|
|
INSERT INTO NOM_LUCRARI
|
|
(NRORD, ID_TATA)
|
|
VALUES
|
|
(crs_linie.codmat, V_ID_LUCRARE)
|
|
RETURNING ID_LUCRARE INTO V_ID_LOT;
|
|
end;
|
|
|
|
MERGE INTO LUCRARI_ELEMENTE A
|
|
USING DUAL B
|
|
ON (A.ID_LUCRARE = V_ID_LOT AND A.ID_ARTICOL = crs_linie.id_articol AND A.ID_POL = crs_linie.id_pol AND A.PRET = crs_linie.pret AND NVL(A.ID_SECTIE, -100) = NVL(crs_linie.id_sectie, -100))
|
|
WHEN MATCHED THEN
|
|
UPDATE SET CANTITATE = crs_linie.cantitate
|
|
WHEN NOT MATCHED THEN
|
|
INSERT
|
|
(ID_LUCRARE,
|
|
ID_ARTICOL,
|
|
CANTITATE,
|
|
ID_POL,
|
|
PRET,
|
|
DISCOUNT_UNITAR,
|
|
ID_SECTIE)
|
|
VALUES
|
|
(V_ID_LOT,
|
|
crs_linie.id_articol,
|
|
crs_linie.cantitate,
|
|
crs_linie.id_pol,
|
|
crs_linie.pret,
|
|
crs_linie.discount_unitar,
|
|
crs_linie.id_sectie);
|
|
|
|
end loop;
|
|
|
|
close crs;
|
|
end adauga_loturi;
|
|
----------------------------------------------------------------------------------
|
|
procedure sterge_loturi(V_ID_LUCRARE IN NUMBER, V_ID_UTIL IN NUMBER) is
|
|
begin
|
|
DELETE FROM LUCRARI_ELEMENTE
|
|
WHERE ID_LUCRARE IN
|
|
(SELECT ID_LUCRARE FROM NOM_LUCRARI WHERE ID_TATA = V_ID_LUCRARE);
|
|
|
|
UPDATE NOM_LUCRARI SET STERS = 1 WHERE ID_TATA = V_ID_LUCRARE;
|
|
end sterge_loturi;
|
|
----------------------------------------------------------------------------------
|
|
/*function citeste_ore_inchidere return number is
|
|
V_NR_ORE NUMBER(2);
|
|
begin
|
|
begin
|
|
SELECT TO_NUMBER(VARVALUE)
|
|
INTO V_NR_ORE
|
|
FROM OPTIUNI
|
|
WHERE VARNAME = 'ORE_INCHIDERE';
|
|
exception
|
|
WHEN NO_DATA_FOUND THEN
|
|
raise_application_error(-20000,
|
|
'Nu este setata perioada de dinaintea termenului de executie pentru care o lucrare este considerata inchisa!');
|
|
end;
|
|
return V_NR_ORE;
|
|
end;*/
|
|
----------------------------------------------------------------------------------
|
|
function genereaza_nr_comanda return varchar2 is
|
|
V_NR_COMANDA COMENZI.NR_COMANDA%TYPE;
|
|
begin
|
|
SELECT TO_CHAR(SEQ_NR_COMANDA.NEXTVAL) INTO V_NR_COMANDA FROM DUAL;
|
|
return V_NR_COMANDA;
|
|
end;
|
|
----------------------------------------------------------------------------------
|
|
function genereaza_nr_lucrare return varchar2 is
|
|
V_NRORD NOM_LUCRARI.NRORD%TYPE;
|
|
V_VALIDAT NUMBER(1);
|
|
V_NESTERS NUMBER(1) := 0;
|
|
V_NR_LUCRARI NUMBER(10);
|
|
begin
|
|
V_VALIDAT := 1;
|
|
LOOP
|
|
SELECT TO_CHAR(SEQ_NR_LUCRARE.NEXTVAL) INTO V_NRORD FROM DUAL;
|
|
|
|
SELECT COUNT(*)
|
|
INTO V_NR_LUCRARI
|
|
FROM NOM_LUCRARI
|
|
WHERE STERS = V_NESTERS
|
|
AND NRORD = V_NRORD;
|
|
|
|
IF V_NR_LUCRARI > 0 THEN
|
|
V_VALIDAT := 0;
|
|
ELSE
|
|
V_VALIDAT := 1;
|
|
END IF;
|
|
|
|
EXIT WHEN V_VALIDAT = 1;
|
|
END LOOP;
|
|
return V_NRORD;
|
|
end;
|
|
----------------------------------------------------------------------------------
|
|
function genereaza_nr_livrare return varchar2 is
|
|
V_NR_LIVRARE NOM_LUCRARI.NRORD%TYPE;
|
|
begin
|
|
SELECT TO_CHAR(SEQ_NR_LIVRARE.NEXTVAL) INTO V_NR_LIVRARE FROM DUAL;
|
|
return V_NR_LIVRARE;
|
|
end;
|
|
----------------------------------------------------------------------------------
|
|
procedure copiaza_comanda(V_ID_COMANDA IN NUMBER,
|
|
V_OPTIUNE_CANT IN NUMBER,
|
|
V_ID_UTIL IN NUMBER,
|
|
V_ID_COMANDA_NOU OUT NUMBER) is
|
|
|
|
V_NR_COMANDA varchar2(100);
|
|
V_DATA_COMANDA date;
|
|
V_ID_PART NOM_PARTENERI.ID_PART%TYPE;
|
|
V_ID_GESTIUNE NOM_GESTIUNI.ID_GESTIUNE%TYPE;
|
|
V_DATA_LIVRARE date;
|
|
V_INTERNA number(1);
|
|
V_OPTIUNE OPTIUNI.VARNAME%TYPE;
|
|
V_COPIERECANTITATE NUMBER(1);
|
|
V_ID_POL CRM_POLITICI_PRETURI.ID_POL%TYPE;
|
|
V_ID_SECTIE NOM_SECTII.ID_SECTIE%TYPE;
|
|
V_ID_SECTIE2 NOM_SECTII.ID_SECTIE%TYPE;
|
|
V_ID_LIVRARE ADRESE_PARTENERI.ID_ADRESA%TYPE;
|
|
V_ID_FACTURARE ADRESE_PARTENERI.ID_ADRESA%TYPE;
|
|
V_ID_CODCLIENT COMENZI.ID_CODCLIENT%TYPE;
|
|
V_ID_SUCURSALA SYN_NOM_FIRME.ID_FIRMA%TYPE;
|
|
V_PROC_DISCOUNT COMENZI.PROC_DISCOUNT%TYPE;
|
|
begin
|
|
SELECT ID_PART,
|
|
INTERNA,
|
|
ID_GESTIUNE,
|
|
ID_SECTIE,
|
|
ID_SECTIE2,
|
|
ID_LIVRARE,
|
|
ID_FACTURARE,
|
|
ID_CODCLIENT,
|
|
ID_SUCURSALA,
|
|
PROC_DISCOUNT
|
|
INTO V_ID_PART,
|
|
V_INTERNA,
|
|
V_ID_GESTIUNE,
|
|
V_ID_SECTIE,
|
|
V_ID_SECTIE2,
|
|
V_ID_LIVRARE,
|
|
V_ID_FACTURARE,
|
|
V_ID_CODCLIENT,
|
|
V_ID_SUCURSALA,
|
|
V_PROC_DISCOUNT
|
|
FROM COMENZI
|
|
WHERE ID_COMANDA = V_ID_COMANDA;
|
|
|
|
V_NR_COMANDA := pack_comenzi.genereaza_nr_comanda();
|
|
V_DATA_COMANDA := SYSDATE;
|
|
V_DATA_LIVRARE := V_DATA_COMANDA + NVL(to_number(pack_comenzi.extrage_optiuni(pack_sesiune.getoptiunefirma('ORE_LIVRARE'),
|
|
V_ID_SECTIE)),
|
|
0) / 24;
|
|
|
|
IF V_OPTIUNE_CANT IS NULL THEN
|
|
BEGIN
|
|
SELECT NVL(to_number(pack_comenzi.extrage_optiuni(pack_sesiune.getoptiunefirma('COPIERECANTITATE'),
|
|
V_ID_SECTIE)),
|
|
0)
|
|
INTO V_COPIERECANTITATE
|
|
FROM OPTIUNI
|
|
WHERE VARNAME = 'COPIERECANTITATE';
|
|
EXCEPTION
|
|
WHEN NO_DATA_FOUND THEN
|
|
RAISE_APPLICATION_ERROR(-20000,
|
|
'Nu ati setat optiunea pentru copierea cantitatilor pe comenzi!');
|
|
END;
|
|
ELSE
|
|
V_COPIERECANTITATE := V_OPTIUNE_CANT;
|
|
END IF;
|
|
|
|
CASE
|
|
WHEN V_INTERNA = 1 THEN
|
|
V_OPTIUNE := 'ID_LISTA_PRETURI_PV';
|
|
WHEN V_INTERNA = 2 THEN
|
|
V_OPTIUNE := 'IDPOLITICAPRETC';
|
|
WHEN V_INTERNA = 3 THEN
|
|
V_OPTIUNE := 'IDPOLITICAPRET';
|
|
END CASE;
|
|
|
|
pack_preturi.optiune_polpret_utilizator_sec(V_ID_UTIL,
|
|
V_ID_SECTIE,
|
|
V_OPTIUNE,
|
|
V_ID_POL);
|
|
|
|
INSERT INTO COMENZI
|
|
(NR_COMANDA,
|
|
DATA_COMANDA,
|
|
ID_PART,
|
|
ID_GESTIUNE,
|
|
ID_SECTIE,
|
|
DATA_LIVRARE,
|
|
INTERNA,
|
|
ID_UTIL,
|
|
DATAORA,
|
|
ID_SECTIE2,
|
|
ID_LIVRARE,
|
|
ID_FACTURARE,
|
|
ID_CODCLIENT,
|
|
ID_SUCURSALA,
|
|
PROC_DISCOUNT)
|
|
VALUES
|
|
(V_NR_COMANDA,
|
|
V_DATA_COMANDA,
|
|
V_ID_PART,
|
|
V_ID_GESTIUNE,
|
|
V_ID_SECTIE,
|
|
V_DATA_LIVRARE,
|
|
V_INTERNA,
|
|
V_ID_UTIL,
|
|
SYSDATE,
|
|
V_ID_SECTIE2,
|
|
V_ID_LIVRARE,
|
|
V_ID_FACTURARE,
|
|
V_ID_CODCLIENT,
|
|
V_ID_SUCURSALA,
|
|
V_PROC_DISCOUNT)
|
|
RETURNING id_comanda INTO V_ID_COMANDA_NOU;
|
|
|
|
IF V_COPIERECANTITATE = 1 THEN
|
|
INSERT INTO comenzi_elemente
|
|
(id_comanda,
|
|
id_articol,
|
|
id_pol,
|
|
pret,
|
|
discount_unitar,
|
|
cantitate,
|
|
id_valuta,
|
|
id_sectie,
|
|
pret_cu_tva)
|
|
SELECT V_ID_COMANDA_NOU as id_comanda,
|
|
A.ID_ARTICOL,
|
|
V_ID_POL AS ID_POL,
|
|
B.PRET,
|
|
A.DISCOUNT_UNITAR,
|
|
A.CANTITATE,
|
|
C.ID_VALUTA,
|
|
V_ID_SECTIE,
|
|
C.PRETURI_CU_TVA AS PRET_CU_TVA
|
|
FROM (SELECT A.ID_ARTICOL,
|
|
SUM(A.CANTITATE) AS CANTITATE,
|
|
A.DISCOUNT_UNITAR,
|
|
MIN(A.ID_COMANDA_ELEMENT) AS ID
|
|
FROM COMENZI_ELEMENTE A
|
|
WHERE A.ID_COMANDA = V_ID_COMANDA
|
|
AND A.STERS = 0
|
|
GROUP BY A.ID_ARTICOL, A.DISCOUNT_UNITAR
|
|
ORDER BY 4) A
|
|
LEFT JOIN CRM_POLITICI_PRET_ART B
|
|
ON A.ID_ARTICOL = B.ID_ARTICOL
|
|
LEFT JOIN CRM_POLITICI_PRETURI C
|
|
ON B.ID_POL = C.ID_POL
|
|
WHERE A.CANTITATE > 0
|
|
AND B.ID_POL = V_ID_POL;
|
|
ELSE
|
|
INSERT INTO comenzi_elemente
|
|
(id_comanda,
|
|
id_articol,
|
|
id_pol,
|
|
pret,
|
|
discount_unitar,
|
|
cantitate,
|
|
id_valuta,
|
|
id_sectie,
|
|
pret_cu_tva)
|
|
SELECT V_ID_COMANDA_NOU as id_comanda,
|
|
A.ID_ARTICOL,
|
|
V_ID_POL AS ID_POL,
|
|
B.PRET,
|
|
A.DISCOUNT_UNITAR,
|
|
A.CANTITATE,
|
|
C.ID_VALUTA,
|
|
V_ID_SECTIE,
|
|
C.PRETURI_CU_TVA AS PRET_CU_TVA
|
|
FROM (select ID_ARTICOL,
|
|
DISCOUNT_UNITAR,
|
|
CANTITATE,
|
|
ID_COMANDA_ELEMENT
|
|
from COMENZI_ELEMENTE
|
|
WHERE ID_COMANDA = V_ID_COMANDA
|
|
AND STERS = 0
|
|
AND CANTITATE > 0
|
|
order by ID_COMANDA_ELEMENT) A
|
|
LEFT JOIN CRM_POLITICI_PRET_ART B
|
|
ON A.ID_ARTICOL = B.ID_ARTICOL
|
|
LEFT JOIN CRM_POLITICI_PRETURI C
|
|
ON B.ID_POL = C.ID_POL
|
|
where B.ID_POL = V_ID_POL;
|
|
END IF;
|
|
end copiaza_comanda;
|
|
----------------------------------------------------------------------------------
|
|
procedure copiaza_comenzi(V_SIR_ID_COMANDA IN VARCHAR2,
|
|
V_SEPARATOR_PARAM IN VARCHAR2,
|
|
V_ID_UTIL IN NUMBER) is
|
|
|
|
TYPE num_rec IS RECORD(
|
|
id_comanda dbms_sql.Number_Table);
|
|
numtab num_rec;
|
|
|
|
V_ID_COMANDA_NOU COMENZI.ID_COMANDA%TYPE;
|
|
V_SEPARATOR VARCHAR2(5);
|
|
V_COPIERECANTITATE NUMBER(1);
|
|
begin
|
|
V_SEPARATOR := NVL(V_SEPARATOR_PARAM, ',');
|
|
|
|
BEGIN
|
|
SELECT TO_NUMBER(VARVALUE)
|
|
INTO V_COPIERECANTITATE
|
|
FROM OPTIUNI
|
|
WHERE VARNAME = 'COPIERECANTITATE';
|
|
EXCEPTION
|
|
WHEN NO_DATA_FOUND THEN
|
|
RAISE_APPLICATION_ERROR(-20000,
|
|
'Nu ati setat optiunea pentru copierea cantitatilor pe comenzi!');
|
|
END;
|
|
|
|
SELECT TO_NUMBER(substr(V_SIR_ID_COMANDA,
|
|
decode(rownum,
|
|
1,
|
|
1,
|
|
instr(V_SIR_ID_COMANDA,
|
|
V_SEPARATOR,
|
|
1,
|
|
rownum - 1) + 1),
|
|
instr(V_SIR_ID_COMANDA, V_SEPARATOR, 1, rownum) -
|
|
decode(rownum,
|
|
1,
|
|
0,
|
|
instr(V_SIR_ID_COMANDA,
|
|
V_SEPARATOR,
|
|
1,
|
|
rownum - 1)) - 1)) AS ID_COMANDA
|
|
BULK COLLECT
|
|
INTO numtab
|
|
FROM dual
|
|
CONNECT BY level <= length(V_SIR_ID_COMANDA) -
|
|
length(REPLACE(V_SIR_ID_COMANDA, V_SEPARATOR));
|
|
|
|
FOR i IN 1 .. numtab.id_comanda.count LOOP
|
|
pack_comenzi.copiaza_comanda(numtab.id_comanda(i),
|
|
V_COPIERECANTITATE,
|
|
V_ID_UTIL,
|
|
V_ID_COMANDA_NOU);
|
|
END LOOP;
|
|
|
|
end copiaza_comenzi;
|
|
----------------------------------------------------------------------------------
|
|
procedure sectii_utilizator(V_ID_UTIL IN NUMBER,
|
|
V_ID_SUCURSALA IN NUMBER,
|
|
p_cursor OUT pack_types.tip_cursor) IS
|
|
-- sectiile la care este asociat partenerul legat de utilizator
|
|
|
|
begin
|
|
|
|
open p_cursor for
|
|
select ps.id_sectie, s.sectie
|
|
from asociere_parteneri_sectii ps
|
|
left join nom_sectii s
|
|
on ps.id_sectie = s.id_sectie
|
|
where ps.id_part in (select id_partener
|
|
from vutilizatori_rol_intern
|
|
where id_util = V_ID_UTIL)
|
|
and NVL2(V_ID_SUCURSALA, s.id_sucursala, -99) =
|
|
NVL(V_ID_SUCURSALA, -99)
|
|
order by s.sectie;
|
|
|
|
end sectii_utilizator;
|
|
----------------------------------------------------------------------------------
|
|
function extrage_optiuni(tcLista varchar2, tnId number) return varchar2 is
|
|
|
|
lcLista varchar2(1000);
|
|
lnNrOptiuni number(3) := 0;
|
|
lcExtragOptId varchar2(500);
|
|
lcId_extras varchar2(10);
|
|
lcReturn varchar2(100);
|
|
|
|
begin
|
|
|
|
lcLista := trim(tcLista);
|
|
lnNrOptiuni := Getwordcount(lcLista, ';');
|
|
for i in 1 .. lnNrOptiuni loop
|
|
lcExtragOptId := Getwordnum(lcLista, i, ';');
|
|
lcId_extras := GETWORDNUM(lcExtragOptId, 1, '::');
|
|
if lcId_extras = to_char(tnId) then
|
|
lcReturn := GETWORDNUM(lcExtragOptId, 2, '::');
|
|
end if;
|
|
end loop;
|
|
|
|
RETURN lcReturn;
|
|
end extrage_optiuni;
|
|
----------------------------------------------------------------------------------
|
|
function citeste_ore_inchidere(tnId number) return number is
|
|
V_NR_ORE NUMBER(2);
|
|
lcLista varchar2(1000);
|
|
lnId number(5) := 0;
|
|
begin
|
|
|
|
lnId := tnId;
|
|
begin
|
|
SELECT VARVALUE
|
|
INTO lcLista
|
|
FROM OPTIUNI
|
|
WHERE VARNAME = 'ORE_INCHIDERE';
|
|
exception
|
|
WHEN NO_DATA_FOUND THEN
|
|
raise_application_error(-20000,
|
|
'Nu este setata perioada de dinaintea termenului de executie pentru care o lucrare este considerata inchisa!');
|
|
end;
|
|
|
|
V_NR_ORE := to_number(pack_comenzi.extrage_optiuni(lcLista, lnId));
|
|
|
|
return V_NR_ORE;
|
|
end;
|
|
----------------------------------------------------------------------------------
|
|
procedure raport_proc_vanzari_sterge(V_ID_COMRAPVANZ IN NUMBER) is
|
|
|
|
begin
|
|
delete from comrapvanzelem where ID_COMRAPVANZ = V_ID_COMRAPVANZ;
|
|
delete from comrapvanz where ID_COMRAPVANZ = V_ID_COMRAPVANZ;
|
|
end;
|
|
|
|
----------------------------------------------------------------------------------
|
|
procedure raport_proc_vanzari(V_DATAORA_I IN TIMESTAMP,
|
|
V_DATAORA_S IN TIMESTAMP,
|
|
V_ID_GRUPA_GEST IN NUMBER,
|
|
V_PROCENT IN NUMBER,
|
|
V_ID_SECTIE IN NUMBER,
|
|
V_ID_UTIL IN NUMBER,
|
|
V_ID_SUCURSALA IN NUMBER,
|
|
V_CURSOR OUT pack_cursor.tip_ref_cursor) is
|
|
V_AN_I NUMBER(4);
|
|
V_LUNA_I NUMBER(2);
|
|
V_AN_F NUMBER(4);
|
|
V_LUNA_F NUMBER(2);
|
|
V_PROCENT_BD NUMBER(10, 4);
|
|
V_TOATE_GRUPELE NUMBER(1);
|
|
V_ID_GRUPA_ART GEST_ART_GR.ID_GRUPA%TYPE;
|
|
|
|
V_ID_COMRAPVANZ COMRAPVANZ.ID_COMRAPVANZ%TYPE;
|
|
V_LISTA_GESTIUNI_DEPOZIT VARCHAR2(1000);
|
|
V_DATAORA_I0 DATE := TRUNC(V_DATAORA_I, 'MONTH'); -- 1 ale lunii de inceput;
|
|
lnNrLuniPerioada number(1) := 1; -- se selecteaza articolele din rulajul din urma cu 1 luni, nu numai cele din perioada, pentru cazul in care un articol nu a avut rulaj in perioada aleasa
|
|
begin
|
|
V_AN_I := EXTRACT(YEAR FROM V_DATAORA_I);
|
|
V_LUNA_I := EXTRACT(MONTH FROM V_DATAORA_I);
|
|
|
|
V_AN_F := EXTRACT(YEAR FROM V_DATAORA_S);
|
|
V_LUNA_F := EXTRACT(MONTH FROM V_DATAORA_S);
|
|
V_PROCENT_BD := to_number(nvl(pack_sesiune.getoptiunefirma('PROCVANZPER'),
|
|
'0'));
|
|
V_TOATE_GRUPELE := to_number(nvl(pack_sesiune.getoptiunefirma('TOATEGRUPELE'),
|
|
'1'));
|
|
IF V_TOATE_GRUPELE = 0 THEN
|
|
V_ID_GRUPA_ART := to_number(pack_comenzi.extrage_optiuni(pack_sesiune.getoptiunefirma('GRUPAARTSECTIE'),
|
|
V_ID_SECTIE));
|
|
ELSE
|
|
V_ID_GRUPA_ART := 0;
|
|
END IF;
|
|
|
|
V_LISTA_GESTIUNI_DEPOZIT := pack_comenzi.extrage_optiuni(pack_sesiune.getoptiunefirma('LISTA_GESTIUNI_DEPOZIT'),
|
|
V_ID_SECTIE);
|
|
|
|
IF V_PROCENT_BD <> V_PROCENT THEN
|
|
UPDATE OPTIUNI
|
|
SET VARVALUE = TO_CHAR(V_PROCENT)
|
|
WHERE VARNAME = 'PROCVANZPER';
|
|
|
|
V_PROCENT_BD := V_PROCENT;
|
|
END IF;
|
|
|
|
V_PROCENT_BD := V_PROCENT_BD / 100;
|
|
|
|
INSERT INTO COMRAPVANZ
|
|
(DATAI, DATAS, ID_GRUPE, PROCENT, ID_SECTIE, ID_UTIL, ID_SUCURSALA)
|
|
VALUES
|
|
(V_DATAORA_I,
|
|
V_DATAORA_S,
|
|
V_ID_GRUPA_GEST,
|
|
V_PROCENT,
|
|
V_ID_SECTIE,
|
|
V_ID_UTIL,
|
|
V_ID_SUCURSALA)
|
|
RETURNING ID_COMRAPVANZ INTO V_ID_COMRAPVANZ;
|
|
|
|
INSERT INTO COMRAPVANZELEM
|
|
(ID_COMRAPVANZ,
|
|
ID_GESTIUNE,
|
|
ID_ARTICOL,
|
|
STOCI,
|
|
VANZARI,
|
|
STOCF,
|
|
STOCDEP,
|
|
VALSTOCI,
|
|
VALSTOCDEP,
|
|
VALSTOCF)
|
|
with crs as
|
|
(select cgg.id_gestiune
|
|
from gest_coresp_grupe_gestiuni cgg
|
|
join nom_gestiuni g
|
|
on cgg.id_gestiune = g.id_gestiune
|
|
where cgg.sters = 0
|
|
and g.inactiv = 0
|
|
and g.sters = 0
|
|
and cgg.id_grupe = V_ID_GRUPA_GEST),
|
|
crsarticole as
|
|
(select id_articol
|
|
from nom_articole
|
|
where id_subgrupa in (select id_subgrupa
|
|
from gest_art_sbgr
|
|
where decode(V_ID_GRUPA_ART, 0, 0, id_grupa) =
|
|
V_ID_GRUPA_ART)
|
|
and sters = 0)
|
|
select V_ID_COMRAPVANZ,
|
|
nvl(a1.id_gestiune, b1.id_gestiune) as id_gestiune,
|
|
nvl(a1.id_articol, b1.id_articol) as id_articol,
|
|
nvl(a1.cants, 0) + nvl(b1.rulajei, 0) as stoci,
|
|
b1.vanzari,
|
|
nvl(a1.cants, 0) + nvl(b1.rulajei, 0) + nvl(b1.rulajep, 0) as stocf,
|
|
nvl(c1.stocdep, 0) as stocdep,
|
|
nvl(a1.valcants, 0) + nvl(b1.valrulajei, 0) as valstoci,
|
|
nvl(c1.valstocdep, 0) as valstocdep,
|
|
nvl(a1.valcants, 0) + nvl(b1.valrulajei, 0) +
|
|
nvl(b1.valrulajep, 0) as valstocf
|
|
from (select id_gestiune,
|
|
id_articol,
|
|
sum(case
|
|
when decode(trunc(dataora), dataact, dataora, dataact) between
|
|
V_DATAORA_I0 and V_DATAORA_I - 1 / 24 / 60 / 60 then
|
|
cant - cante
|
|
else
|
|
0
|
|
end) as rulajei,
|
|
sum(case
|
|
when decode(trunc(dataora), dataact, dataora, dataact) between
|
|
V_DATAORA_I0 and V_DATAORA_I - 1 / 24 / 60 / 60 then
|
|
(cant - cante) * pretvtva
|
|
else
|
|
0
|
|
end) as valrulajei,
|
|
sum(case
|
|
when decode(trunc(dataora), dataact, dataora, dataact) between
|
|
V_DATAORA_I and V_DATAORA_S then
|
|
cant - cante
|
|
else
|
|
0
|
|
end) as rulajep,
|
|
sum(case
|
|
when decode(trunc(dataora), dataact, dataora, dataact) between
|
|
V_DATAORA_I and V_DATAORA_S then
|
|
(cant - cante) * pretvtva
|
|
else
|
|
0
|
|
end) as valrulajep,
|
|
sum(case
|
|
when decode(trunc(dataora), dataact, dataora, dataact) between
|
|
V_DATAORA_I and V_DATAORA_S and id_tip_rulaj = 0 then
|
|
cante
|
|
else
|
|
0
|
|
end) as vanzari,
|
|
sum(case
|
|
when decode(trunc(dataora), dataact, dataora, dataact) between
|
|
V_DATAORA_I and V_DATAORA_S and id_tip_rulaj = 0 then
|
|
cante * pretvtva
|
|
else
|
|
0
|
|
end) as valvanzari
|
|
from rul
|
|
where an * 12 + luna between
|
|
V_AN_I * 12 + V_LUNA_I - lnNrLuniPerioada and
|
|
V_AN_F * 12 + V_LUNA_F
|
|
and sters = 0
|
|
and id_gestiune in (select id_gestiune from crs)
|
|
and id_articol in (select id_articol from crsarticole)
|
|
group by id_gestiune, id_articol) b1
|
|
left join (select id_gestiune,
|
|
id_articol,
|
|
sum(cants) as cants,
|
|
sum(cants * (pretv + tvav)) as valcants
|
|
from stoc
|
|
where an = V_AN_I
|
|
and luna = V_LUNA_I
|
|
and id_gestiune in (select id_gestiune from crs)
|
|
and id_articol in (select id_articol from crsarticole)
|
|
and cants <> 0
|
|
group by id_gestiune, id_articol) a1
|
|
on a1.id_articol = b1.id_articol
|
|
and a1.id_gestiune = b1.id_gestiune
|
|
left join (select id_articol,
|
|
sum(cants + cant - cante) as stocdep,
|
|
sum((cants + cant - cante) * (pretv + tvav)) as valstocdep
|
|
from stoc
|
|
where an = V_AN_F
|
|
and luna = V_LUNA_F
|
|
and id_gestiune in
|
|
(SELECT X
|
|
FROM table(charn2collection(V_LISTA_GESTIUNI_DEPOZIT,
|
|
',')))
|
|
and id_articol in (select id_articol from crsarticole)
|
|
group by id_articol) c1
|
|
on a1.id_articol = c1.id_articol;
|
|
|
|
-- aceleasi coloane ca si cursorul din completeaza_raport
|
|
OPEN V_CURSOR FOR
|
|
SELECT A.ID_COMRAPVANZ,
|
|
A.ID_COMRAPVANZELEM,
|
|
A.ID_GESTIUNE,
|
|
A.ID_ARTICOL,
|
|
C.ID_SUBGRUPA,
|
|
B.NUME_GESTIUNE,
|
|
D.SUBGRUPA,
|
|
C.DENUMIRE,
|
|
A.STOCI,
|
|
A.VANZARI,
|
|
A.STOCF,
|
|
A.CANTITATE,
|
|
A.STOCDEP,
|
|
a.valstoci,
|
|
a.Valstocf,
|
|
A.VALSTOCDEP,
|
|
A.VALIDAT
|
|
FROM COMRAPVANZELEM A
|
|
LEFT JOIN NOM_GESTIUNI B
|
|
ON A.ID_GESTIUNE = B.ID_GESTIUNE
|
|
LEFT JOIN NOM_ARTICOLE C
|
|
ON A.ID_ARTICOL = C.ID_ARTICOL
|
|
LEFT JOIN GEST_ART_SBGR D
|
|
ON C.ID_SUBGRUPA = D.ID_SUBGRUPA
|
|
WHERE A.ID_COMRAPVANZ = V_ID_COMRAPVANZ
|
|
ORDER BY B.NUME_GESTIUNE, D.SUBGRUPA, C.DENUMIRE;
|
|
|
|
end raport_proc_vanzari;
|
|
----------------------------------------------------------------------------------
|
|
procedure completeaza_raport(V_ID_COMRAPVANZ IN NUMBER,
|
|
V_LISTA_ARTICOLE IN VARCHAR,
|
|
V_LISTA_GESTIUNI IN VARCHAR,
|
|
V_CURSOR OUT pack_cursor.tip_ref_cursor) is
|
|
V_AN_I NUMBER(4);
|
|
V_LUNA_I NUMBER(2);
|
|
V_AN_F NUMBER(4);
|
|
V_LUNA_F NUMBER(2);
|
|
V_DATAORA_I COMRAPVANZ.DATAI%TYPE;
|
|
V_DATAORA_S COMRAPVANZ.DATAS%TYPE;
|
|
V_SEPARATOR VARCHAR2(1) := ',';
|
|
V_ID_MAX COMRAPVANZELEM.ID_COMRAPVANZELEM%TYPE;
|
|
begin
|
|
SELECT A.ID_COMRAPVANZELEM, B.DATAI, B.DATAS
|
|
INTO V_ID_MAX, V_DATAORA_I, V_DATAORA_S
|
|
FROM (SELECT V_ID_COMRAPVANZ AS ID_COMRAPVANZ,
|
|
NVL(MAX(ID_COMRAPVANZELEM), 0) AS ID_COMRAPVANZELEM
|
|
FROM COMRAPVANZELEM
|
|
WHERE ID_COMRAPVANZ = V_ID_COMRAPVANZ) A
|
|
LEFT JOIN COMRAPVANZ B
|
|
ON A.ID_COMRAPVANZ = B.ID_COMRAPVANZ;
|
|
|
|
V_AN_I := EXTRACT(YEAR FROM V_DATAORA_I);
|
|
V_LUNA_I := EXTRACT(MONTH FROM V_DATAORA_I);
|
|
V_AN_F := EXTRACT(YEAR FROM V_DATAORA_S);
|
|
V_LUNA_F := EXTRACT(MONTH FROM V_DATAORA_S);
|
|
|
|
MERGE INTO COMRAPVANZELEM A
|
|
USING (
|
|
WITH CRS_GESTIUNI AS
|
|
(SELECT X as ID_GESTIUNE
|
|
FROM table(charn2collection(V_LISTA_GESTIUNI, V_SEPARATOR))),
|
|
CRS_ARTICOLE AS
|
|
(SELECT X as ID_ARTICOL
|
|
FROM table(charn2collection(V_LISTA_ARTICOLE, V_SEPARATOR)))
|
|
SELECT V_ID_COMRAPVANZ AS ID_COMRAPVANZ,
|
|
A1.ID_ARTICOL,
|
|
B1.ID_GESTIUNE,
|
|
NVL(C1.CANTS, 0) + NVL(D1.RULAJEI, 0) AS STOCI,
|
|
NVL(D1.VANZARI, 0) AS VANZARI,
|
|
NVL(C1.CANTS, 0) + NVL(D1.RULAJEI, 0) + NVL(D1.RULAJEP, 0) AS STOCF
|
|
FROM CRS_ARTICOLE A1
|
|
LEFT JOIN CRS_GESTIUNI B1
|
|
ON 1 = 1
|
|
LEFT JOIN (select id_gestiune, id_articol, sum(cants) as cants
|
|
from stoc
|
|
where an * 12 + luna = V_AN_I * 12 + V_LUNA_I
|
|
and id_gestiune in
|
|
(select id_gestiune from CRS_GESTIUNI)
|
|
and id_articol in
|
|
(select id_articol from CRS_ARTICOLE)
|
|
and cants >= 0
|
|
group by id_gestiune, id_articol) C1
|
|
ON A1.ID_ARTICOL = C1.ID_ARTICOL
|
|
AND B1.ID_GESTIUNE = C1.ID_GESTIUNE
|
|
LEFT JOIN (select id_gestiune,
|
|
id_articol,
|
|
sum(case
|
|
when decode(trunc(dataora),
|
|
dataact,
|
|
dataora,
|
|
dataact) < V_DATAORA_I then
|
|
cant - cante
|
|
else
|
|
0
|
|
end) as rulajei,
|
|
sum(case
|
|
when decode(trunc(dataora),
|
|
dataact,
|
|
dataora,
|
|
dataact) between V_DATAORA_I and
|
|
V_DATAORA_S then
|
|
cant - cante
|
|
else
|
|
0
|
|
end) as rulajep,
|
|
sum(case
|
|
when decode(trunc(dataora),
|
|
dataact,
|
|
dataora,
|
|
dataact) between V_DATAORA_I and
|
|
V_DATAORA_S and id_tip_rulaj = 0 then
|
|
cante
|
|
else
|
|
0
|
|
end) as vanzari
|
|
from rul
|
|
where an * 12 + luna between V_AN_I * 12 + V_LUNA_I and
|
|
V_AN_F * 12 + V_LUNA_F
|
|
and sters = 0
|
|
and id_gestiune in
|
|
(select id_gestiune from CRS_GESTIUNI)
|
|
and id_articol in
|
|
(select id_articol from CRS_ARTICOLE)
|
|
group by id_gestiune, id_articol) D1
|
|
on A1.id_articol = D1.id_articol
|
|
and C1.id_gestiune = D1.id_gestiune) B ON (A.ID_ARTICOL = B.ID_ARTICOL AND A.ID_GESTIUNE = B.ID_GESTIUNE AND A.ID_COMRAPVANZ = B.ID_COMRAPVANZ) WHEN NOT MATCHED THEN
|
|
INSERT
|
|
(ID_COMRAPVANZ, ID_GESTIUNE, ID_ARTICOL, STOCI, VANZARI, STOCF)
|
|
VALUES
|
|
(B.ID_COMRAPVANZ,
|
|
B.ID_GESTIUNE,
|
|
B.ID_ARTICOL,
|
|
B.STOCI,
|
|
B.VANZARI,
|
|
B.STOCF);
|
|
|
|
-- aceleasi coloane ca si cursorul din raport_proc_vanzari
|
|
OPEN V_CURSOR FOR
|
|
SELECT A.ID_COMRAPVANZ,
|
|
A.ID_COMRAPVANZELEM,
|
|
A.ID_GESTIUNE,
|
|
A.ID_ARTICOL,
|
|
C.ID_SUBGRUPA,
|
|
B.NUME_GESTIUNE,
|
|
D.SUBGRUPA,
|
|
C.DENUMIRE,
|
|
A.STOCI,
|
|
A.VANZARI,
|
|
A.STOCF,
|
|
A.CANTITATE,
|
|
A.STOCDEP,
|
|
a.valstoci,
|
|
a.Valstocf,
|
|
A.VALSTOCDEP,
|
|
A.VALIDAT
|
|
FROM COMRAPVANZELEM A
|
|
LEFT JOIN NOM_GESTIUNI B
|
|
ON A.ID_GESTIUNE = B.ID_GESTIUNE
|
|
LEFT JOIN NOM_ARTICOLE C
|
|
ON A.ID_ARTICOL = C.ID_ARTICOL
|
|
LEFT JOIN GEST_ART_SBGR D
|
|
ON C.ID_SUBGRUPA = D.ID_SUBGRUPA
|
|
WHERE A.ID_COMRAPVANZ = V_ID_COMRAPVANZ
|
|
AND A.ID_COMRAPVANZELEM > V_ID_MAX
|
|
ORDER BY B.NUME_GESTIUNE, D.SUBGRUPA, C.DENUMIRE;
|
|
|
|
end completeaza_raport;
|
|
|
|
-------------------------------------------------------------
|
|
-- vizualizare / editare raport vanzari perioada
|
|
-------------------------------------------------------------
|
|
procedure raport_proc_vanzari_viz(V_ID_COMRAPVANZ IN NUMBER,
|
|
V_CURSOR OUT pack_cursor.tip_ref_cursor) is
|
|
begin
|
|
-- aceleasi coloane ca si cursorul din raport_proc_vanzari
|
|
OPEN V_CURSOR FOR
|
|
SELECT A.ID_COMRAPVANZ,
|
|
A.ID_COMRAPVANZELEM,
|
|
A.ID_GESTIUNE,
|
|
A.ID_ARTICOL,
|
|
C.ID_SUBGRUPA,
|
|
B.NUME_GESTIUNE,
|
|
D.SUBGRUPA,
|
|
C.DENUMIRE,
|
|
A.STOCI,
|
|
A.VANZARI,
|
|
A.STOCF,
|
|
A.CANTITATE,
|
|
A.STOCDEP,
|
|
a.valstoci,
|
|
a.Valstocf,
|
|
A.VALSTOCDEP,
|
|
A.VALIDAT
|
|
FROM COMRAPVANZELEM A
|
|
LEFT JOIN NOM_GESTIUNI B
|
|
ON A.ID_GESTIUNE = B.ID_GESTIUNE
|
|
LEFT JOIN NOM_ARTICOLE C
|
|
ON A.ID_ARTICOL = C.ID_ARTICOL
|
|
LEFT JOIN GEST_ART_SBGR D
|
|
ON C.ID_SUBGRUPA = D.ID_SUBGRUPA
|
|
WHERE A.ID_COMRAPVANZ = V_ID_COMRAPVANZ
|
|
ORDER BY B.NUME_GESTIUNE, D.SUBGRUPA, C.DENUMIRE;
|
|
|
|
end raport_proc_vanzari_viz;
|
|
----------------------------------------------------------------------------------
|
|
procedure actualizeaza_raport(V_ID_COMRAPVANZ IN NUMBER,
|
|
V_LISTA_ACTUALIZARI IN CLOB,
|
|
V_NR_COMENZI_GENERATE OUT NUMBER,
|
|
V_CURSOR OUT pack_cursor.tip_ref_cursor) is
|
|
CURSOR CRS IS
|
|
SELECT A.ID_GESTIUNE, B.NUME_GESTIUNE
|
|
FROM (SELECT DISTINCT ID_GESTIUNE
|
|
FROM COMRAPVANZELEM
|
|
WHERE CANTITATE <> 0
|
|
AND ID_COMRAPVANZ = V_ID_COMRAPVANZ) A
|
|
LEFT JOIN NOM_GESTIUNI B
|
|
ON A.ID_GESTIUNE = B.ID_GESTIUNE
|
|
ORDER BY B.NUME_GESTIUNE;
|
|
CRS_LINIE CRS%ROWTYPE;
|
|
V_SEPARATOR VARCHAR2(1) := '|';
|
|
V_ID_COMANDA COMENZI.ID_COMANDA%TYPE;
|
|
V_ID_POL CRM_POLITICI_PRETURI.ID_POL%TYPE;
|
|
V_ID_SECTIE COMRAPVANZ.ID_SECTIE%TYPE;
|
|
V_ID_UTIL COMRAPVANZ.ID_UTIL%TYPE;
|
|
V_ID_SUCURSALA COMRAPVANZ.ID_SUCURSALA%TYPE;
|
|
V_DATA_COMANDA COMRAPVANZ.DATAORA%TYPE;
|
|
V_DATA_LIVRARE COMENZI.DATA_LIVRARE%TYPE;
|
|
V_NR_INREGISTRARI NUMBER(10);
|
|
V_LISTA_ERORI VARCHAR2(32000);
|
|
begin
|
|
V_NR_COMENZI_GENERATE := 0;
|
|
|
|
-- generare comenzi
|
|
SELECT ID_SECTIE, ID_UTIL, ID_SUCURSALA, DATAORA
|
|
INTO V_ID_SECTIE, V_ID_UTIL, V_ID_SUCURSALA, V_DATA_COMANDA
|
|
FROM COMRAPVANZ
|
|
WHERE ID_COMRAPVANZ = V_ID_COMRAPVANZ;
|
|
|
|
V_ID_POL := to_number(pack_comenzi.extrage_optiuni(pack_sesiune.getoptiunefirma('IDPOLITICAPRET'),
|
|
V_ID_SECTIE));
|
|
|
|
IF V_ID_POL IS NULL THEN
|
|
RAISE_APPLICATION_ERROR(-20000,
|
|
'Nu este setata politica de preturi implicita pentru comenzile de la subunitati!');
|
|
ELSE
|
|
SELECT COUNT(*)
|
|
INTO V_NR_INREGISTRARI
|
|
FROM CRM_VPOLITICI_PRET_CURENTE
|
|
WHERE ID_POL = V_ID_POL;
|
|
IF V_NR_INREGISTRARI = 0 THEN
|
|
RAISE_APPLICATION_ERROR(-20000,
|
|
'Politica de preturi implicita nu mai este valabila!');
|
|
END IF;
|
|
END IF;
|
|
|
|
SELECT STRINGAGG(ID_ARTICOL)
|
|
INTO V_LISTA_ERORI
|
|
FROM (SELECT DISTINCT ID_ARTICOL
|
|
FROM COMRAPVANZELEM
|
|
WHERE ID_COMRAPVANZELEM IN
|
|
(select to_number(extractvalue(column_value,
|
|
'/crsraportvanzari/id')) as ID
|
|
from table(XMLSequence(extract(XMLType(V_LISTA_ACTUALIZARI),
|
|
'//VFPData/crsraportvanzari')))))
|
|
WHERE ID_ARTICOL NOT IN (SELECT ID_ARTICOL
|
|
FROM CRM_POLITICI_PRET_ART
|
|
WHERE ID_POL = V_ID_POL
|
|
AND PRET <> 0);
|
|
|
|
IF V_LISTA_ERORI IS NOT NULL THEN
|
|
OPEN V_CURSOR FOR
|
|
SELECT DENUMIRE, CODMAT
|
|
FROM NOM_ARTICOLE
|
|
WHERE ID_ARTICOL IN
|
|
(SELECT TO_NUMBER(X) AS ID
|
|
FROM table(charc2collection(V_LISTA_ERORI, ',')))
|
|
ORDER BY DENUMIRE;
|
|
|
|
ELSE
|
|
UPDATE COMRAPVANZ
|
|
SET COMPLETAT = 1
|
|
WHERE ID_COMRAPVANZ = V_ID_COMRAPVANZ;
|
|
|
|
MERGE INTO COMRAPVANZELEM A
|
|
USING (select to_number(extractvalue(column_value,
|
|
'/crsraportvanzari/id')) as ID,
|
|
to_number(extractvalue(column_value,
|
|
'/crsraportvanzari/cantitate'),
|
|
'9G999D9999',
|
|
'nls_numeric_characters=.,') as CANTITATE
|
|
from table(XMLSequence(extract(XMLType(V_LISTA_ACTUALIZARI),
|
|
'//VFPData/crsraportvanzari')))) B
|
|
ON (A.ID_COMRAPVANZELEM = B.ID)
|
|
WHEN MATCHED THEN
|
|
UPDATE SET CANTITATE = B.CANTITATE, VALIDAT = 1;
|
|
|
|
V_DATA_LIVRARE := V_DATA_COMANDA + NVL(to_number(pack_comenzi.extrage_optiuni(pack_sesiune.getoptiunefirma('ORE_LIVRARE'),
|
|
V_ID_SECTIE)),
|
|
0) / 24;
|
|
|
|
OPEN CRS;
|
|
LOOP
|
|
FETCH CRS
|
|
INTO CRS_LINIE;
|
|
EXIT WHEN CRS%NOTFOUND;
|
|
|
|
INSERT INTO COMENZI
|
|
(NR_COMANDA,
|
|
DATA_COMANDA,
|
|
DATA_LIVRARE,
|
|
ID_GESTIUNE,
|
|
INTERNA,
|
|
ID_UTIL,
|
|
ID_SECTIE,
|
|
ID_SUCURSALA)
|
|
VALUES
|
|
(pack_comenzi.genereaza_nr_comanda(),
|
|
V_DATA_COMANDA,
|
|
V_DATA_LIVRARE,
|
|
CRS_LINIE.ID_GESTIUNE,
|
|
3,
|
|
V_ID_UTIL,
|
|
V_ID_SECTIE,
|
|
V_ID_SUCURSALA)
|
|
RETURNING ID_COMANDA INTO V_ID_COMANDA;
|
|
|
|
V_NR_COMENZI_GENERATE := V_NR_COMENZI_GENERATE + 1;
|
|
|
|
INSERT INTO COMENZI_ELEMENTE
|
|
(ID_COMANDA,
|
|
ID_ARTICOL,
|
|
ID_POL,
|
|
PRET,
|
|
CANTITATE,
|
|
ID_VALUTA,
|
|
PRET_CU_TVA,
|
|
ID_SECTIE)
|
|
SELECT V_ID_COMANDA,
|
|
A.ID_ARTICOL,
|
|
B.ID_POL,
|
|
C.PRET,
|
|
A.CANTITATE,
|
|
B.ID_VALUTA,
|
|
B.PRETURI_CU_TVA,
|
|
V_ID_SECTIE
|
|
FROM (SELECT sb.subgrupa,
|
|
art.denumire,
|
|
ve.ID_ARTICOL,
|
|
ve.CANTITATE
|
|
FROM COMRAPVANZELEM ve
|
|
left join nom_articole art
|
|
on ve.id_articol = art.id_articol
|
|
left join gest_art_sbgr sb
|
|
on art.id_subgrupa = sb.id_subgrupa
|
|
WHERE ID_COMRAPVANZ = V_ID_COMRAPVANZ
|
|
AND ID_GESTIUNE = CRS_LINIE.ID_GESTIUNE
|
|
AND CANTITATE <> 0) A
|
|
LEFT JOIN (SELECT ID_POL, ID_VALUTA, PRETURI_CU_TVA
|
|
FROM CRM_POLITICI_PRETURI
|
|
WHERE ID_POL = V_ID_POL) B
|
|
ON 1 = 1
|
|
LEFT JOIN CRM_POLITICI_PRET_ART C
|
|
ON B.ID_POL = C.ID_POL
|
|
AND A.ID_ARTICOL = C.ID_ARTICOL
|
|
ORDER BY A.SUBGRUPA, A.DENUMIRE;
|
|
|
|
END LOOP;
|
|
CLOSE CRS;
|
|
|
|
OPEN V_CURSOR FOR
|
|
SELECT DENUMIRE FROM NOM_ARTICOLE WHERE 1 = 2;
|
|
END IF;
|
|
end actualizeaza_raport;
|
|
|
|
----------------------------------------------------------------------------------
|
|
-- Centralizator rapoarte vanzari: V_TIP = 1 cantitate completata de utilizatori; 2 = cantitate = vanzari, pentru listare pe furnizori
|
|
----------------------------------------------------------------------------------
|
|
procedure centralizator_rapoarte(V_LUNA IN NUMBER,
|
|
V_AN IN NUMBER,
|
|
V_ID_SECTIE IN NUMBER,
|
|
V_CURSOR OUT pack_cursor.tip_ref_cursor) is
|
|
begin
|
|
OPEN V_CURSOR FOR
|
|
SELECT A.ID_COMRAPVANZ,
|
|
A.DATAI,
|
|
A.DATAS,
|
|
B.NUME_GRUPA,
|
|
A.DATAORA,
|
|
C.UTILIZATOR
|
|
FROM COMRAPVANZ A
|
|
LEFT JOIN GEST_NOM_GRUPE B
|
|
ON A.ID_GRUPE = B.ID_GRUPE
|
|
LEFT JOIN SYN_UTILIZATORI C
|
|
ON A.ID_UTIL = C.ID_UTIL
|
|
WHERE TO_DATE(TO_CHAR(A.DATAORA, 'MMYYYY'), 'MMYYYY') =
|
|
TO_DATE(V_AN || V_LUNA, 'YYYYMM')
|
|
AND NVL(A.ID_SECTIE, -99) = NVL(V_ID_SECTIE, -99)
|
|
ORDER BY A.DATAORA DESC;
|
|
|
|
end centralizator_rapoarte;
|
|
----------------------------------------------------------------------------------
|
|
procedure listeaza_raport(V_ID_COMRAPVANZ IN NUMBER,
|
|
V_DATA OUT DATE,
|
|
V_CURSOR OUT pack_cursor.tip_ref_cursor) is
|
|
begin
|
|
SELECT DATAORA
|
|
INTO V_DATA
|
|
FROM COMRAPVANZ
|
|
WHERE ID_COMRAPVANZ = V_ID_COMRAPVANZ;
|
|
|
|
OPEN V_CURSOR FOR
|
|
SELECT A.ID_COMRAPVANZ,
|
|
A.ID_COMRAPVANZELEM,
|
|
A.ID_GESTIUNE,
|
|
A.ID_ARTICOL,
|
|
B.NUME_GESTIUNE,
|
|
C.DENUMIRE,
|
|
C.CODMAT,
|
|
C.UM,
|
|
A.CANTITATE
|
|
FROM COMRAPVANZELEM A
|
|
LEFT JOIN NOM_GESTIUNI B
|
|
ON A.ID_GESTIUNE = B.ID_GESTIUNE
|
|
LEFT JOIN NOM_ARTICOLE C
|
|
ON A.ID_ARTICOL = C.ID_ARTICOL
|
|
WHERE A.ID_COMRAPVANZ = V_ID_COMRAPVANZ
|
|
AND A.CANTITATE <> 0
|
|
ORDER BY B.NUME_GESTIUNE, C.DENUMIRE, C.CODMAT;
|
|
end listeaza_raport;
|
|
|
|
----------------------------------------------------------------------------------
|
|
-- raport comenzi furnizori pe baza vanzarilor
|
|
----------------------------------------------------------------------------------
|
|
procedure listeaza_raport_vz_fz(V_ID_COMRAPVANZ IN NUMBER,
|
|
V_CANTITATE IN NUMBER,
|
|
V_DATA OUT DATE,
|
|
V_DATAI OUT DATE,
|
|
V_DATAS OUT DATE,
|
|
V_CURSOR OUT pack_cursor.tip_ref_cursor) is
|
|
begin
|
|
-- V_CANTITATE: 1 = se foloseste coloana cantitate; 0 = se foloseste coloana vanzari
|
|
SELECT DATAORA, DATAI, DATAS
|
|
INTO V_DATA, V_DATAI, V_DATAS
|
|
FROM COMRAPVANZ
|
|
WHERE ID_COMRAPVANZ = V_ID_COMRAPVANZ;
|
|
|
|
OPEN V_CURSOR FOR
|
|
SELECT E.GRUPA,
|
|
D.SUBGRUPA,
|
|
B.DENUMIRE AS FURNIZOR,
|
|
A.ID_ARTICOL,
|
|
C.DENUMIRE,
|
|
C.CODMAT,
|
|
C.UM,
|
|
SUM(DECODE(V_CANTITATE, 1, A.CANTITATE, A.VANZARI)) AS CANTITATE,
|
|
MAX(A.STOCDEP) AS STOCDEP,
|
|
sum(a.stoci) as stoci,
|
|
sum(a.stocf) as stocf,
|
|
sum(a.valstoci) as valstoci,
|
|
sum(a.valstocf) as valstocf,
|
|
max(a.valstocdep) as valstocdep
|
|
FROM COMRAPVANZELEM A
|
|
JOIN NOM_ARTICOLE C
|
|
ON A.ID_ARTICOL = C.ID_ARTICOL
|
|
LEFT JOIN NOM_PARTENERI B
|
|
ON C.ID_PART = B.ID_PART
|
|
LEFT JOIN GEST_ART_SBGR D
|
|
ON C.ID_SUBGRUPA = D.ID_SUBGRUPA
|
|
LEFT JOIN GEST_ART_GR E
|
|
ON D.ID_GRUPA = E.ID_GRUPA
|
|
WHERE A.ID_COMRAPVANZ = V_ID_COMRAPVANZ
|
|
GROUP BY B.DENUMIRE,
|
|
E.GRUPA,
|
|
D.SUBGRUPA,
|
|
A.ID_ARTICOL,
|
|
C.DENUMIRE,
|
|
C.CODMAT,
|
|
C.UM
|
|
ORDER BY E.GRUPA, D.SUBGRUPA, B.DENUMIRE, C.DENUMIRE, C.CODMAT;
|
|
|
|
end listeaza_raport_vz_fz;
|
|
|
|
----------------------------------------------------------------------------------
|
|
-- raport vanzari un articol, o gestiune pe o perioada - detaliu la raport_proc_vanzari
|
|
----------------------------------------------------------------------------------
|
|
procedure rap_vanz_per_detaliu(V_ID_COMRAPVANZELEM IN NUMBER,
|
|
V_CURSOR OUT pack_cursor.tip_ref_cursor) is
|
|
V_ID_ARTICOL COMRAPVANZELEM.ID_ARTICOL%TYPE;
|
|
V_ID_GESTIUNE COMRAPVANZELEM.ID_GESTIUNE%TYPE;
|
|
V_ID_COMRAPVANZ COMRAPVANZ.ID_COMRAPVANZ%TYPE;
|
|
V_DATAI COMRAPVANZ.DATAI%TYPE;
|
|
V_DATAS COMRAPVANZ.DATAS%TYPE;
|
|
begin
|
|
SELECT VE.ID_ARTICOL, VE.ID_GESTIUNE, V.ID_COMRAPVANZ, V.DATAI, V.DATAS
|
|
INTO V_ID_ARTICOL, V_ID_GESTIUNE, V_ID_COMRAPVANZ, V_DATAI, V_DATAS
|
|
FROM COMRAPVANZELEM VE
|
|
JOIN COMRAPVANZ V
|
|
ON VE.ID_COMRAPVANZ = V.ID_COMRAPVANZ
|
|
WHERE ID_COMRAPVANZELEM = V_ID_COMRAPVANZELEM;
|
|
|
|
OPEN V_CURSOR FOR
|
|
SELECT R.ID_ARTICOL,
|
|
G.GRUPA,
|
|
SB.SUBGRUPA,
|
|
A.DENUMIRE,
|
|
A.CODMAT,
|
|
A.UM,
|
|
R.CANTE AS VANZARI,
|
|
R.DATAORA,
|
|
U.UTILIZATOR,
|
|
GS.NUME_GESTIUNE
|
|
FROM RUL R
|
|
JOIN NOM_ARTICOLE A
|
|
ON R.ID_ARTICOL = A.ID_ARTICOL
|
|
LEFT JOIN GEST_ART_SBGR SB
|
|
ON A.ID_SUBGRUPA = SB.ID_SUBGRUPA
|
|
LEFT JOIN GEST_ART_GR G
|
|
ON SB.ID_GRUPA = G.ID_GRUPA
|
|
LEFT JOIN SYN_UTILIZATORI U
|
|
ON R.ID_UTIL = U.ID_UTIL
|
|
LEFT JOIN NOM_GESTIUNI GS
|
|
ON R.ID_GESTIUNE = GS.ID_GESTIUNE
|
|
WHERE R.ID_ARTICOL = V_ID_ARTICOL
|
|
AND R.ID_GESTIUNE = V_ID_GESTIUNE
|
|
AND R.DATAORA BETWEEN V_DATAI AND V_DATAS
|
|
AND R.AN BETWEEN EXTRACT(YEAR FROM V_DATAI) AND
|
|
EXTRACT(YEAR FROM V_DATAS)
|
|
AND R.ID_TIP_RULAJ = 0
|
|
ORDER BY R.DATAORA;
|
|
|
|
end rap_vanz_per_detaliu;
|
|
|
|
----------------------------------------------------------------------------------
|
|
function verifica_acces_comanda(V_ID_COMANDA IN NUMBER) return varchar2 is
|
|
V_ID_SECTIE NOM_SECTII.ID_SECTIE%TYPE;
|
|
begin
|
|
SELECT ID_SECTIE
|
|
INTO V_ID_SECTIE
|
|
FROM COMENZI
|
|
WHERE ID_COMANDA = V_ID_COMANDA;
|
|
|
|
return pack_sesiune.verifica_acces('COMENZI_ELEMENTE',
|
|
V_ID_COMANDA,
|
|
pack_comenzi.extrage_optiuni(pack_sesiune.getoptiunefirma('MINSESCOMANDA'),
|
|
V_ID_SECTIE));
|
|
end;
|
|
----------------------------------------------------------------------------------
|
|
procedure deblocheaza_acces_comanda(V_ID_COMANDA IN NUMBER) is
|
|
begin
|
|
pack_sesiune.deblocheaza_acces('COMENZI_ELEMENTE', V_ID_COMANDA);
|
|
end;
|
|
|
|
-----------------------------------------------------------------
|
|
-- genereaza factura din comanda automat, fara interfata grafica
|
|
-- fara scadere din gestiune!!!
|
|
-----------------------------------------------------------------
|
|
procedure factureaza_comanda(tnIdComanda IN comenzi.id_comanda%type,
|
|
tnAn IN act.an%type DEFAULT EXTRACT(YEAR FROM
|
|
SYSDATE),
|
|
tnLuna IN act.luna%type DEFAULT EXTRACT(MONTH FROM
|
|
SYSDATE),
|
|
tnNrAct IN vanzari.numar_act%type DEFAULT NULL,
|
|
tdDataAct IN vanzari.data_act%type DEFAULT TRUNC(SYSDATE),
|
|
tnIncasat IN NUMBER DEFAULT 0,
|
|
tnSumaIncasat IN NUMBER DEFAULT 0,
|
|
tcTipIncasare IN VARCHAR2 DEFAULT 'CHITANTA',
|
|
tnIdDelegat IN VANZARI.ID_DELEGAT%TYPE DEFAULT NULL,
|
|
tnIdMasina IN vanzari.id_masina%type DEFAULT NULL,
|
|
tnIdAgent IN vanzari.id_agent%type DEFAULT NULL,
|
|
tcTextAditional IN vanzari.text_aditional%type DEFAULT NULL,
|
|
tnIdUtil IN vanzari.id_util%type DEFAULT -3,
|
|
tcMesaj OUT VARCHAR2,
|
|
tnIdVanzare OUT VANZARI.ID_VANZARE%TYPE) IS
|
|
|
|
-- tdDataAct - provizoriu pentru inregistrarea unor bonuri care nu s-au inregistrat in baza de date
|
|
-- tnIncasat: 0 = neincasat; 1 = incasat total; 2 = incasat partial (avans)
|
|
-- tcTipIncasare: BONFISCAL/CARD/TICHETE/CHITANTA
|
|
lnTipIncasare number(2);
|
|
|
|
nTipIncasareBonFiscal NUMBER := 2;
|
|
nTipIncasareCardBancar NUMBER := 3;
|
|
nTipIncasareTichete NUMBER := 5;
|
|
nTipIncasareChitanta NUMBER := 11;
|
|
|
|
lnAn calendar.anul%type := tnAn;
|
|
lnLuna calendar.luna%type := tnLuna;
|
|
lnTvaIncasare calendar.tva_incasare%type;
|
|
ldDataAct act.dataact%type;
|
|
ldDataIreg act.dataireg%type;
|
|
ldDataScad act.datascad%type;
|
|
ldDataCurs act.dataact%type;
|
|
|
|
lcSerieFactura vanzari.serie_act%type;
|
|
lnNrAct vanzari.numar_act%type := tnNrAct;
|
|
lnIdResponsabil act.id_responsabil%type;
|
|
lcListaId varchar2(100) := to_char(tnIdComanda);
|
|
lcDescriere varchar2(100);
|
|
lnTip vanzari.tip%type := 3; -- factura din comanda
|
|
lnIdFdoc act.id_fdoc%type;
|
|
|
|
lnIdValuta act.id_valuta%type;
|
|
lnInValuta number(1) := 0;
|
|
lnIdUtil vanzari.id_util%type := nvl(tnIdUtil, -3);
|
|
|
|
lnTotftva act.suma%type;
|
|
lnTotTva act.suma%type;
|
|
lnTotcTva act.suma%type;
|
|
|
|
ldDataExp vanzari.dataora_exp%type;
|
|
lnDiscountFactura vanzari.discount%type := 0;
|
|
lnIdDelegat vanzari.id_delegat%type := tnIdDelegat;
|
|
lnIdMasina vanzari.id_masina%type := tnIdMasina;
|
|
lnIdAgent vanzari.id_agent%type := tnIdAgent;
|
|
lcTextAditional varchar2(100) := tcTextAditional;
|
|
lnDiscountEvidentiat vanzari.discount_evidentiat%type := 0;
|
|
lnParametruAditional number(1);
|
|
|
|
lcListaIncasare varchar2(1000); -- V_LISTA_INCASARE : tip1|valoare1|id_bancasa1;tip2|valoare2|id_bancasa2 (pentru incasari cu mai multe tipuri ex: NUMERAR + CARD + TICHETE)
|
|
V_CURSOR_VERIFICARE pack_facturare.cursor_facturare;
|
|
|
|
lnIdSucursala act.id_sucursala%type;
|
|
lnIdSectie act.id_sectie%type;
|
|
lnIdVenChelt act.id_venchelt%type;
|
|
lnIdPartClient act.id_partd%type;
|
|
lnIdPartCasa act.id_partd%type;
|
|
lnIdSet act.Id_set%type := 25002;
|
|
lnIdLucrare act.id_lucrare%type;
|
|
|
|
lnIdGestiune stoc.id_gestiune%type;
|
|
lnSumaIncasat act.suma%type;
|
|
lnIdTipDocFactura number(2) := pack_facturare.nid_tipfactura;
|
|
lnIdSerieFactura number(10);
|
|
lnRec number(10);
|
|
BEGIN
|
|
lnAn := extract(year from sysdate);
|
|
lnLuna := extract(month from sysdate);
|
|
ldDataAct := CASE
|
|
WHEN tdDataAct is not null then
|
|
tdDataAct
|
|
else
|
|
trunc(sysdate)
|
|
end;
|
|
ldDataIreg := ldDataAct;
|
|
ldDataScad := ldDataAct;
|
|
ldDataCurs := ldDataAct;
|
|
|
|
pack_sesiune.setAn(lnAn);
|
|
pack_sesiune.setLuna(lnLuna);
|
|
|
|
begin
|
|
SELECT TVA_INCASARE
|
|
INTO lnTvaIncasare
|
|
FROM CALENDAR
|
|
WHERE AN = lnAn
|
|
AND LUNA = lnLuna;
|
|
exception
|
|
when NO_DATA_FOUND then
|
|
RAISE_APPLICATION_ERROR(-20001,
|
|
'Nu s-a deschis luna ' ||
|
|
lpad(lnLuna, 2, '0') || '/' || lnAn || '!');
|
|
end;
|
|
|
|
lnTipIncasare := case
|
|
when tcTipIncasare = 'BONFISCAL' then
|
|
pack_facturare.nTipIncasareBonFiscal
|
|
when tcTipIncasare = 'CARD' then
|
|
pack_facturare.nTipIncasareCardBancar
|
|
when tcTipIncasare = 'TICHETE' then
|
|
pack_facturare.nTipIncasareTichete
|
|
when tcTipIncasare = 'CHITANTA' then
|
|
pack_facturare.nTipIncasareChitanta
|
|
else
|
|
pack_facturare.nTipIncasareChitanta
|
|
end;
|
|
|
|
lnIdFdoc := TO_NUMBER(pack_sesiune.getoptiunefirma('ID_FDOC_FACT')); -- FEL DOCUMENT DIN OPTIUNI
|
|
if lnIdFdoc is null then
|
|
tcMesaj := 'Nu s-a configurat Tip Document Factura (ID_FDOC_FACT) in Optiuni!';
|
|
RAISE_APPLICATION_ERROR(-20001, tcMesaj);
|
|
end if;
|
|
|
|
lnIdSerieFactura := to_number(pack_sesiune.getoptiunefirma('COM_ID_SERIE_FACT'));
|
|
if lnIdSerieFactura is null then
|
|
tcMesaj := 'Nu s-a configurat Serie Factura (COM_ID_SERIE_FACT) in Optiuni!';
|
|
RAISE_APPLICATION_ERROR(-20001, tcMesaj);
|
|
end if;
|
|
|
|
-- obtin lcSerieFactura, lnNrAct
|
|
lcSerieFactura := pack_serii_numere.citeste_serie(lnIdSerieFactura);
|
|
if NVL(lnNrAct, 0) = 0 then
|
|
pack_serii_numere.aloca_numar(lnIdTipDocFactura,
|
|
lnIdSerieFactura,
|
|
lnIdGestiune,
|
|
lnIdUtil,
|
|
lnIdSucursala,
|
|
lnNrAct);
|
|
end if;
|
|
-- PENTRU FIECARE SUCURSALA,ID_SET(DIN POLITICA PRETURI) - FAC INREGISTRARI IN ACT, RUL, APOI IN VANZARI_DETALII
|
|
select max(p.id_sucursala) as id_sucursala,
|
|
MAX(c.id_part) as id_part_client
|
|
into lnIdSucursala, lnIdPartClient
|
|
FROM comenzi c
|
|
join comenzi_elemente e
|
|
on c.id_comanda = e.id_comanda
|
|
join crm_politici_preturi p
|
|
on e.id_pol = p.id_pol
|
|
where c.id_comanda = tnIdComanda;
|
|
|
|
pack_facturare.initializeaza_date_factura(ldDataIreg,
|
|
lnIdFdoc,
|
|
ldDataAct,
|
|
ldDataScad,
|
|
lcSerieFactura,
|
|
lnNrAct,
|
|
lnIdPartClient,
|
|
lnIdLucrare,
|
|
lnIdSectie,
|
|
lnIdVenChelt,
|
|
lnIdResponsabil,
|
|
NULL, -- explicatia 4
|
|
NULL, -- id_ordl
|
|
lcListaId,
|
|
lcDescriere,
|
|
lnTIP,
|
|
lnIdSet,
|
|
ldDataCurs,
|
|
lnIdValuta,
|
|
lnInValuta,
|
|
lnTvaIncasare,
|
|
lnIdSucursala,
|
|
lnIdUtil);
|
|
|
|
insert into vanzari_detalii_temp
|
|
(id_pol,
|
|
id_articol,
|
|
serie,
|
|
id_gestiune,
|
|
pret_achizitie,
|
|
pretv_orig,
|
|
pret,
|
|
proc_tvav,
|
|
pret_cu_tva,
|
|
id_jtva_coloana,
|
|
in_stoc,
|
|
cont,
|
|
id_valuta,
|
|
id_valutad,
|
|
pretd,
|
|
cantitate)
|
|
select e.id_pol,
|
|
e.id_articol,
|
|
'' as serie,
|
|
-999 as id_gestiune,
|
|
0 as pret_achizitie,
|
|
e.pret as pretv_orig,
|
|
e.pret as pret,
|
|
ppa.proc_tvav,
|
|
e.pret_cu_tva,
|
|
case ppa.proc_tvav
|
|
when 1.20 then
|
|
27
|
|
when 1.24 then
|
|
15
|
|
when 1.19 then
|
|
1
|
|
when 1.09 then
|
|
3
|
|
when 1.05 then
|
|
13
|
|
else
|
|
8
|
|
end as id_jtva_coloana,
|
|
0 as in_stoc,
|
|
'' as cont,
|
|
p.id_valuta,
|
|
p.id_valuta as id_valutad,
|
|
0 as pretd,
|
|
e.cantitate
|
|
from comenzi_elemente e
|
|
join comenzi c
|
|
on c.id_comanda = e.id_comanda
|
|
join vnom_articole a
|
|
on e.id_articol = a.id_articol
|
|
join crm_politici_preturi p
|
|
on e.id_pol = p.id_pol
|
|
join crm_politici_pret_art ppa
|
|
on e.id_pol = ppa.id_pol
|
|
and e.id_articol = ppa.id_articol
|
|
where c.id_comanda = tnIdComanda;
|
|
|
|
select count(*) into lnRec from vanzari_detalii_temp;
|
|
|
|
-- totaluri pentru inregistrarea facturii si incasarii
|
|
select sum(pack_sesiune.calculeaza_total_fara_tva(e.pret,
|
|
null,
|
|
null,
|
|
null,
|
|
null,
|
|
e.cantitate,
|
|
e.pret_cu_tva,
|
|
ppa.proc_tvav,
|
|
null,
|
|
null)),
|
|
sum(pack_sesiune.calculeaza_total_tva(e.pret,
|
|
null,
|
|
null,
|
|
null,
|
|
null,
|
|
e.cantitate,
|
|
e.pret_cu_tva,
|
|
ppa.proc_tvav,
|
|
null,
|
|
null)),
|
|
sum(pack_sesiune.calculeaza_total_cu_tva(e.pret,
|
|
null,
|
|
null,
|
|
null,
|
|
null,
|
|
e.cantitate,
|
|
e.pret_cu_tva,
|
|
ppa.proc_tvav,
|
|
null,
|
|
null))
|
|
INTO lnTotftva, lnTotTva, lnTotcTva
|
|
FROM comenzi_elemente e
|
|
join crm_politici_preturi p
|
|
on e.id_pol = p.id_pol
|
|
join crm_politici_pret_art ppa
|
|
on e.id_pol = ppa.id_pol
|
|
and e.id_articol = ppa.id_articol
|
|
WHERE e.id_comanda = tnIdComanda;
|
|
|
|
if tnIncasat <> 0 then
|
|
lnSumaIncasat := case
|
|
when tnIncasat = 1 then
|
|
lnTotcTVA
|
|
else
|
|
tnSumaIncasat
|
|
end;
|
|
-- tip|valoare|id_bancasa|ascc|scd|ascd
|
|
lnIdPartCasa := to_number(pack_sesiune.getoptiunefirma('ID_PART_CASA'));
|
|
|
|
lcListaIncasare := lnTipIncasare || '|' || lnSumaIncasat || '|' ||
|
|
lnIdPartCasa || '|' || 'xxxx|5311|xxxx';
|
|
end if;
|
|
|
|
ldDataExp := SYSDATE;
|
|
pack_facturare.scrie_factura2(lnTOTFTVA,
|
|
lnTOTTVA,
|
|
lnDiscountFactura,
|
|
Null,
|
|
lnNrAct,
|
|
lcListaIncasare,
|
|
lnIdDelegat,
|
|
lnIdMasina,
|
|
null,
|
|
0,
|
|
ldDataExp,
|
|
lnIdAgent,
|
|
lcTextAditional,
|
|
lnDiscountEvidentiat,
|
|
lnParametruAditional,
|
|
tnIdVanzare,
|
|
V_CURSOR_VERIFICARE);
|
|
|
|
-- SCRIU VANZAREA CHIAR DACA NU SUNT COMPLETATE ANALITICELE/PARTENERII, SI INTORC MESAJ DE ATENTIONARE
|
|
if tnIdVanzare is null then
|
|
pack_facturare.finalizeaza_factura(NULL,
|
|
lnIdDelegat, -- V_ID_DELEGAT,
|
|
lnIdMasina, -- V_ID_MASINA,
|
|
null, -- id_facturare
|
|
0, -- listare detaliata
|
|
ldDataExp,
|
|
lnIdAgent, -- V_ID_AGENT,
|
|
lcTextAditional, -- V_TEXT_ADITIONAL,
|
|
0 -- V_PARAMETRU_ADITIONAL
|
|
);
|
|
tnIdVanzare := pack_facturare.nid_vanzare;
|
|
tcMesaj := 'Nu s-au configurat partenerii si/sau conturile analitice! Nu s-a inregistrat factura!';
|
|
/* RAISE_APPLICATION_ERROR(-20000,
|
|
'Nu s-au configurat partenerii si/sau conturile analitice!');*/
|
|
end if;
|
|
|
|
<<SFARSIT>>
|
|
null;
|
|
end factureaza_comanda;
|
|
----------------------------------------------------------------------------------
|
|
/*procedure recompune_optiuni
|
|
declare
|
|
-- Local variables here
|
|
lcLista varchar2(1000);
|
|
lcIdCautat varchar2(100);
|
|
lnPoz number(4);
|
|
lnPozIncepeValVeche number(4);
|
|
lnx number(4);
|
|
lcValoare varchar2(100);
|
|
lcValNou varchar2(100);
|
|
begin
|
|
-- Test statements here
|
|
lcLista := '1001::3;2::777;1003::5';
|
|
lcIdCautat := '2' || '::';
|
|
lcValNou := '9';
|
|
lnPoz := instr(lcLista, lcIdCautat);
|
|
dbms_output.put_line('Lista initiala = ' || lcLista);
|
|
if lnPoz > 0 then
|
|
lnPozIncepeValVeche := lnPoz + length(lcIdCautat);
|
|
dbms_output.put_line('Unde incepe valoarea veche = ' ||
|
|
lnPozIncepeValVeche);
|
|
lnPoz := instr(lcLista, ';', lnPozIncepeValVeche);
|
|
dbms_output.put_line('Urmatoarea aparitie a lui ; = ' || lnPoz);
|
|
lcValoare := substr(lcLista,
|
|
lnPozIncepeValVeche,
|
|
lnPoz - lnPozIncepeValVeche);
|
|
dbms_output.put_line('lcValoare= ' || lcValoare);
|
|
lcLista := substr(lcLista, 1, lnPozIncepeValVeche - 1) || lcValNou ||
|
|
substr(lcLista, lnPozIncepeValVeche + length(lcValoare));
|
|
dbms_output.put_line('Lista finala= ' || lcLista);
|
|
|
|
end if;
|
|
|
|
end;*/
|
|
----------------------------------------------------------------------------------
|
|
----------------------------------------------------------------------------------
|
|
-- raport comenzi furnizori pe baza vanzarilor
|
|
----------------------------------------------------------------------------------
|
|
end PACK_COMENZI;
|
|
/
|