Skip to content

Instantly share code, notes, and snippets.

@yancya
Last active October 10, 2022 03:31
Show Gist options
  • Star 2 You must be signed in to star a gist
  • Fork 0 You must be signed in to fork a gist
  • Save yancya/387b61924cbcd672176bfd0d58320625 to your computer and use it in GitHub Desktop.
Save yancya/387b61924cbcd672176bfd0d58320625 to your computer and use it in GitHub Desktop.
カラム名にテーブル名を含めるべきか否か考える https://twitter.com/neko314_/status/1579000770938433536?s=61&t=TGIhzWS_A0b4j3dWhxK50A
WITH teams AS (
SELECT 1 AS id
, 'yancya-club' AS name)
, members AS (
SELECT 1 AS id
, 'yancya' AS name
, 1 AS team_id)
SELECT *
FROM members
JOIN teams ON teams.id = team_id
;
-- id | name | team_id | id | name
-- ----+--------+---------+----+-------------
-- 1 | yancya | 1 | 1 | yancya-club
-- 確かに `id` とか `name` が複数あってダルそう
WITH teams AS (
SELECT 1 AS id
, 'yancya-club' AS name)
, members AS (
SELECT 1 AS id
, 'yancya' AS name
, 1 AS team_id)
SELECT id, name
FROM members
JOIN teams ON teams.id = team_id
;
-- ERROR: column reference "id" is ambiguous
-- LINE 10: SELECT id, name
-- 辛い、でもまぁ、これは、それはそう、という気がする
WITH teams AS (
SELECT 1 AS team_id
, 'yancya-club' AS team_name)
, members AS (
SELECT 1 AS member_id
, 'yancya' AS member_name
, 1 AS member_team_id) -- ここがなぁ
SELECT member_id
, member_name
, member_team_id -- このなぁ
, team_id
, team_name
FROM members
JOIN teams ON teams.team_id = members.member_team_id
;
-- member_id | member_name | member_team_id | team_id | team_name
-- -----------+-------------+----------------+---------+-------------
-- 1 | yancya | 1 | 1 | yancya-club
-- SELECT の部分はスッキリしている気はしますが、外部キーの名前に違和感が出てきますね……
WITH teams AS (
SELECT 1 AS id
, 'yancya-club' AS name)
, members AS (
SELECT 1 AS id
, 'yancya' AS name
, 1 AS team_id)
SELECT members.id AS member_id
, members.name AS member_name
, members.team_id AS member_team_id -- これは……
, teams.id AS team_id
, teams.name AS team_name
FROM members
JOIN teams ON teams.id = team_id
;
-- member_id | member_name | members_team_id | team_id | team_name
-- -----------+-------------+-----------------+---------+-------------
-- 1 | yancya | 1 | 1 | yancya-club
-- 別名を付ければ済むわけですが、それが面倒というのも分かる
-- 別名も命名規約に従っていると微妙な別名を付けることになりかねない
-- JOIN のキーに使ったカラム名はテーブル名プレフィックスつけない方がいいのでは……
WITH teams AS (
SELECT 1 AS team_id
, 'yancya-club' AS name)
, members AS (
SELECT 1 AS id
, 'yancya' AS name
, 1 AS team_id)
SELECT members.id AS member_id
, members.name AS member_name
, team_id
, teams.name AS team_name
FROM members
JOIN teams USING(team_id)
;
-- member_id | member_name | team_id | team_name
-- -----------+-------------+---------+-------------
-- 1 | yancya | 1 | yancya-club
-- USING を使うと勝手にまとまってくれて嬉しい上にテーブル名で修飾しなくて済むようになる
-- そのために、サロゲートキー(主キー)だけは外部キーと同じ名前(テーブル名つきの名前)にしたらどうか思う事はある
WITH team AS (
SELECT 1 AS team_id
, 'yancya-club' AS name)
, member AS (
SELECT 1 AS id
, 'yancya' AS name
, 1 AS team_id)
SELECT member.id AS member_id
, member.name AS member_name
, team_id
, team.name AS team_name
FROM member
JOIN team USING(team_id)
;
-- member_id | member_name | team_id | team_name
-- -----------+-------------+---------+-------------
-- 1 | yancya | 1 | yancya-club
-- オフトピですが、テーブル名は単数形の方が良いのではと思うことがあります
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment