Обсуждение: linking

Поиск
Список
Период
Сортировка

linking

От
si
Дата:
Please can you help:

+--------------------------------------+
|              DEPARTMENT              |
+----------+----------------+----------+
| LOCATION |  DESCRIPTION   |  DEPT_NO |
+----------+----------------+----------+
| Bedrock  | Administration |     1    |
| Bedrock  | Quarry         |     2    |
| Redcliff | Stockpile      |     3    |
+----------+----------------+----------+

+-----------------------------+
|         EMPLOYEE            |
+---------+------------+------+
| EMPL_ID | NAME_LAST  | DEPT |
+---------+------------+------+
|    1    | Slate      |  1   |
|    4    | Flintstone |  2   |
|    5    | Rubble     |  2   |
|    7    | Rockhead   |  3   |
|   11    | Gravel     |  1   |
+---------+------------+------+

create sequence increment start 1 increment 1 maxvalue 2147483647 minvalue 1 cache 1;

create table DEPARTMENT (
LOCATION varchar(30),
DESCRIPTION varchar(30),
DEPT_NO int unique not null default nextval('increment') primary key
);

create table EMPLOYEE (
EMPL_ID int unique not null primary key,
NAME_LAST varchar(20),
DEPT int references DEPARTMENT (DEPT_NO)
);

Insert into DEPARTMENT values ('Bedrock','Administration');

Insert into Employee values ('1','Slate','????');

How do I replace ???? to automatically get the DEPT_NO value?

e.g. In theory I need to replace ???? with (select DEPT_NO from DEPARTMENT where location = 'Administration' and
DESCRIPTION= 'Bedrock';) but I am not sure how to do this all in 1 statement. 

The DEPT_NO is automatically created if no value is given, which is why I also need to create the DEPT relation
automatically.

Thanks,
Si

_____________________________________________________________
Pick up your email anywhere in the world ---> http://www.remail.net

Re: linking

От
"Oliver Elphick"
Дата:
si wrote:
  >Please can you help:

  >Insert into DEPARTMENT values ('Bedrock','Administration');
  >
  >Insert into Employee values ('1','Slate','????');
  >
  >How do I replace ???? to automatically get the DEPT_NO value?
  >
  >e.g. In theory I need to replace ???? with (select DEPT_NO from DEPARTMENT w
      >here location = 'Administration' and DESCRIPTION = 'Bedrock';) but I am
      >not sure how to do this all in 1 statement.
  >
  >The DEPT_NO is automatically created if no value is given, which is why I al
      >so need to create the DEPT relation automatically.

In 7.1 you can simply do this:

junk=# Insert into Employee values (1,'Slate',
junk(# (select DEPT_NO from DEPARTMENT where DESCRIPTION = 'Administration'
and location = 'Bedrock'));
INSERT 2085500 1

junk=# select * from department;
 location |  description   | dept_no
----------+----------------+---------
 Bedrock  | Administration |       1
(1 row)

junk=# select * from employee;
 empl_id | name_last | dept
---------+-----------+------
       1 | Slate     |    1
(1 row)

However, if you do this, you need a unique index on (location, description);
at the moment you could have more than one dept_no for the same combination.


--
Oliver Elphick                                Oliver.Elphick@lfix.co.uk
Isle of Wight                              http://www.lfix.co.uk/oliver
PGP: 1024R/32B8FAA1: 97 EA 1D 47 72 3F 28 47  6B 7E 39 CC 56 E4 C1 47
GPG: 1024D/3E1D0C1C: CA12 09E0 E8D5 8870 5839  932A 614D 4C34 3E1D 0C1C
                 ========================================
     "I will lift up mine eyes unto the hills, from whence
      cometh my help. My help cometh from the LORD, which
      made heaven and earth."
                           Psalms 121:1,2