Skip to content

Commit 57d33e8

Browse files
authored
feat: add solutions to lc problem: No.3626 (#4596)
No.3626.Find Stores with Inventory Imbalance
1 parent 6569141 commit 57d33e8

File tree

8 files changed

+727
-0
lines changed

8 files changed

+727
-0
lines changed
Lines changed: 306 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,306 @@
1+
---
2+
comments: true
3+
difficulty: 中等
4+
edit_url: https://github.com/doocs/leetcode/edit/main/solution/3600-3699/3626.Find%20Stores%20with%20Inventory%20Imbalance/README.md
5+
tags:
6+
- 数据库
7+
---
8+
9+
<!-- problem:start -->
10+
11+
# [3626. 查找库存不平衡的店铺](https://leetcode.cn/problems/find-stores-with-inventory-imbalance)
12+
13+
[English Version](/solution/3600-3699/3626.Find%20Stores%20with%20Inventory%20Imbalance/README_EN.md)
14+
15+
## 题目描述
16+
17+
<!-- description:start -->
18+
19+
<p>表:<code>stores</code></p>
20+
21+
<pre>
22+
+-------------+---------+
23+
| Column Name | Type |
24+
+-------------+---------+
25+
| store_id | int |
26+
| store_name | varchar |
27+
| location | varchar |
28+
+-------------+---------+
29+
store_id 是这张表的唯一主键。
30+
每一行包含有关商店及其位置的信息。
31+
</pre>
32+
33+
<p>表:<code>inventory</code></p>
34+
35+
<pre>
36+
+-------------+---------+
37+
| Column Name | Type |
38+
+-------------+---------+
39+
| inventory_id| int |
40+
| store_id | int |
41+
| product_name| varchar |
42+
| quantity | int |
43+
| price | decimal |
44+
+-------------+---------+
45+
inventory_id 是这张表的唯一主键。
46+
每一行代表特定商店中某一特定产品的库存情况。
47+
</pre>
48+
49+
<p>编写一个解决方案来查找库存不平衡的商店 - 即最贵商品的库存比最便宜商品少的商店。</p>
50+
51+
<ul>
52+
<li>对于每个商店,识别 <strong>最贵的商品</strong>(最高价格)及其数量,如果有多个最贵的商品则选取数量最多的一个。</li>
53+
<li>对于每个商店,识别 <strong>最便宜的商品</strong>(最低价格)及其数量,如果有多个最便宜的物品则选取数量最多的一个。</li>
54+
<li>如果最贵商品的数量 <strong>少于</strong> 最便宜商品的数量,则商店存在库存不平衡。</li>
55+
<li>按(最便宜商品的数量/最贵商品的数量)计算 <strong>不平衡比</strong>。</li>
56+
<li>不平衡比&nbsp;<strong>舍入到 2 位</strong>&nbsp;小数</li>
57+
<li>结果只包含&nbsp;<strong>至少有</strong><strong> </strong><code>3</code>&nbsp;<strong>个不同商品</strong> 的店铺</li>
58+
</ul>
59+
60+
<p>返回结果表以不平衡比率降序排列,然后按商店名称升序排列。</p>
61+
62+
<p>结果格式如下所示。</p>
63+
64+
<p>&nbsp;</p>
65+
66+
<p><strong class="example">示例:</strong></p>
67+
68+
<div class="example-block">
69+
<p><strong>输入:</strong></p>
70+
71+
<p>stores 表:</p>
72+
73+
<pre class="example-io">
74+
+----------+----------------+-------------+
75+
| store_id | store_name | location |
76+
+----------+----------------+-------------+
77+
| 1 | Downtown Tech | New York |
78+
| 2 | Suburb Mall | Chicago |
79+
| 3 | City Center | Los Angeles |
80+
| 4 | Corner Shop | Miami |
81+
| 5 | Plaza Store | Seattle |
82+
+----------+----------------+-------------+
83+
</pre>
84+
85+
<p>inventory 表:</p>
86+
87+
<pre class="example-io">
88+
+--------------+----------+--------------+----------+--------+
89+
| inventory_id | store_id | product_name | quantity | price |
90+
+--------------+----------+--------------+----------+--------+
91+
| 1 | 1 | Laptop | 5 | 999.99 |
92+
| 2 | 1 | Mouse | 50 | 19.99 |
93+
| 3 | 1 | Keyboard | 25 | 79.99 |
94+
| 4 | 1 | Monitor | 15 | 299.99 |
95+
| 5 | 2 | Phone | 3 | 699.99 |
96+
| 6 | 2 | Charger | 100 | 25.99 |
97+
| 7 | 2 | Case | 75 | 15.99 |
98+
| 8 | 2 | Headphones | 20 | 149.99 |
99+
| 9 | 3 | Tablet | 2 | 499.99 |
100+
| 10 | 3 | Stylus | 80 | 29.99 |
101+
| 11 | 3 | Cover | 60 | 39.99 |
102+
| 12 | 4 | Watch | 10 | 299.99 |
103+
| 13 | 4 | Band | 25 | 49.99 |
104+
| 14 | 5 | Camera | 8 | 599.99 |
105+
| 15 | 5 | Lens | 12 | 199.99 |
106+
+--------------+----------+--------------+----------+--------+
107+
</pre>
108+
109+
<p><strong>输出:</strong></p>
110+
111+
<pre class="example-io">
112+
+----------+----------------+-------------+------------------+--------------------+------------------+
113+
| store_id | store_name | location | most_exp_product | cheapest_product | imbalance_ratio |
114+
+----------+----------------+-------------+------------------+--------------------+------------------+
115+
| 3 | City Center | Los Angeles | Tablet | Stylus | 40.00 |
116+
| 1 | Downtown Tech | New York | Laptop | Mouse | 10.00 |
117+
| 2 | Suburb Mall | Chicago | Phone | Case | 25.00 |
118+
+----------+----------------+-------------+------------------+--------------------+------------------+
119+
</pre>
120+
121+
<p><strong>解释:</strong></p>
122+
123+
<ul>
124+
<li><strong>Downtown Tech (store_id = 1):</strong>
125+
126+
<ul>
127+
<li>最贵的商品:笔记本($999.99)数量为 5</li>
128+
<li>最便宜的商品:鼠标($19.99)数量为 50</li>
129+
<li>库存不平衡:5 &lt; 50(贵的商品的库存更少)</li>
130+
<li>不平衡比:50 / 5 = 10.00</li>
131+
<li>有 4&nbsp;件商品(≥ 3),所以满足要求</li>
132+
</ul>
133+
</li>
134+
<li><strong>Suburb Mall (store_id = 2):</strong>
135+
<ul>
136+
<li>最贵的商品:手机($699.99)数量为 3</li>
137+
<li>最便宜的商品:保护壳($15.99)数量为75</li>
138+
<li>库存不平衡:3 &lt; 75(贵的商品的库存更少)</li>
139+
<li>不平衡比:75 / 3 = 25.00</li>
140+
<li>有 4&nbsp;件商品(≥ 3),所以满足要求</li>
141+
</ul>
142+
</li>
143+
<li><strong>City Center (store_id = 3):</strong>
144+
<ul>
145+
<li>最贵的商品:平板电脑($499.99)数量为 2</li>
146+
<li>最便宜的商品:触控笔($29.99)数量为 80</li>
147+
<li>不平衡比:2 &lt; 80(贵的商品的库存更少)</li>
148+
<li>不平衡比:80 / 2 = 40.00</li>
149+
<li>有 3 件商品(≥ 3),所以满足要求</li>
150+
</ul>
151+
</li>
152+
<li><strong>未包含的商店:</strong>
153+
<ul>
154+
<li>Corner Shop(store_id = 4):只有两件商品(手表,手环)- 不满足最少 3 件商品的要求</li>
155+
<li>Plaza Store(store_id = 5):只有两件商品(相机,镜头)- 不满足最少 3 件商品的要求</li>
156+
</ul>
157+
</li>
158+
159+
</ul>
160+
161+
<p>结果表按不平衡比降序排序,然后以商店名升序排序。</p>
162+
</div>
163+
164+
<!-- description:end -->
165+
166+
## 解法
167+
168+
<!-- solution:start -->
169+
170+
### 方法一:窗口函数 + 连接
171+
172+
我们可以使用窗口函数来计算每个商店的最贵和最便宜商品,并且使用连接来筛选出库存不平衡的商店。具体步骤如下:
173+
174+
1. **计算每个商店的最贵商品**:使用 `RANK()` 窗口函数按价格降序排列,并在数量相同的情况下按数量降序排列,选取排名第一的商品。
175+
2. **计算每个商店的最便宜商品**:使用 `RANK()` 窗口函数按价格升序排列,并在数量相同的情况下按数量降序排列,选取排名第一的商品。
176+
3. **筛选至少有 3 个不同商品的商店**:使用 `COUNT()` 窗口函数来统计每个商店的商品数量,并筛选出数量大于等于 3 的商店。
177+
4. **连接最贵和最便宜商品**:将最贵商品和最便宜商品的结果进行连接,确保最贵商品的数量小于最便宜商品的数量。
178+
5. **计算不平衡比**:计算最便宜商品数量与最贵商品数量的比率,并将其舍入到两位小数。
179+
6. **连接商店信息**:将结果与商店信息表进行连接,以获取商店名称和位置。
180+
7. **排序结果**:按不平衡比降序排列,然后按商店名称升序排列。
181+
182+
<!-- tabs:start -->
183+
184+
#### MySQL
185+
186+
```sql
187+
# Write your MySQL query statement below
188+
WITH
189+
T AS (
190+
SELECT
191+
store_id,
192+
product_name,
193+
quantity,
194+
RANK() OVER (
195+
PARTITION BY store_id
196+
ORDER BY price DESC, quantity DESC
197+
) rk1,
198+
RANK() OVER (
199+
PARTITION BY store_id
200+
ORDER BY price, quantity DESC
201+
) rk2,
202+
COUNT(1) OVER (PARTITION BY store_id) cnt
203+
FROM inventory
204+
),
205+
P1 AS (
206+
SELECT *
207+
FROM T
208+
WHERE rk1 = 1 AND cnt >= 3
209+
),
210+
P2 AS (
211+
SELECT *
212+
FROM T
213+
WHERE rk2 = 1
214+
)
215+
SELECT
216+
s.store_id store_id,
217+
store_name,
218+
location,
219+
p1.product_name most_exp_product,
220+
p2.product_name cheapest_product,
221+
ROUND(p2.quantity / p1.quantity, 2) imbalance_ratio
222+
FROM
223+
P1 p1
224+
JOIN P2 p2 ON p1.store_id = p2.store_id AND p1.quantity < p2.quantity
225+
JOIN stores s ON p1.store_id = s.store_id
226+
ORDER BY imbalance_ratio DESC, store_name;
227+
```
228+
229+
#### Pandas
230+
231+
```python
232+
import pandas as pd
233+
234+
235+
def find_inventory_imbalance(
236+
stores: pd.DataFrame, inventory: pd.DataFrame
237+
) -> pd.DataFrame:
238+
# 首先筛选出至少有3个产品的店铺
239+
store_counts = inventory["store_id"].value_counts()
240+
valid_stores = store_counts[store_counts >= 3].index
241+
242+
# 找出每个店铺最贵的产品
243+
most_expensive = (
244+
inventory[inventory["store_id"].isin(valid_stores)]
245+
.sort_values(["store_id", "price", "quantity"], ascending=[True, False, False])
246+
.groupby("store_id")
247+
.first()
248+
.reset_index()
249+
)
250+
251+
# 找出每个店铺最便宜的产品
252+
cheapest = (
253+
inventory.sort_values(
254+
["store_id", "price", "quantity"], ascending=[True, True, False]
255+
)
256+
.groupby("store_id")
257+
.first()
258+
.reset_index()
259+
)
260+
261+
# 合并结果
262+
merged = pd.merge(
263+
most_expensive, cheapest, on="store_id", suffixes=("_most", "_cheap")
264+
)
265+
266+
# 筛选出最贵产品数量 < 最便宜产品数量的记录
267+
result = merged[merged["quantity_most"] < merged["quantity_cheap"]].copy()
268+
269+
# 计算不平衡比例
270+
result["imbalance_ratio"] = (
271+
result["quantity_cheap"] / result["quantity_most"]
272+
).round(2)
273+
274+
# 合并店铺信息
275+
result = pd.merge(result, stores, on="store_id")
276+
277+
# 选择并重命名列
278+
result = result[
279+
[
280+
"store_id",
281+
"store_name",
282+
"location",
283+
"product_name_most",
284+
"product_name_cheap",
285+
"imbalance_ratio",
286+
]
287+
].rename(
288+
columns={
289+
"product_name_most": "most_exp_product",
290+
"product_name_cheap": "cheapest_product",
291+
}
292+
)
293+
294+
# 按要求排序
295+
result = result.sort_values(
296+
["imbalance_ratio", "store_name"], ascending=[False, True]
297+
).reset_index(drop=True)
298+
299+
return result
300+
```
301+
302+
<!-- tabs:end -->
303+
304+
<!-- solution:end -->
305+
306+
<!-- problem:end -->

0 commit comments

Comments
 (0)