Loading learning content...
Consider an enrollment: a student enrolls in a course. Where does the enrollment date belong? Not to the student (they have many enrollment dates for different courses). Not to the course (different students enrolled on different dates). The date belongs to the relationship itself—to the specific pairing of this student with this course.
This is a relationship attribute: a property that describes the association between entities rather than any single entity. Relationship attributes are one of the most important yet often misunderstood concepts in ER modeling. They capture data that exists only in the context of connection.
Mastering relationship attributes is essential for creating accurate data models. Place an attribute in the wrong location—on an entity instead of the relationship—and you'll struggle with data redundancy, update anomalies, or inability to represent the required information at all.
By the end of this page, you will understand what relationship attributes are, when they're necessary, how to distinguish them from entity attributes, implement them in databases, and handle their unique challenges in different cardinality scenarios.
A relationship attribute is an attribute that describes a characteristic of the association between entity instances, rather than a characteristic of any participating entity.
Formal Definition:
Given a relationship R between entity types E₁, E₂, ..., Eₙ, an attribute A is a relationship attribute if the value of A depends on the specific combination (e₁, e₂, ..., eₙ) rather than on any single eᵢ.
The Dependency Test:
To determine if an attribute belongs on a relationship:
If all answers are "yes," it's a relationship attribute.
| Relationship | Attribute | Why It's on the Relationship |
|---|---|---|
| ENROLLS_IN (Student, Course) | enrollment_date | Date differs per student-course pair |
| ENROLLS_IN (Student, Course) | grade | Grade is for this student in this specific course |
| WORKS_IN (Employee, Department) | start_date | When this employee joined this department |
| WORKS_IN (Employee, Department) | position | Role in this specific department |
| SUPPLIES (Vendor, Product) | unit_price | Price this vendor charges for this product |
| SUPPLIES (Vendor, Product) | contract_date | When agreement was signed |
ER Diagram Notation:
In Chen notation, relationship attributes attach directly to the diamond:
┌───────────────┐
│ grade │
└───────┬───────┘
│
┌──────────┐ ┌──────────◇──────────┐ ┌──────────┐
│ STUDENT │─────────│ ENROLLS_IN │─────────│ COURSE │
└──────────┘ └──────────┬──────────┘ └──────────┘
│
┌───────┴───────┐
│ enrollment_date│
└───────────────┘
The ovals for grade and enrollment_date connect to the diamond, not to either rectangle.
Many M:N relationships have at least one attribute. In fact, when you identify an M:N relationship, you should immediately ask: 'What information do I need to know about each instance of this relationship?' The answer often reveals relationship attributes.
One of the most common modeling mistakes is placing relationship attributes on entities. This section provides a rigorous framework for distinguishing the two.
The Cardinal Rule:
An attribute belongs on the construct (entity or relationship) whose instances it describes. If the attribute varies with each relationship instance, it belongs on the relationship. If it's constant across all relationships for that entity, it belongs on the entity.
Case Study: Employee Salary
Consider an employee's salary. Where should it go?
Scenario A: Fixed salary per employee
salary is an entity attribute on EMPLOYEEScenario B: Salary varies by assignment
salary is a relationship attribute on WORKS_INScenario C: Salary changes over time
The same data item can belong to different constructs depending on business requirements!
Ask: 'If I substitute one entity for another in this relationship, does the attribute value change?' If you replace Course A with Course B (keeping the same student), does enrollment_date change? Yes—it's a relationship attribute. Does student.birthdate change? No—it's an entity attribute.
The cardinality of a relationship affects how its attributes are implemented and whether they can be migrated to participating entities.
Many-to-Many (M:N):
Relationship attributes in M:N relationships are unambiguously necessary. They cannot be placed on either entity without creating redundancy or losing distinct values.
M:N: ENROLLS_IN (Student, Course, grade, enrollment_date)
STUDENT COURSE
┌────────┐ ┌──────────────────────┐ ┌────────┐
│ S101 │────▶│ (S101, C01, A, 2024) │◀────│ C01 │
│ │────▶│ (S101, C02, B, 2024) │ │ │
└────────┘ │ (S102, C01, A-, 2024)│◀────│ C02 │
┌────────┐────▶│ (S102, C03, C, 2024) │ │ │
│ S102 │ └──────────────────────┘ │ C03 │
└────────┘ └────────┘
Each (student, course) pair has its own grade and date.
Attributes cannot move to either entity without duplication.
One-to-Many (1:N):
In 1:N relationships, relationship attributes can theoretically migrate to the "many" side entity because each "many" entity participates in exactly one relationship instance.
1:N: WORKS_IN (Employee, Department, start_date, position)
Can migrate to Employee:
Employee table:
emp_id | name | dept_id | start_date | position
E01 | Alice | D01 | 2020-01-15 | Developer
E02 | Bob | D01 | 2021-03-20 | Analyst
E03 | Charlie | D02 | 2019-07-10 | Manager
This works because each employee has exactly one (start_date, position) for their current department. However, conceptually recognizing these as relationship attributes helps if requirements change (e.g., historical tracking needed).
| Cardinality | Attribute Location | Can Migrate? | Implementation |
|---|---|---|---|
| M:N | On relationship (junction table) | No—would require duplication | Column in junction table |
| 1:N | On relationship or N-side entity | Yes—to N-side entity | Column in N-side table or junction |
| 1:1 | On relationship or either entity | Yes—to either entity | Column in either table (choose one) |
Even when attributes migrate to an entity table for implementation, they remain conceptually relationship attributes. The dept_id, start_date, and position in the Employee table all describe the WORKS_IN relationship, not the employee intrinsically. Document this in your schema for future maintainers.
The implementation of relationship attributes in SQL follows directly from the relationship's cardinality and whether a junction table exists.
M:N Implementation (Junction Table Required):
1234567891011121314151617181920212223242526272829303132
-- Entity tablesCREATE TABLE Student ( student_id INT PRIMARY KEY, name VARCHAR(100), email VARCHAR(200)); CREATE TABLE Course ( course_id INT PRIMARY KEY, title VARCHAR(200), credits INT); -- Junction table with relationship attributesCREATE TABLE Enrollment ( student_id INT, course_id INT, -- Relationship attributes enrollment_date DATE NOT NULL, grade VARCHAR(2), status ENUM('active', 'withdrawn', 'completed') DEFAULT 'active', -- Constraints PRIMARY KEY (student_id, course_id), FOREIGN KEY (student_id) REFERENCES Student(student_id), FOREIGN KEY (course_id) REFERENCES Course(course_id)); -- Inserting relationship instances with attributesINSERT INTO Enrollment VALUES (101, 1, '2024-01-15', NULL, 'active'), (101, 2, '2024-01-16', 'A', 'completed'), (102, 1, '2024-01-20', 'B+', 'completed');1:N Implementation (Attributes in N-side Table):
-- Department (1-side)
CREATE TABLE Department (
dept_id INT PRIMARY KEY,
name VARCHAR(100),
budget DECIMAL(15,2)
);
-- Employee (N-side) with relationship attributes
CREATE TABLE Employee (
emp_id INT PRIMARY KEY,
name VARCHAR(100),
-- Foreign key for relationship
dept_id INT NOT NULL,
-- Relationship attributes (describe WORKS_IN, not Employee intrinsically)
start_date DATE NOT NULL,
position VARCHAR(100),
is_department_head BOOLEAN DEFAULT FALSE,
-- Constraint
FOREIGN KEY (dept_id) REFERENCES Department(dept_id)
);
Note that start_date, position, and is_department_head are relationship attributes even though they're stored in the Employee table. They describe the employee-department association, not the employee alone.
When relationship attributes are migrated to entity tables (as in 1:N), add comments documenting their true nature: '-- Relationship attribute: describes WORKS_IN, not Employee'. This prevents future confusion during schema evolution.
Relationship attributes appear in queries whenever you need information about the association itself, not just the participating entities.
Common Query Patterns:
12345678910111213141516171819202122232425262728293031323334
-- Find all enrollments with their metadataSELECT s.name AS student, c.title AS course, e.enrollment_date, e.grade, e.statusFROM Student sJOIN Enrollment e ON s.student_id = e.student_idJOIN Course c ON e.course_id = c.course_id; -- Filter by relationship attributeSELECT s.name, c.titleFROM Student sJOIN Enrollment e ON s.student_id = e.student_idJOIN Course c ON e.course_id = c.course_idWHERE e.grade IN ('A', 'A-', 'A+'); -- Top grades only -- Aggregate on relationship attributeSELECT c.title, AVG( CASE e.grade WHEN 'A' THEN 4.0 WHEN 'A-' THEN 3.7 WHEN 'B+' THEN 3.3 WHEN 'B' THEN 3.0 WHEN 'B-' THEN 2.7 WHEN 'C+' THEN 2.3 WHEN 'C' THEN 2.0 WHEN 'D' THEN 1.0 WHEN 'F' THEN 0.0 END) AS avg_gpaFROM Course cJOIN Enrollment e ON c.course_id = e.course_idWHERE e.status = 'completed'GROUP BY c.course_id, c.title; -- Date-based queries on relationship attributeSELECT s.name, c.title, e.enrollment_dateFROM Student sJOIN Enrollment e ON s.student_id = e.student_idJOIN Course c ON e.course_id = c.course_idWHERE e.enrollment_date >= '2024-01-01'ORDER BY e.enrollment_date DESC;Update Patterns:
-- Update a specific enrollment's grade
UPDATE Enrollment
SET grade = 'A', status = 'completed'
WHERE student_id = 101 AND course_id = 2;
-- Bulk update relationship attributes
UPDATE Enrollment
SET status = 'withdrawn'
WHERE enrollment_date < '2023-01-01' AND grade IS NULL;
Important: Notice that relationship attribute updates require identifying the specific relationship instance (the student-course pair), not just one entity.
Without relationship attributes, the Enrollment table would only record that student X is in course Y. With attributes, you can answer: When did they enroll? What grade did they earn? Are they still active? Relationship attributes transform relationships from boolean facts to rich descriptors.
Relationship attributes can be composite or multi-valued, just like entity attributes. These cases require special handling.
Composite Relationship Attributes:
A composite attribute has sub-components that together describe one characteristic.
SUPPLIES (Vendor, Product) with:
contract_period: (start_date, end_date)
contact: (name, phone, email)
Implementation Options:
contract_start_date, contract_end_datecontract_period DATERANGEcontract JSONMulti-Valued Relationship Attributes:
A multi-valued attribute can have multiple values for a single relationship instance.
ENROLLS_IN (Student, Course) with:
attendance_dates: [2024-01-15, 2024-01-17, 2024-01-19, ...]
homework_scores: [95, 87, 92, ...]
Implementation requires a separate table:
-- Main relationship table
CREATE TABLE Enrollment (
student_id INT,
course_id INT,
enrollment_date DATE,
PRIMARY KEY (student_id, course_id)
);
-- Multi-valued relationship attribute
CREATE TABLE EnrollmentAttendance (
student_id INT,
course_id INT,
attendance_date DATE,
status ENUM('present', 'absent', 'excused'),
PRIMARY KEY (student_id, course_id, attendance_date),
FOREIGN KEY (student_id, course_id)
REFERENCES Enrollment(student_id, course_id)
);
-- Another multi-valued relationship attribute
CREATE TABLE EnrollmentHomework (
student_id INT,
course_id INT,
homework_number INT,
score DECIMAL(5,2),
submitted_date DATETIME,
PRIMARY KEY (student_id, course_id, homework_number),
FOREIGN KEY (student_id, course_id)
REFERENCES Enrollment(student_id, course_id)
);
If a relationship has many multi-valued attributes, it may indicate the relationship itself should become an entity. When ENROLLMENT needs attendance, homework, exams, and participation tracking, consider promoting it to an ENROLLMENT entity with its own relationships to ATTENDANCE_RECORD, HOMEWORK_SUBMISSION, etc.
Relationships often have temporal dimensions—they exist during a time period, or their attributes change over time. Handling temporality in relationship attributes requires careful design.
Time-Bounded Relationships:
Some relationships have explicit start and end times:
CREATE TABLE Employment (
employee_id INT,
company_id INT,
start_date DATE NOT NULL,
end_date DATE, -- NULL means current
position VARCHAR(100),
salary DECIMAL(12,2),
PRIMARY KEY (employee_id, company_id, start_date), -- Includes start for history
FOREIGN KEY (employee_id) REFERENCES Employee(id),
FOREIGN KEY (company_id) REFERENCES Company(id)
);
The (employee_id, company_id, start_date) primary key allows the same employee-company pair to appear multiple times with different periods (rehires, promotions recorded as new periods).
Historical Tracking:
When relationship attribute values change and history must be preserved:
-- Current enrollments (standard design)
CREATE TABLE Enrollment (
student_id INT,
course_id INT,
current_grade VARCHAR(2),
PRIMARY KEY (student_id, course_id)
);
-- Grade history (relationship attribute changes over time)
CREATE TABLE EnrollmentGradeHistory (
student_id INT,
course_id INT,
grade VARCHAR(2),
effective_date DATETIME,
changed_by INT, -- Who made the change
reason VARCHAR(200), -- Why it changed
PRIMARY KEY (student_id, course_id, effective_date),
FOREIGN KEY (student_id, course_id)
REFERENCES Enrollment(student_id, course_id)
);
This pattern maintains current values for fast querying while preserving full history for auditing.
| Pattern | Description | Use Case |
|---|---|---|
| Current Only | Store only current relationship state | Where history is not required |
| Time-Bounded | start_date/end_date columns | Employment, memberships, contracts |
| History Table | Separate table for historical values | Audit requirements, grade changes |
| Temporal Versioning | Valid-time and transaction-time tracking | Financial systems, legal records |
Consider temporal requirements during initial design. Adding time-bounded attributes to an existing relationship is much harder than including them from the start. Ask stakeholders: 'Do we need to know when this relationship existed?' and 'Do we need to track changes to relationship attributes?'
Based on years of database design experience, here are best practices for handling relationship attributes effectively:
enrollment_date not just date.If you're unsure whether an attribute belongs on an entity or relationship, try modeling it both ways. The one that avoids redundancy and represents the real-world semantics accurately is correct. When still uncertain, choose the relationship—it's easier to migrate attributes from relationship to entity than vice versa.
Relationship attributes capture data that describes the association between entities rather than the entities themselves. They are essential for accurate modeling of many real-world relationships, especially M:N relationships where attribute values vary by each entity pair.
Module Complete:
With relationship attributes understood, you've completed the study of Relationships in ER Modeling. You now understand:
This comprehensive understanding of relationships prepares you to model complex domains accurately and implement them effectively in database systems.
Congratulations! You've mastered the concept of relationships in ER modeling—from definition through implementation. This knowledge forms the foundation for creating accurate, efficient database schemas that faithfully represent real-world domains. Next, you'll explore Cardinality constraints in detail.