IdentifiantMot de passe
Loading...
Mot de passe oublié ?Je m'inscris ! (gratuit)
Navigation

Inscrivez-vous gratuitement
pour pouvoir participer, suivre les réponses en temps réel, voter pour les messages, poser vos propres questions et recevoir la newsletter

Oracle Discussion :

Impossible d'exécuter des procédures


Sujet :

Oracle

  1. #1
    Futur Membre du Club
    Inscrit en
    Avril 2008
    Messages
    6
    Détails du profil
    Informations forums :
    Inscription : Avril 2008
    Messages : 6
    Points : 7
    Points
    7
    Par défaut Impossible d'exécuter des procédures
    Bonjour à tous,

    Voici mon problème,
    Dans le cadre d'un TP on nous a demandé de créer une base de données comprenant des tables,des packages ainsi que des procédures (etc...).

    Mon souci est que lorsque j'essaie de faire appel à celle-ci il me retourne une erreur.

    Je travaille sous Oracle 10g, j'administre ma BD via SqlDeveloper.

    Voici les sources permettant de créer ma BD :

    Code : Sélectionner tout - Visualiser dans une fenêtre à part
    1
    2
    3
    4
    5
    6
    7
    8
    9
    10
    11
    12
    13
    14
    15
    16
    17
    18
    19
    20
    21
    22
    23
    24
    25
    26
    27
    28
    29
    30
    31
    32
    33
    34
    35
    36
    37
    38
    39
    40
    41
    42
    43
    44
    45
    46
    47
    48
    49
    50
    51
    52
    53
    54
    55
    56
    57
    58
    59
    60
    61
    62
    63
    64
    65
    66
    67
    68
    69
    70
    71
    72
    73
    74
    75
    76
    77
    78
    79
    80
    81
    82
    83
    84
    85
    86
    87
    88
    89
    90
    91
    92
    93
    94
    95
    96
    97
    98
    99
    100
    101
    102
    103
    104
    105
    106
    107
    108
    109
    110
    111
    112
    113
    114
    115
    116
    117
    118
    119
    120
    121
    122
    123
    124
    125
    126
    127
    128
    129
    130
    131
    132
    133
    134
    135
    136
    137
    138
    139
    140
    141
    142
    143
    144
    145
    146
    147
    148
    149
    150
    151
    152
    153
    154
    155
    156
    157
    158
    159
    160
    161
    162
    163
    164
    165
    166
    167
    168
    169
    170
    171
    172
    173
    174
    175
    176
    177
    178
    179
    180
    181
    182
    183
    184
    185
    186
    187
    188
    189
    190
    191
    192
    193
    194
    195
    196
    197
    198
    199
    200
    201
    202
    203
    204
    205
    206
    207
    208
    209
    210
    211
    212
    213
    214
    215
    216
    217
    218
    219
    220
    221
    222
    223
    224
    225
    226
    227
    228
    229
    230
    231
    232
    233
    234
    235
    236
    237
    238
    239
    240
    241
    242
    243
    244
    245
    246
    247
    248
    249
    250
    251
    252
    253
    254
    255
    256
    257
    258
    259
    260
    261
    262
    263
    264
    265
    266
    267
    268
    269
    270
    271
    272
    273
    274
    275
    276
    277
    278
    279
    280
    281
    282
    283
    284
    285
    286
    287
    288
    289
    290
    291
    292
    293
    294
    295
    296
    297
    298
    299
    300
    301
    302
    303
    304
    305
    306
    307
    308
    309
    310
    311
    312
    313
    314
    315
    316
    317
    318
    319
    320
    321
    322
    323
    324
    325
    326
    327
    328
    329
    330
    331
    332
    333
    334
    335
    336
    337
    338
    339
    340
    341
    342
    343
    344
    345
    346
    347
    348
    349
    350
    351
    352
    353
    354
    355
    356
    357
    358
    359
    360
    361
    362
    363
    364
    365
    366
    367
    368
    369
    370
    371
    372
    373
    374
    375
    376
    377
    378
    379
    380
    381
    382
    383
    384
    385
    386
    387
    388
    389
    390
    391
    392
    393
    394
    395
    396
    397
    398
    399
    400
    401
    402
    403
    404
    405
    406
    407
    408
    409
    410
    411
    412
    413
    414
    415
    416
    417
    418
    419
    420
    421
    422
    423
    424
    425
    426
    427
    428
    429
    430
    431
    432
    433
    434
    435
    436
    437
    438
    439
    440
    441
    442
    443
    444
    445
    446
    447
    448
    449
    450
    451
    452
    453
    454
    455
    456
    457
    458
    459
    460
    461
    462
    463
    464
    465
    466
    467
    468
    469
    470
    471
    472
    473
    474
    475
    476
    477
    478
    479
    480
    481
    482
    483
    484
    485
    486
    487
    488
    489
    490
    491
    492
    493
    494
    495
    496
    497
    498
    499
    500
    501
    502
    503
    504
    505
    506
    507
    508
    509
    510
    511
    512
    513
    514
    515
    516
    517
    518
    519
    520
    521
    522
    523
    524
    525
    526
    527
    528
    529
    530
    531
    532
    533
    534
    535
    536
    537
    538
    539
    540
    541
    542
    543
    544
    545
    546
    547
    548
    549
    550
    551
    552
    553
    554
    555
    556
    557
    558
    559
    560
    561
    562
    563
    564
    565
    566
    567
    568
    569
    570
    571
    572
    573
    574
    575
    576
    577
    578
    579
    580
    581
    582
    583
    584
    585
    586
    587
    588
    589
    590
    591
    592
    593
    594
    595
    596
    597
    598
    599
    600
    601
    602
    603
    604
    605
    606
    607
    608
    609
    610
    611
    612
    613
    614
    615
    616
    617
    618
    619
    620
    621
    622
    623
    624
    625
    626
    627
    628
    629
    630
    631
    632
    633
    634
    635
    636
    637
    638
    639
    640
    641
    642
    643
    644
     
    CREATE TABLE  "REGIONS" 
       (	"REGION_ID" NUMBER NOT NULL ENABLE, 
    	"REGION_NAME" VARCHAR2(25), 
    	 CONSTRAINT "REGION_ID_PK" PRIMARY KEY ("REGION_ID") ENABLE, 
    	 CONSTRAINT "REGION_ID_NN" CHECK ("REGION_ID" IS NOT NULL) ENABLE
       )
    /
    CREATE TABLE  "COUNTRIES" 
       (	"COUNTRY_ID" CHAR(2 CHAR) NOT NULL ENABLE, 
    	"COUNTRY_NAME" VARCHAR2(40), 
    	"REGION_ID" NUMBER, 
    	 CONSTRAINT "COUNTRY_ID_NN" CHECK ("COUNTRY_ID" IS NOT NULL) ENABLE, 
    	 CONSTRAINT "COUNTRY_ID_PK" PRIMARY KEY ("COUNTRY_ID") ENABLE, 
    	 CONSTRAINT "COUNTRY_REGION_FK" FOREIGN KEY ("REGION_ID")
    	  REFERENCES  "REGIONS" ("REGION_ID") ENABLE
       )
    /
    CREATE TABLE  "JOBS" 
       (	"JOB_ID" VARCHAR2(10) NOT NULL ENABLE, 
    	"JOB_TITLE" VARCHAR2(35) NOT NULL ENABLE, 
    	"MIN_SALARY" NUMBER(6,0), 
    	"MAX_SALARY" NUMBER(6,0), 
    	 CONSTRAINT "JOB_ID_PK" PRIMARY KEY ("JOB_ID") ENABLE, 
    	 CONSTRAINT "JOB_TITLE_NN" CHECK ("JOB_TITLE" IS NOT NULL) ENABLE
       )
    /
    CREATE TABLE  "EMPLOYEES" 
       (	"EMPLOYEE_ID" NUMBER(6,0) NOT NULL ENABLE, 
    	"FIRST_NAME" VARCHAR2(20), 
    	"LAST_NAME" VARCHAR2(25) NOT NULL ENABLE, 
    	"EMAIL" VARCHAR2(25) NOT NULL ENABLE, 
    	"PHONE_NUMBER" VARCHAR2(20), 
    	"HIRE_DATE" DATE NOT NULL ENABLE, 
    	"JOB_ID" VARCHAR2(10) NOT NULL ENABLE, 
    	"SALARY" NUMBER(8,2), 
    	"COMMISSION_PCT" NUMBER(2,2), 
    	"MANAGER_ID" NUMBER(6,0), 
    	"DEPARTMENT_ID" NUMBER(4,0), 
    	 CONSTRAINT "EMPLOYEE_EMAIL_UK" CHECK ("EMAIL" IS NOT NULL) ENABLE, 
    	 CONSTRAINT "EMPLOYEE_ID_PK" PRIMARY KEY ("EMPLOYEE_ID") ENABLE, 
    	 CONSTRAINT "EMPLOYEE_LAST_NAME_NN" CHECK ("LAST_NAME" IS NOT NULL) ENABLE, 
    	 CONSTRAINT "EMPLOYEE_HIRE_DATE_NN" CHECK ("HIRE_DATE" IS NOT NULL) ENABLE, 
    	 CONSTRAINT "EMPLOYEE_JOB_NN" CHECK ("JOB_ID" IS NOT NULL) ENABLE, 
    	 CONSTRAINT "EMPLOYEE_SALARY_MIN" CHECK (SALARY > 0) ENABLE, 
    	 CONSTRAINT "EMPLOYEE_MANAGER_FK" FOREIGN KEY ("MANAGER_ID")
    	  REFERENCES  "EMPLOYEES" ("EMPLOYEE_ID") ENABLE, 
    	 CONSTRAINT "EMPLOYEE_JOB_FK" FOREIGN KEY ("JOB_ID")
    	  REFERENCES  "JOBS" ("JOB_ID") ON DELETE CASCADE ENABLE
       )
    /
    CREATE TABLE  "LOCATIONS" 
       (	"LOCATION_ID" NUMBER(4,0) NOT NULL ENABLE, 
    	"STREET_ADDRESS" VARCHAR2(40), 
    	"POSTAL_CODE" VARCHAR2(12), 
    	"CITY" VARCHAR2(30) NOT NULL ENABLE, 
    	"STATE_PROVINCE" VARCHAR2(25), 
    	"COUNTRY_ID" CHAR(2 CHAR), 
    	 CONSTRAINT "LOC_CITY_NN" CHECK ("CITY" IS NOT NULL) ENABLE, 
    	 CONSTRAINT "LOC_ID_PK" PRIMARY KEY ("LOCATION_ID") ENABLE, 
    	 CONSTRAINT "LOCATION_COUNTRY_ID_FK" FOREIGN KEY ("COUNTRY_ID")
    	  REFERENCES  "COUNTRIES" ("COUNTRY_ID") ON DELETE CASCADE ENABLE
       )
    /
    CREATE TABLE  "DEPARTMENTS" 
       (	"DEPARTMENT_ID" NUMBER(4,0) NOT NULL ENABLE, 
    	"DEPARTMENT_NAME" VARCHAR2(30) NOT NULL ENABLE, 
    	"MANAGER_ID" NUMBER(6,0), 
    	"LOCATION_ID" NUMBER(4,0), 
    	 CONSTRAINT "DEPARTMENT_NAME_NN" CHECK ("DEPARTMENT_NAME" IS NOT NULL) ENABLE, 
    	 CONSTRAINT "DEPARTMENT_ID_PK" PRIMARY KEY ("DEPARTMENT_ID") ENABLE, 
    	 CONSTRAINT "DEPARTMENT_MANAGER_FK" FOREIGN KEY ("MANAGER_ID")
    	  REFERENCES  "EMPLOYEES" ("EMPLOYEE_ID") ON DELETE SET NULL ENABLE, 
    	 CONSTRAINT "DEPARTMENT_LOCATION_FK" FOREIGN KEY ("LOCATION_ID")
    	  REFERENCES  "LOCATIONS" ("LOCATION_ID") ON DELETE CASCADE ENABLE
       )
    /
    CREATE TABLE  "JOB_GRADES" 
       (	"GRADE_LEVEL" VARCHAR2(3), 
    	"LOWEST_SAL" NUMBER, 
    	"HIGHEST_SAL" NUMBER
       )
    /
    CREATE TABLE  "JOB_HISTORY" 
       (	"EMPLOYEE_ID" NUMBER(6,0) NOT NULL ENABLE, 
    	"START_DATE" DATE NOT NULL ENABLE, 
    	"END_DATE" DATE NOT NULL ENABLE, 
    	"JOB_ID" VARCHAR2(10) NOT NULL ENABLE, 
    	"DEPARTMENT_ID" NUMBER(4,0), 
    	 CONSTRAINT "JH_EMPLOYEE_IN" CHECK ("EMPLOYEE_ID" IS NOT NULL) ENABLE, 
    	 CONSTRAINT "JH_START_DATE_NN" CHECK ("START_DATE" IS NOT NULL) ENABLE, 
    	 CONSTRAINT "JH_END_DATE_NN" CHECK ("END_DATE" IS NOT NULL) ENABLE, 
    	 CONSTRAINT "JH_JOB_NN" CHECK ("JOB_ID" IS NOT NULL) ENABLE, 
    	 CONSTRAINT "JH_DATE_INTERVAL" CHECK (END_DATE < START_DATE) ENABLE, 
    	 CONSTRAINT "JH_EMP_ID_ST_DATE_PK" PRIMARY KEY ("EMPLOYEE_ID", "START_DATE") ENABLE, 
    	 CONSTRAINT "JH_JOB_FK" FOREIGN KEY ("JOB_ID")
    	  REFERENCES  "JOBS" ("JOB_ID") ENABLE, 
    	 CONSTRAINT "JH_EMPLOYEE_FK" FOREIGN KEY ("EMPLOYEE_ID")
    	  REFERENCES  "EMPLOYEES" ("EMPLOYEE_ID") ENABLE, 
    	 CONSTRAINT "JH_DEPARTMENT_FK" FOREIGN KEY ("DEPARTMENT_ID")
    	  REFERENCES  "DEPARTMENTS" ("DEPARTMENT_ID") ENABLE
       )
    /
    alter table "EMPLOYEES" add constraint DEPARTMENT_FK foreign key("DEPARTMENT_ID") references "DEPARTMENTS"("DEPARTMENT_ID")
    /
    /*
    CREATE TABLE  "TEST" 
       (	"NOM" VARCHAR2(4000), 
    	"PRENOM" VARCHAR2(4000), 
    	"SEXE" VARCHAR2(4000), 
    	"AGE" VARCHAR2(4000)
       )
    /
    */
    CREATE INDEX  "LOC_STATE_PROVINCE_IX" ON  "LOCATIONS" ("STATE_PROVINCE")
    /
    CREATE INDEX  "LOC_COUNTRY_IX" ON  "LOCATIONS" ("COUNTRY_ID", "LOCATION_ID" DESC)
    /
    CREATE INDEX  "LOC_CITY_IX" ON  "LOCATIONS" ("CITY")
    /
    CREATE INDEX  "JH_JOB_IX" ON  "JOB_HISTORY" ("JOB_ID", "JOB_ID" DESC)
    /
    CREATE INDEX  "JH_EMPLOYEE_IX" ON  "JOB_HISTORY" ("EMPLOYEE_ID", "EMPLOYEE_ID" DESC)
    /
    CREATE INDEX  "JH_DEPARTMENT_IX" ON  "JOB_HISTORY" ("DEPARTMENT_ID", "DEPARTMENT_ID" DESC)
    /
    CREATE INDEX  "EMPLOYEE_NAME_IX" ON  "EMPLOYEES" ("LAST_NAME", "EMPLOYEE_ID" DESC)
    /
    CREATE INDEX  "EMPLOYEE_MANAGER_IX" ON  "EMPLOYEES" ("MANAGER_ID")
    /
    CREATE INDEX  "EMPLOYEE_JOB_IX" ON  "EMPLOYEES" ("JOB_ID")
    /
    CREATE INDEX  "EMPLOYEE_DEPARTMENT_IX" ON  "EMPLOYEES" ("EMPLOYEE_ID", "EMPLOYEE_ID" DESC)
    /
    CREATE INDEX  "DEPARTMENT_LOCATION_IX" ON  "DEPARTMENTS" ("LOCATION_ID")
    /
    CREATE UNIQUE INDEX  "COUNTRY_C_ID_PK" ON  "COUNTRIES" ("COUNTRY_ID", "COUNTRY_ID" DESC)
    /
    CREATE OR REPLACE PACKAGE  "SUPPRIMER_DONNEE_PKG" AS
     
      /*Ce package contient toutes les procedure qui seront utilisees pour ajouter une
      ligne a n'importe quelle table dans la base de donnees*/
     
    END SUPPRIMER_DONNEE_PKG;
    /
    CREATE OR REPLACE PACKAGE BODY  "SUPPRIMER_DONNEE_PKG" AS
     
    /*Procedure pour supprimer un pays, l'ID de ce pays et le parametre IN*/
    procedure delete_country(
    the_id COUNTRIES.COUNTRY_ID%type)
    is
    begin
    delete from COUNTRIES
    where country_id = the_id;
    commit;
    end delete_country;
     
    /*Procedure pour supprimer un departement*/
    /*ATTENTION, tous le employes dans ce departement seront supprim¿egalement*/
    /*Il faudra mieux proposer a l'utilisateur s'il ne veut pas les affecter dans un autre departement avant*/
    procedure delete_department(
    the_id DEPARTMENTS.DEPARTMENT_ID%type)
    is
    begin
    delete from DEPARTMENTS
    where department_id = the_id;
     
    update job_history
    set end_date = sysdate
    where department_id = the_id;
    commit;
    end delete_department;
     
    /*Procedure pour supprimer un d¿rtement*/
    procedure delete_employee(
                              the_id EMPLOYEES.EMPLOYEE_ID%type)
    is
    begin
      delete from EMPLOYEES
      where employee_id = the_id;
     
      update JOB_HISTORY
      set end_date = sysdate
      where employee_id = the_id;
      commit;
    end delete_employee;
     
    /*Procedure pour supprimer un job*/
    /*ATTENTION, tous les employes ayant ce job seront supprim¿egalement*/
    /*Il faudra mieux proposer a l'utilisateur s'il ne veut pas les affecter dans un autre job avant*/
    procedure delete_job(
                      the_id JOBS.JOB_ID%type)
    is
    begin
      delete from JOBS
      where job_id = the_id;
     
      commit;
    end delete_job;
     
    /*Procedure pour supprimer un departement*/
    /*ATTENTION, tous les departements dans cette location ainsi que les employes qui travail seront supprimes egalement*/
    /*Il faudra mieux proposer a l'utilisateur s'il ne veut pas demenager les departemets dans
    une autre location ou affecter les employes dans un autre departement avant*/
    procedure delete_location(
                            the_id LOCATIONS.LOCATION_ID%type)
    is
     
    begin
      delete from LOCATIONS
      where location_id = the_id;
      commit;
    end delete_location;
     
    /*Procedure pour supprimer un departement*/
    procedure delete_region(
                          the_id REGIONS.REGION_ID%type)
    is
    begin
      delete from REGIONS
      where region_id = the_id;
      commit;
    end delete_region;
     
     
     
    END SUPPRIMER_DONNEE_PKG;
    /
     CREATE OR REPLACE PACKAGE  "MODIFIER_DONNEE_PKG" AS
     
      /*Ce package contient toutes les procedure qui seront utilises pour modifier 
      une donnee sur n'importe quelle table dans la base de donnes*/
     
    END MODIFIER_DONNEE_PKG;
    /
    CREATE OR REPLACE PACKAGE BODY  "MODIFIER_DONNEE_PKG" AS
     
    /*Procedure pour modifier les informations sur un pays*/
    /*Elle prend en parametres l'ancien ID, le nouveau ID, le nouveau nom et region*/
    procedure modify_country(
    the_old_id COUNTRIES.COUNTRY_ID%type,
    the_new_id COUNTRIES.COUNTRY_ID%type,
    the_name COUNTRIES.COUNTRY_NAME%type,
    the_region_id COUNTRIES.REGION_ID%type)
    is
    begin
    update COUNTRIES
    set country_id = the_new_id, country_name = the_name, region_id = the_region_id
    where country_id = the_old_id;
    commit;
    end modify_country;
     
    /*Procedure pour modifier les informations sur un departement*/
    /*Elle prend en parametres L'ID (q'on ne peut pas changer, sinon il faudra supprimer
    le departement et la recrer de nouveau), le nouveau nom, le nouveau manager et
    sa nouvelle location*/
    procedure modify_department(
    the_id DEPARTMENTS.DEPARTMENT_ID%type,
    the_name DEPARTMENTS.DEPARTMENT_NAME%type,
    the_manager DEPARTMENTS.MANAGER_ID%type,
    the_location DEPARTMENTS.LOCATION_ID%type)
    is
    begin
    update DEPARTMENTS
    set department_name = the_name, manager_id = the_manager, location_id = the_location
    where department_id = the_id;
    commit;
    end modify_department;
     
    /*Idem que pour le departement*/
    procedure modify_employee(
    the_id EMPLOYEES.EMPLOYEE_ID%type,
    the_firstname EMPLOYEES.FIRST_NAME%type,
    the_name EMPLOYEES.LAST_NAME%type,
    the_email EMPLOYEES.EMAIL%type,
    the_phone EMPLOYEES.PHONE_NUMBER%type,
    the_job EMPLOYEES.JOB_ID%type,
    the_salary EMPLOYEES.SALARY%type,
    the_commission EMPLOYEES.COMMISSION_PCT%type,
    the_manager EMPLOYEES.MANAGER_ID%type,
    the_department EMPLOYEES.DEPARTMENT_ID%type)
    is
     
    begin
      update EMPLOYEES
      set first_name = the_firstname, last_name = the_name, email = the_email, 
              phone_number = the_phone, job_id = the_job, salary = the_salary, 
              commission_pct = the_commission, manager_id = the_manager, 
              department_id = the_department
      where employee_id = the_id;
     
      update JOB_HISTORY
      set job_id = the_job, department_id = the_department
      where employee_id = the_id;
      commit;
    end modify_employee;
     
    /*Procedure pour modifier les informations sur un grade (salaire minimum et maximum)*/
    /*Elle prend en parametres le niveau de grade a changer avec ainsi que les nouveau valeurs*/
    procedure modify_grade(
                        the_level JOB_GRADES.GRADE_LEVEL%type,
                        the_lowest JOB_GRADES.LOWEST_SAL%type,
                        the_highest JOB_GRADES.HIGHEST_SAL%type)
    is
    begin
      update JOB_GRADES
      set lowest_sal = the_lowest, highest_sal = the_highest
      where grade_level = the_level;
      commit;
    end modify_grade;
     
    /*Procedure pour modifier les informations sur un job*/
    /*Elle prend en parametres l'ancien ID, le nouveau ID, le nouveau intitule ainsi que le salaire
    minimum et maximum*/
    procedure modify_job(
                      the_old_id JOBS.JOB_ID%type,
                      the_new_id JOBS.JOB_ID%type,
                      the_title JOBS.JOB_TITLE%type,
                      the_min_sal JOBS.MIN_SALARY%type,
                      the_max_sal JOBS.MAX_SALARY%type)
    is
    begin
      update JOBS
      set job_id = the_new_id, job_title = the_title, min_salary = the_min_sal, 
           max_salary = the_max_sal
      where job_id = the_old_id;
      commit;
    end modify_job;
     
    /*Procedure pour modifier les informations sur une location*/
    /*Idem que pour le departement et la tble EMPLOYEES*/
    procedure modify_location(
                            the_id LOCATIONS.LOCATION_ID%type,
                            the_street LOCATIONS.STREET_ADDRESS%type,
                            the_zip LOCATIONS.POSTAL_CODE%type,
                            the_city LOCATIONS.CITY%type,
                            the_state LOCATIONS.STATE_PROVINCE%type,
                            the_country LOCATIONS.COUNTRY_ID%type)
    is
     
    begin
      update LOCATIONS
      set street_address = the_street, postal_code = the_zip, city = the_city, 
            state_province = the_state, country_id = the_country
      where location_id = the_id;
      commit;
    end modify_location;
     
    /*Procedure pour modifier les informations sur une region*/
    /*Idem*/
    procedure modify_region(
                          the_id REGIONS.REGION_ID%type,
                          the_name REGIONS.REGION_NAME%type)
    is
    begin
      update REGIONS
      set region_id = the_id, region_name = the_name
      where region_id = the_id;
      commit;
    end modify_region;
     
     
     
    END MODIFIER_DONNEE_PKG;
    /
     CREATE OR REPLACE PACKAGE  "AJOUTER_DONNEE_PKG" AS
     
      /*Ce package contient toutes les procedure qui seront utilises pour ajouter une
      ligne a n'importe quelle table dans la base de donnees*/
     
    END AJOUTER_DONNEE_PKG;
    /
    CREATE OR REPLACE PACKAGE BODY  "AJOUTER_DONNEE_PKG" AS
     
    /*Procedure pour ajouter un pays*/
    procedure add_country(
    the_id COUNTRIES.COUNTRY_ID%type,
    the_name COUNTRIES.COUNTRY_NAME%type,
    the_region_id COUNTRIES.REGION_ID%type)
    is
    begin
    insert into COUNTRIES(COUNTRY_ID, country_name, region_id)
    values (the_id, the_name, the_region_id);
    commit;
    end add_country;
     
    /*Procedure pour ajouter un departement*/
    procedure add_department(
    the_name DEPARTMENTS.DEPARTMENT_NAME%type,
    the_manager DEPARTMENTS.MANAGER_ID%type,
    the_location DEPARTMENTS.LOCATION_ID%type)
    is
    begin
    insert into DEPARTMENTS(DEPARTMENT_ID, DEPARTMENT_name, manager_id, location_id)
    values (departments_seq.NEXTVAL, the_name, the_manager, the_location);
    commit;
    end add_department;
     
    /*Procedure pour ajouter un nouveau employee*/
    procedure add_employee(
    the_firstname EMPLOYEES.FIRST_NAME%type,
    the_name EMPLOYEES.LAST_NAME%type,
    the_email EMPLOYEES.EMAIL%type,
    the_phone EMPLOYEES.PHONE_NUMBER%type,
    the_job EMPLOYEES.JOB_ID%type,
    the_salary EMPLOYEES.SALARY%type,
    the_commission EMPLOYEES.COMMISSION_PCT%type,
    the_manager EMPLOYEES.MANAGER_ID%type,
    the_department EMPLOYEES.DEPARTMENT_ID%type)
    is
     
    begin
      insert into EMPLOYEES(EMPLOYEE_ID, first_name, last_name, email, phone_number,
                            hire_date, job_id, salary, commission_pct, manager_id,
                            department_id)
      values (employees_seq.NEXTVAL, the_firstname, the_name, the_email, 
              the_phone, sysdate, the_job, the_salary, the_commission, the_manager, 
              the_department);
     
      insert into JOB_HISTORY(EMPLOYEE_ID, start_date,  job_id, department_id)
      values (employees_seq.CURRVAL, sysdate, the_job, the_department);
      commit;
    end add_employee;
     
    procedure add_grade(
                        the_level JOB_GRADES.GRADE_LEVEL%type,
                        the_lowest JOB_GRADES.LOWEST_SAL%type,
                        the_highest JOB_GRADES.HIGHEST_SAL%type)
    is
    begin
      insert into JOB_GRADES(GRADE_LEVEL, lowest_sal, highest_sal)
      values (the_level, the_lowest, the_highest);
      commit;
    end add_grade;
     
    /*Procedure pour ajouter un nouveau poste dans l'entrprise*/
    procedure add_job(
                      the_id JOBS.JOB_ID%type,
                      the_title JOBS.JOB_TITLE%type,
                      the_min_sal JOBS.MIN_SALARY%type,
                      the_max_sal JOBS.MAX_SALARY%type)
    is
    begin
      insert into JOBS(JOB_ID, job_title, min_salary, max_salary)
      values (the_id, the_title, the_min_sal, the_max_sal);
      commit;
    end add_job;
     
    /*Procedure pour ajouter une location*/
    procedure add_location(
                            the_street LOCATIONS.STREET_ADDRESS%type,
                            the_zip LOCATIONS.POSTAL_CODE%type,
                            the_city LOCATIONS.CITY%type,
                            the_state LOCATIONS.STATE_PROVINCE%type,
                            the_country LOCATIONS.COUNTRY_ID%type)
    is
     
    begin
      insert into LOCATIONS(LOCATION_ID, street_address, postal_code, city, 
                            state_province, country_id)
      values (locations_seq.NEXTVAL, the_street, the_zip, the_city, the_state, 
              the_country);
      commit;
    end add_location;
     
    /*Procedure pour ajouter une region*/
    procedure add_region(
                          the_id REGIONS.REGION_ID%type,
                          the_name REGIONS.REGION_NAME%type)
    is
    begin
      insert into REGIONS(REGION_ID, region_name)
      values (the_id, the_name);
      commit;
    end add_region;
     
     
     
    END AJOUTER_DONNEE_PKG;
    /
      CREATE SEQUENCE   "LOCATIONS_SEQ"  MINVALUE 1 MAXVALUE 99999999 INCREMENT BY 100 START WITH 1 CACHE 20 NOORDER  NOCYCLE
    /
     CREATE SEQUENCE   "EMPLOYEES_SEQ"  MINVALUE 1 MAXVALUE 99999999 INCREMENT BY 1 START WITH 1 CACHE 20 NOORDER  NOCYCLE
    /
     CREATE SEQUENCE   "DEPARTMENTS_SEQ"  MINVALUE 1 MAXVALUE 9999 INCREMENT BY 10 START WITH 1 CACHE 20 NOORDER  NOCYCLE
    /
    CREATE OR REPLACE TRIGGER  "SECURE_REGIONS" 
    BEFORE INSERT ON regions BEGIN
    IF (TO_CHAR(SYSDATE,'DY') IN ('SAT','SUN')) OR
    (TO_CHAR(SYSDATE,'HH24:MI')
    NOT BETWEEN '08:00' AND '18:00') THEN
    RAISE_APPLICATION_ERROR(-20500, 'You may insert'
    ||' into EMPLOYEES table only during '
    ||' business hours.');
    END IF;
    END;
     
    /
    ALTER TRIGGER  "SECURE_REGIONS" ENABLE
    /
    CREATE OR REPLACE TRIGGER  "SECURE_LOCATIONS" 
    BEFORE INSERT ON locations BEGIN
    IF (TO_CHAR(SYSDATE,'DY') IN ('SAT','SUN')) OR
    (TO_CHAR(SYSDATE,'HH24:MI')
    NOT BETWEEN '08:00' AND '18:00') THEN
    RAISE_APPLICATION_ERROR(-20500, 'You may insert'
    ||' into EMPLOYEES table only during '
    ||' business hours.');
    END IF;
    END;
     
    /
    ALTER TRIGGER  "SECURE_LOCATIONS" ENABLE
    /
    CREATE OR REPLACE TRIGGER  "SECURE_JOBS" 
    BEFORE INSERT ON jobs BEGIN
    IF (TO_CHAR(SYSDATE,'DY') IN ('SAT','SUN')) OR
    (TO_CHAR(SYSDATE,'HH24:MI')
    NOT BETWEEN '08:00' AND '18:00') THEN
    RAISE_APPLICATION_ERROR(-20500, 'You may insert'
    ||' into EMPLOYEES table only during '
    ||' business hours.');
    END IF;
    END;
     
    /
    ALTER TRIGGER  "SECURE_JOBS" ENABLE
    /
    CREATE OR REPLACE TRIGGER  "SECURE_JOB_HISTORY" 
    BEFORE INSERT ON job_history BEGIN
    IF (TO_CHAR(SYSDATE,'DY') IN ('SAT','SUN')) OR
    (TO_CHAR(SYSDATE,'HH24:MI')
    NOT BETWEEN '08:00' AND '18:00') THEN
    RAISE_APPLICATION_ERROR(-20500, 'You may insert'
    ||' into EMPLOYEES table only during '
    ||' business hours.');
    END IF;
    END;
     
    /
    ALTER TRIGGER  "SECURE_JOB_HISTORY" ENABLE
    /
    CREATE OR REPLACE TRIGGER  "SECURE_JOB_GRADES" 
    BEFORE INSERT ON job_grades BEGIN
    IF (TO_CHAR(SYSDATE,'DY') IN ('SAT','SUN')) OR
    (TO_CHAR(SYSDATE,'HH24:MI')
    NOT BETWEEN '08:00' AND '18:00') THEN
    RAISE_APPLICATION_ERROR(-20500, 'You may insert'
    ||' into EMPLOYEES table only during '
    ||' business hours.');
    END IF;
    END;
     
    /
    ALTER TRIGGER  "SECURE_JOB_GRADES" ENABLE
    /
    CREATE OR REPLACE TRIGGER  "SECURE_EMP" 
    BEFORE INSERT ON employees BEGIN
    IF (TO_CHAR(SYSDATE,'DY') IN ('SAT','SUN')) OR
    (TO_CHAR(SYSDATE,'HH24:MI')
    NOT BETWEEN '08:00' AND '18:00') THEN
    RAISE_APPLICATION_ERROR(-20500, 'You may insert'
    ||' into EMPLOYEES table only during '
    ||' business hours.');
    END IF;
    END;
     
    /
    ALTER TRIGGER  "SECURE_EMP" ENABLE
    /
    CREATE OR REPLACE TRIGGER  "SECURE_DEPARTMENTS" 
    BEFORE INSERT ON departments BEGIN
    IF (TO_CHAR(SYSDATE,'DY') IN ('SAT','SUN')) OR
    (TO_CHAR(SYSDATE,'HH24:MI')
    NOT BETWEEN '08:00' AND '18:00') THEN
    RAISE_APPLICATION_ERROR(-20500, 'You may insert'
    ||' into EMPLOYEES table only during '
    ||' business hours.');
    END IF;
    END;
     
    /
    ALTER TRIGGER  "SECURE_DEPARTMENTS" ENABLE
    /
    CREATE OR REPLACE TRIGGER  "SECURE_COUNTRIES" 
    BEFORE INSERT ON countries BEGIN
    IF (TO_CHAR(SYSDATE,'DY') IN ('SAT','SUN')) OR
    (TO_CHAR(SYSDATE,'HH24:MI')
    NOT BETWEEN '08:00' AND '18:00') THEN
    RAISE_APPLICATION_ERROR(-20500, 'You may insert'
    ||' into EMPLOYEES table only during '
    ||' business hours.');
    END IF;
    END;
     
    /
    ALTER TRIGGER  "SECURE_COUNTRIES" ENABLE
    /
    CREATE OR REPLACE TRIGGER  "RESTRICT_SALARY" 
    BEFORE INSERT OR UPDATE OF salary ON employees
    FOR EACH ROW
    declare
      salaire_maximum EMPLOYEES.SALARY%type;
      salaire_minimum EMPLOYEES.SALARY%type;
    BEGIN
    SELECT min_salary, max_salary
    INTO salaire_minimum, salaire_maximum
    FROM jobs
    WHERE job_id = :NEW.job_id;
    IF :NEW.salary < salaire_minimum OR
    :NEW.salary > salaire_maximum THEN
    RAISE_APPLICATION_ERROR(-20505,'Out of range');
    END IF;
    END;
     
    /
    ALTER TRIGGER  "RESTRICT_SALARY" ENABLE
    /
    CREATE OR REPLACE FORCE VIEW  "EMP_DETAILS_VIEW" ("Numero", "Numero Poste", "Identificateur Directeur", "Numero Departement", "Identificateur Location", "Identificateur Pays", "Prenom", "Nom", "Salaire", "Pourcentage", "Nom Departement", "Titre Poste", "Ville", "Province", "Pays", "Region") AS 
      select
    e.employee_id "Numero",
    e.job_id "Numero Poste",
    e.manager_id "Identificateur Directeur",
    e.department_id "Numero Departement",
    d.location_id "Identificateur Location",
    l.country_id "Identificateur Pays",
    e.first_name "Prenom",
    e.last_name "Nom",
    e.salary "Salaire",
    e.commission_pct "Pourcentage",
    d.department_name "Nom Departement",
    j.job_title "Titre Poste",
    l.city "Ville",
    l.state_province "Province",
    co.country_name "Pays",
    r.REGION_NAME "Region"
    from employees e, departments d, jobs j, locations l, countries co, regions r
    where e.DEPARTMENT_ID = d.DEPARTMENT_ID
    and d.LOCATION_ID = l.LOCATION_ID
    and l.COUNTRY_ID = co.COUNTRY_ID
    and co.REGION_ID = r.REGION_ID
    and j.JOB_ID = e.JOB_ID
    with read only
    /
    Voici maintenant ma requète :

    Code : Sélectionner tout - Visualiser dans une fenêtre à part
    1
    2
    3
    4
    5
    6
    7
    8
    9
    10
    11
    12
     
    BEGIN 
    AJOUTER_DONNEE_PKG.add_employee('Test', 
                                                        'TEST', 
                                                        'test@test.test', 
                                                        '0123456789', 
                                                        '10', 
                                                        5000, 
                                                        0.25, 
                                                        01, 
                                                        100); 
    END;
    Enfin voici l'erreur retournée :

    Code : Sélectionner tout - Visualiser dans une fenêtre à part
    1
    2
    3
    4
    5
    6
    7
    8
    9
    10
    11
    12
    13
    14
    15
    16
    17
    18
    19
    20
    21
     
    Error starting at line 1 in command:
    BEGIN 
    AJOUTER_DONNEE_PKG.add_employee('Test', 
                                                        'TEST', 
                                                        'test@test.test', 
                                                        '0123456789', 
                                                        '10', 
                                                        5000, 
                                                        0.25, 
                                                        01, 
                                                        100); 
    END;
    Error report:
    ORA-06550: Ligne 2, colonne 20 :
    PLS-00302: Le composant 'ADD_EMPLOYEE' doit être déclaré
    ORA-06550: Ligne 2, colonne 1 :
    PL/SQL: Statement ignored
    06550. 00000 -  "line %s, column %s:\n%s"
    *Cause:    Usually a PL/SQL compilation error.
    *Action:
    J'espère avoir été assez précis.

    Merci par avance de votre aide.

  2. #2
    Invité
    Invité(e)
    Par défaut
    Il faut rendre publique ta procédure en incluant sa déclaration dans les specs du package :
    Code : Sélectionner tout - Visualiser dans une fenêtre à part
    1
    2
    3
    4
    5
    6
    7
    8
    9
    10
    11
    12
    13
    14
    15
    16
    17
    18
    CREATE OR REPLACE PACKAGE  "AJOUTER_DONNEE_PKG" AS
     
      /*Ce package contient toutes les procedure qui seront utilises pour ajouter une
      ligne a n'importe quelle table dans la base de donnees*/
    /*Procedure pour ajouter un nouveau employee*/
    procedure add_employee(
    the_firstname EMPLOYEES.FIRST_NAME%type,
    the_name EMPLOYEES.LAST_NAME%type,
    the_email EMPLOYEES.EMAIL%type,
    the_phone EMPLOYEES.PHONE_NUMBER%type,
    the_job EMPLOYEES.JOB_ID%type,
    the_salary EMPLOYEES.SALARY%type,
    the_commission EMPLOYEES.COMMISSION_PCT%type,
    the_manager EMPLOYEES.MANAGER_ID%type,
    the_department EMPLOYEES.DEPARTMENT_ID%type) ;
     
     
    END AJOUTER_DONNEE_PKG;

  3. #3
    Futur Membre du Club
    Inscrit en
    Avril 2008
    Messages
    6
    Détails du profil
    Informations forums :
    Inscription : Avril 2008
    Messages : 6
    Points : 7
    Points
    7
    Par défaut
    Merci beaucoup,
    Une erreur toute bête surement mais quand on débute ...

    Bref ça marche merci encore.


+ Répondre à la discussion
Cette discussion est résolue.

Discussions similaires

  1. Impossible d'exécuter des procédure
    Par JP.NUAGE dans le forum Bases de données
    Réponses: 0
    Dernier message: 22/07/2012, 19h01
  2. Réponses: 9
    Dernier message: 27/07/2011, 09h49
  3. Réponses: 3
    Dernier message: 05/08/2009, 17h03
  4. Pb ordre d'exécution des procédures
    Par ogeiger dans le forum Windows Forms
    Réponses: 6
    Dernier message: 19/12/2008, 19h44

Partager

Partager
  • Envoyer la discussion sur Viadeo
  • Envoyer la discussion sur Twitter
  • Envoyer la discussion sur Google
  • Envoyer la discussion sur Facebook
  • Envoyer la discussion sur Digg
  • Envoyer la discussion sur Delicious
  • Envoyer la discussion sur MySpace
  • Envoyer la discussion sur Yahoo