How to have a one-to-many relationship with a privileged child?

Another way (without Nulls and without cycles in the FOREIGN KEY relationships) is to have a third table to store the "favourite children". In most DBMS, you'll need an additional UNIQUE constraint on TableB.

@Aaron was faster to identify that the naming convention above is rather cumbersome and can lead to errors. It's usually better (and will keep you sane) if you don't have Id columns all over your tables and if the columns (that are joined) have same names in the many tables that appear. So, here's a renaming:

Parent
    ParentID        INT NOT NULL PRIMARY KEY

Child
    ChildID         INT NOT NULL PRIMARY KEY
    ParentID        INT NOT NULL FOREIGN KEY REFERENCES Parent (ParentID)
    UNIQUE (ParentID, ChildID)

FavoriteChild
    ParentID        INT NOT NULL PRIMARY KEY
    ChildID         INT NOT NULL 
    FOREIGN KEY (ParentID, ChildID) 
        REFERENCES Child (ParentID, ChildID)

In SQL-Server (that you are using), you also have the option of the IsFavorite bit column you mention. The unique favourite child per parent can be accomplished via a filtered Unique Index:

Parent
    ParentID        INT NOT NULL PRIMARY KEY

Child
    ChildID         INT NOT NULL PRIMARY KEY
    ParentID        INT NOT NULL FOREIGN KEY REFERENCES Parent (ParentID)
    IsFavorite      BIT NOT NULL

CREATE UNIQUE INDEX is_FavoriteChild
  ON Child (ParentID)
  WHERE IsFavorite = 1 ;

And the main reason that your option 1 is not recommended, at least not in SQL-Server, is that the pattern of circular paths in the foreign key references has some problems.

Read a quite old article: SQL By Design: The Circular Reference

When inserting or deleting rows from the two table, you'll run into the "chicken-and-egg" problem. Which table should I insert first - without violating any constraint?

In order to solve that, you have to define at least one column nullable. (OK, technically you don't have to, you can have all columns as NOT NULL but only in DBMS, like Postgres and Oracle, that have implemented deferrable constraints. See @Erwin's answer in a similar question: Complex foreign key constraint in SQLAlchemy on how this can be done in Postgres). Still, this setup feels like skating on thin ice.

Check also an almost identical question at SO (but for MySQL) In SQL, is it OK for two tables to refer to each other? where my answer is pretty much the same. MySQL has no partial indexes though, so the only viable options are the nullable FK and the extra table solution.


It depends on what your priority is. Do you want to avoid work or do you want to adhere to the strictest rules of normalization?

Personally, I think it is better to have IsFavorite in the child table, and would be willing to put in the work to make sure that at most one child for every parent is that parent's favorite. The primary reason has nothing to do with the nullable foreign key thing: I don't like the idea at all of foreign keys pointing in both directions.

@ypercube's suggestion is a good compromise as well.

As an aside, please, please, please don't litter your schema with meaningless column names like Id. I would much rather see the Id be named in a meaningful way throughout the schema. Does it identify an author? Ok, call it AuthorID. Does it represent a product? Ok, ProductID. Is it an employee, and in some cases references a manager? Ok, EmployeeID and ManagerID make more sense to me than ID and Parent. While it may seem logical to leave that out (and redundant to put it in), when you start writing complex joins (or post queries here) you will definitely sense some cursing when you're trying to reverse engineer a bunch of joins that point to columns like a.Parent = b.ID ... blecch.