Thread: DDL issue

DDL issue

From
Rich Shepard
Date:
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




Re: DDL issue

From
"David G. Johnston"
Date:
On Thursday, September 12, 2024, Rich Shepard <rshepard@appl-ecosys.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.

Read up on “many-to-many” data models.  In SQL they involve a linking table, one row per bidirectional edge, in addition to the two node tables.

David J.
 

Re: DDL issue

From
Adrian Klaver
Date:
On 9/12/24 16:01, Rich Shepard 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.

Quick and dirty:

people_table
    person_id  PK
    name_last
    name_first
    email_address
    ph_number
    ...

location_table
    loc_id   PK
    person_id_fk FK <--> people_table(person_id)
    loc_name
    loc_st_addr
    loc_st_city
    loc_st_st_prov
    ...

contact_table
    contact_id  PK
    loc_id_fk   FK <--> location_table(loc_id)
    contact_ph_number
    contact_email  --Can be null

It can get more involved then this, depends on how flexible you want to get.

> 
> TIA,
> 
> Rich
> 
> 
> 

-- 
Adrian Klaver
adrian.klaver@aklaver.com




Re: DDL issue

From
Muhammad Usman Khan
Date:
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@example.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@example.com';

Output:

first_name | last_name | email               | dairy_name | location   | phone_number
----------- |----------- |--------------------- |------------|------------|--------------
usman       | khan       | usmankhan@example.com | Dairy A    | Location A | 123456789
usman       | khan       | usmankhan@example.com | Dairy B    | Location B | 987654321
usman       | khan       | usmankhan@example.com | Dairy C    | Location C | 111222333
usman       | khan       | usmankhan@example.com | Dairy D    | Location D | 444555666
usman       | khan       | usmankhan@example.com | Dairy E    | Location E | 777888999

On Fri, 13 Sept 2024 at 04:01, Rich Shepard <rshepard@appl-ecosys.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



Re: DDL issue

From
Tony Shelver
Date:

On Fri, 13 Sept 2024 at 06:43, Muhammad Usman Khan <usman.k@bitnine.net> wrote:
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@example.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@example.com';

Output:

first_name | last_name | email               | dairy_name | location   | phone_number
----------- |----------- |--------------------- |------------|------------|--------------
usman       | khan       | usmankhan@example.com | Dairy A    | Location A | 123456789
usman       | khan       | usmankhan@example.com | Dairy B    | Location B | 987654321
usman       | khan       | usmankhan@example.com | Dairy C    | Location C | 111222333
usman       | khan       | usmankhan@example.com | Dairy D    | Location D | 444555666
usman       | khan       | usmankhan@example.com | Dairy E    | Location E | 777888999

On Fri, 13 Sept 2024 at 04:01, Rich Shepard <rshepard@appl-ecosys.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




Or if you want to get even more flexible, where a dairy could have more than one owner as well as one owner having more than one dairy, you could create an intersection / relationship table.

Something like
 
-- Create people table (one entry per person) 
CREATE TABLE people_dairy_map ( pdm_id SERIAL PRIMARY KEY, 
first_name VARCHAR(100), 
last_name VARCHAR(100), 
email VARCHAR(100) UNIQUE ); 
phone_number VARCHAR(15), 
person_id INT REFERENCES people(person_id)
dairy_id INT REFERENCES dairies(dairy_id);

I would be careful of ON DELETE CASCADE, just on principle :)

Obviously dairies table would no longer need the phone_number
I would possibly suggest putting the email_address in the PDM table, just in case you find a use case where a dairy has different email addresses depending on the owner.

For even more flexibility / future proofing, you could consider a 'type' column in the PDM table.  For example, type = 'O' would be owner, type = 'M' would be manager, and so on.   Now you have a full contacts representation that can be used for other purposes apart from denoting ownership details.

The above 3 tables represents what we used to call a simple BOM structure (Bill of Materials), and is used for example in manufacturing, where a car has many parts, a part can be used in many parts.  The same structure can also be used to represent lhe cases where a part is a sub-assembly of another part (assembly), and so on and so on, going many levels deep with the same basic 3 tables.

Re: DDL issue

From
Rich Shepard
Date:
On Thu, 12 Sep 2024, David G. Johnston wrote:

> Read up on “many-to-many” data models. In SQL they involve a linking
> table, one row per bidirectional edge, in addition to the two node tables.

David,

Thanks very much. I knew about those a long time ago but haven't needed them
in a long time so I forgot about them. Will re-learn.

Much appreciated,

Rich



Re: DDL issue

From
Rich Shepard
Date:
On Thu, 12 Sep 2024, Adrian Klaver wrote:

> Quick and dirty:
>
> people_table
>   person_id  PK
>   name_last
>   name_first
>   email_address
>   ph_number
>   ...
>
> location_table
>   loc_id   PK
>   person_id_fk FK <--> people_table(person_id)
>   loc_name
>   loc_st_addr
>   loc_st_city
>   loc_st_st_prov
>   ...
>
> contact_table
>   contact_id  PK
>   loc_id_fk   FK <--> location_table(loc_id)
>   contact_ph_number
>   contact_email  --Can be null
>
> It can get more involved then this, depends on how flexible you want to get.

Adrian,

There are many companies with multiple locations, but few owners with
multiple companies, each with a different location. David's reminder about
many-to-many tables will do the job.

Thanks,

Rich



Re: DDL issue

From
Rich Shepard
Date:
On Fri, 13 Sep 2024, Muhammad Usman Khan wrote:

> 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

Muhammed,

Thank you. There are a number of industries (most involving natural
resources) so the one-to-many table will be more general.

Regards,

Rich



Re: DDL issue

From
Rich Shepard
Date:
On Fri, 13 Sep 2024, Tony Shelver wrote:

> Or if you want to get even more flexible, where a dairy could have more
> than one owner as well as one owner having more than one dairy, you could
> create an intersection / relationship table.
>
> Something like
>
> -- Create people table (one entry per person)
> CREATE TABLE people_dairy_map ( pdm_id SERIAL PRIMARY KEY,
> first_name VARCHAR(100),
> last_name VARCHAR(100),
> email VARCHAR(100) UNIQUE );
> phone_number VARCHAR(15),
> person_id INT REFERENCES people(person_id)
> dairy_id INT REFERENCES dairies(dairy_id);

Thanks, Tony.

Regards,

Rich



Re: DDL issue

From
Rich Shepard
Date:
On Thu, 12 Sep 2024, Adrian Klaver wrote:

> Quick and dirty:
>
> people_table
>   person_id  PK
>   name_last
>   name_first
>   email_address
>   ph_number
>   ...
>
> location_table
>   loc_id   PK
>   person_id_fk FK <--> people_table(person_id)
>   loc_name
>   loc_st_addr
>   loc_st_city
>   loc_st_st_prov
>   ...
>
> contact_table
>   contact_id  PK
>   loc_id_fk   FK <--> location_table(loc_id)
>   contact_ph_number
>   contact_email  --Can be null
>
> It can get more involved then this, depends on how flexible you want to get.

Adrian,

This comes close; I need to think about this.

Thanks,

Rich