From: | Muhammad Usman Khan <usman(dot)k(at)bitnine(dot)net> |
---|---|
To: | Rich Shepard <rshepard(at)appl-ecosys(dot)com> |
Cc: | pgsql-general(at)postgresql(dot)org |
Subject: | Re: DDL issue |
Date: | 2024-09-13 04:43:14 |
Message-ID: | CAPnRvGt_=bWgTKaZSaK=K_TXJYHQ3oOJckvzUByfotCuGoMNzw@mail.gmail.com |
Views: | Raw Message | Whole Thread | Download mbox | Resend email |
Thread: | |
Lists: | pgsql-general |
Hi,
To handle this situation in PostgreSQL, you can model the data in a way
that maintains a single entry for each owner in the people table while
linking the owner to multiple dairies through a separate dairies table.
This is a typical one-to-many relationship (one person can own many
dairies).
The following is testing scenario which might help you
-- Create people table (one entry per person)
CREATE TABLE people ( person_id SERIAL PRIMARY KEY,
first_name VARCHAR(100),
last_name VARCHAR(100),
email VARCHAR(100) UNIQUE );
-- Create dairies table (each dairy will be linked to a person)
CREATE TABLE dairies ( dairy_id SERIAL PRIMARY KEY,
dairy_name VARCHAR(100),
location VARCHAR(100),
phone_number VARCHAR(15),
person_id INT REFERENCES people(person_id) ON DELETE CASCADE );
-- Insert a person (owner) into people table
INSERT INTO people (first_name, last_name, email) VALUES ('usman', 'khan', '
usmankhan(at)example(dot)com');
-- Insert multiple dairies owned by the same person
INSERT INTO dairies (dairy_name, location, phone_number, person_id)
VALUES ('Dairy
A', 'Location A', '123456789', 1), ('Dairy B', 'Location B', '987654321', 1),
('Dairy C', 'Location C', '111222333', 1), ('Dairy D', 'Location D',
'444555666', 1), ('Dairy E', 'Location E', '777888999', 1);
SELECT p.first_name, p.last_name, p.email, d.dairy_name, d.location,
d.phone_number
FROM people p
JOIN dairies d ON p.person_id = d.person_id
WHERE p.email = 'usmankhan(at)example(dot)com';
Output:
first_name | last_name | email | dairy_name |
location | phone_number
----------- |----------- |---------------------
|------------|------------|--------------
usman | khan | usmankhan(at)example(dot)com | Dairy A |
Location A | 123456789
usman | khan | usmankhan(at)example(dot)com | Dairy B |
Location B | 987654321
usman | khan | usmankhan(at)example(dot)com | Dairy C |
Location C | 111222333
usman | khan | usmankhan(at)example(dot)com | Dairy D |
Location D | 444555666
usman | khan | usmankhan(at)example(dot)com | Dairy E |
Location E | 777888999
On Fri, 13 Sept 2024 at 04:01, Rich Shepard <rshepard(at)appl-ecosys(dot)com>
wrote:
> I have one name in the people table who owns 5 different dairies with three
> different phone numbers, but all 5 have the the same email address.
>
> The five dairies each has its own name and location while the people table
> has five rows with the same last and first names and email address.
>
> Is there a way to have only one entry for the owner in the people table
> while related to five different company names? In some industries, such as
> dairy farms, this is not an unusual situation.
>
> TIA,
>
> Rich
>
>
>
>
From | Date | Subject | |
---|---|---|---|
Next Message | Willow Chargin | 2024-09-13 05:20:10 | Functionally dependent columns in SELECT DISTINCT |
Previous Message | Thiemo Kellner | 2024-09-13 00:55:48 | Re: Better way to process records in bash? |