MySQL + JSON = 王炸!!
作者:「已注銷」
JSON 數(shù)據(jù)類型
{
?"Image":?{
???"Width":?800,
???"Height":?600,
???"Title":?"View?from?15th?Floor",
???"Thumbnail":?{
?????"Url":?"http://www.example.com/image/481989943",
?????"Height":?125,
?????"Width":?100
???},
?"IDs":?[116,?943,?234,?38793]
?}
}
[
???{
?????"precision":?"zip",
?????"Latitude":?37.7668,
?????"Longitude":?-122.3959,
?????"Address":?"",
?????"City":?"SAN?FRANCISCO",
?????"State":?"CA",
?????"Zip":?"94107",
?????"Country":?"US"
???},
???{
?????"precision":?"zip",
?????"Latitude":?37.371991,
?????"Longitude":?-122.026020,
?????"Address":?"",
?????"City":?"SUNNYVALE",
?????"State":?"CA",
?????"Zip":?"94085",
?????"Country":?"US"
???}
?]
業(yè)務(wù)表結(jié)構(gòu)設(shè)計實戰(zhàn)
用戶登錄設(shè)計
DROP?TABLE?IF?EXISTS?UserLogin;
CREATE?TABLE?UserLogin?(
????userId?BIGINT?NOT?NULL,
????loginInfo?JSON,
????PRIMARY?KEY(userId)
);
SET?@a?=?'
{
???"cellphone"?:?"13918888888",
???"wxchat"?:?"破產(chǎn)碼農(nóng)",
???"QQ"?:?"82946772"
}
';
INSERT?INTO?UserLogin?VALUES?(1,@a);
SET?@b?=?'
{??
??"cellphone"?:?"15026888888"
}
';
INSERT?INTO?UserLogin?VALUES?(2,@b);
SELECT
????userId,
????JSON_UNQUOTE(JSON_EXTRACT(loginInfo,"$.cellphone"))?cellphone,
????JSON_UNQUOTE(JSON_EXTRACT(loginInfo,"$.wxchat"))?wxchat
FROM?UserLogin;
+--------+-------------+--------------+
|?userId?|?cellphone???|?wxchat???????|
+--------+-------------+--------------+
|??????1?|?13918888888?|?破產(chǎn)碼農(nóng)?????|
|??????2?|?15026888888?|?NULL?????????|
+--------+-------------+--------------+
2?rows?in?set?(0.01?sec)
SELECT?
????userId,
????loginInfo->>"$.cellphone"?cellphone,
????loginInfo->>"$.wxchat"?wxchat
FROM?UserLogin;
ALTER?TABLE?UserLogin?ADD?COLUMN?cellphone?VARCHAR(255)?AS?(loginInfo->>"$.cellphone");
ALTER?TABLE?UserLogin?ADD?UNIQUE?INDEX?idx_cellphone(cellphone);
EXPLAIN?SELECT??*??FROM?UserLogin?
WHERE?cellphone?=?'13918888888'\G
***************************?1.?row?***************************
???????????id:?1
??select_type:?SIMPLE
????????table:?UserLogin
???partitions:?NULL
?????????type:?const
possible_keys:?idx_cellphone
??????????key:?idx_cellphone
??????key_len:?1023
??????????ref:?const
?????????rows:?1
?????filtered:?100.00
????????Extra:?NULL
1?row?in?set,?1?warning?(0.00?sec)
CREATE?TABLE?UserLogin?(
????userId?BIGINT,
????loginInfo?JSON,
????cellphone?VARCHAR(255)?AS?(loginInfo->>"$.cellphone"),
????PRIMARY?KEY(userId),
????UNIQUE?KEY?uk_idx_cellphone(cellphone)
);
用戶畫像設(shè)計
在電商行業(yè)中,根據(jù)用戶的穿搭喜好,推薦相應(yīng)的商品; 在音樂行業(yè)中,根據(jù)用戶喜歡的音樂風(fēng)格和常聽的歌手,推薦相應(yīng)的歌曲; 在金融行業(yè),根據(jù)用戶的風(fēng)險喜好和投資經(jīng)驗,推薦相應(yīng)的理財產(chǎn)品。
CREATE?TABLE?Tags?(
????tagId?bigint?auto_increment,
????tagName?varchar(255)?NOT?NULL,
????primary?key(tagId)
);
SELECT?*?FROM?Tags;
+-------+--------------+
|?tagId?|?tagName??????|
+-------+--------------+
|?????1?|?70后?????????|
|?????2?|?80后?????????|
|?????3?|?90后?????????|
|?????4?|?00后?????????|
|?????5?|?愛運動???????|
|?????6?|?高學(xué)歷???????|
|?????7?|?小資?????????|
|?????8?|?有房?????????|
|?????9?|?有車?????????|
|????10?|?常看電影?????|
|????11?|?愛網(wǎng)購???????|
|????12?|?愛外賣???????|
+-------+--------------+
+-------+---------------------------------------+
|用戶????|標(biāo)簽???????????????????????????????????|
+-------+---------------------------------------+
|David ?|80后?;?高學(xué)歷?;?小資?;?有房?;常看電影???|
|Tom ???|90后?;常看電影?;?愛外賣?????????????????|
+-------+---------------------------------------
DROP?TABLE?IF?EXISTS?UserTag;
CREATE?TABLE?UserTag?(
????userId?bigint?NOT?NULL,
????userTags?JSON,
????PRIMARY?KEY?(userId)
);
INSERT?INTO?UserTag?VALUES?(1,'[2,6,8,10]');
INSERT?INTO?UserTag?VALUES?(2,'[3,10,12]');
ALTER?TABLE?UserTag
ADD?INDEX?idx_user_tags?((cast((userTags->"$")?as?unsigned?array)));
EXPLAIN?SELECT?*?FROM?UserTag?
WHERE?10?MEMBER?OF(userTags->"$")\G
***************************?1.?row?***************************
???????????id:?1
??select_type:?SIMPLE
????????table:?UserTag
???partitions:?NULL
?????????type:?ref
possible_keys:?idx_user_tags
??????????key:?idx_user_tags
??????key_len:?9
??????????ref:?const
?????????rows:?1
?????filtered:?100.00
????????Extra:?Using?where
1?row?in?set,?1?warning?(0.00?sec)
SELECT?*?FROM?UserTag?
WHERE?10?MEMBER?OF(userTags->"$");
+--------+---------------+
|?userId?|?userTags??????|
+--------+---------------+
|??????1?|?[2,?6,?8,?10]?|
|??????2?|?[3,?10,?12]???|
+--------+---------------+
2?rows?in?set?(0.00?sec)
EXPLAIN?SELECT?*?FROM?UserTag?
WHERE?JSON_CONTAINS(userTags->"$",?'[2,10]')\G
***************************?1.?row?***************************
???????????id:?1
??select_type:?SIMPLE
????????table:?UserTag
???partitions:?NULL
?????????type:?range
possible_keys:?idx_user_tags
??????????key:?idx_user_tags
??????key_len:?9
??????????ref:?NULL
?????????rows:?3
?????filtered:?100.00
????????Extra:?Using?where
1?row?in?set,?1?warning?(0.00?sec)
SELECT?*?FROM?UserTag?
WHERE?JSON_CONTAINS(userTags->"$",?'[2,10]');
+--------+---------------+
|?userId?|?userTags??????|
+--------+---------------+
|??????1?|?[2,?6,?8,?10]?|
+--------+---------------+
1?row?in?set?(0.00?sec)
EXPLAIN?SELECT?*?FROM?UserTag?
WHERE?JSON_OVERLAPS(userTags->"$",?'[2,3,10]')\G
***************************?1.?row?***************************
???????????id:?1
??select_type:?SIMPLE
????????table:?UserTag
???partitions:?NULL
?????????type:?range
possible_keys:?idx_user_tags
??????????key:?idx_user_tags
??????key_len:?9
??????????ref:?NULL
?????????rows:?4
?????filtered:?100.00
????????Extra:?Using?where
1?row?in?set,?1?warning?(0.00?sec)
SELECT?*?FROM?UserTag?
WHERE?JSON_OVERLAPS(userTags->"$",?'[2,3,10]');
+--------+---------------+
|?userId?|?userTags??????|
+--------+---------------+
|??????1?|?[2,?6,?8,?10]?|
|??????2?|?[3,?10,?12]???|
+--------+---------------+
2?rows?in?set?(0.01?sec)
總結(jié)
使用 JSON 數(shù)據(jù)類型,推薦用 MySQL 8.0.17 以上的版本,性能更好,同時也支持 Multi-Valued Indexes; JSON 數(shù)據(jù)類型的好處是無須預(yù)先定義列,數(shù)據(jù)本身就具有很好的描述性; 不要將有明顯關(guān)系型的數(shù)據(jù)用 JSON 存儲,如用戶余額、用戶姓名、用戶身份證等,這些都是每個用戶必須包含的數(shù)據(jù); JSON 數(shù)據(jù)類型推薦使用在不經(jīng)常更新的靜態(tài)數(shù)據(jù)存儲。
點分享 點收藏 點點贊 點在看
評論
圖片
表情




