comments | difficulty | edit_url | tags | |
---|---|---|---|---|
true |
简单 |
|
表: Cinema
+-------------+------+ | Column Name | Type | +-------------+------+ | seat_id | int | | free | bool | +-------------+------+ Seat_id 是该表的自动递增主键列。 在 PostgreSQL 中,free
存储为整数。请使用::boolean
将其转换为布尔格式。 该表的每一行表示第 i 个座位是否空闲。1 表示空闲,0 表示被占用。
查找电影院所有连续可用的座位。
返回按 seat_id
升序排序 的结果表。
测试用例的生成使得两个以上的座位连续可用。
结果表格式如下所示。
示例 1:
输入: Cinema 表: +---------+------+ | seat_id | free | +---------+------+ | 1 | 1 | | 2 | 0 | | 3 | 1 | | 4 | 1 | | 5 | 1 | +---------+------+ 输出: +---------+ | seat_id | +---------+ | 3 | | 4 | | 5 | +---------+
我们可以使用自连接的方式,将相邻的两个座位连接起来,然后筛选出连续空余的座位并去重排序即可。
# Write your MySQL query statement below
SELECT DISTINCT a.seat_id
FROM
Cinema AS a
JOIN Cinema AS b ON ABS(a.seat_id - b.seat_id) = 1 AND a.free AND b.free
ORDER BY 1;
我们也可以使用 LAG
和 LEAD
函数(或者 SUM() OVER(ROWS BETWEEN 1 PRECEDING AND 1 FOLLOWING)
)来获取相邻的座位信息,然后筛选出连续空余的座位并去重排序即可。
# Write your MySQL query statement below
WITH
T AS (
SELECT
seat_id,
(free + (LAG(free) OVER (ORDER BY seat_id))) AS a,
(free + (LEAD(free) OVER (ORDER BY seat_id))) AS b
FROM Cinema
)
SELECT seat_id
FROM T
WHERE a = 2 OR b = 2;
# Write your MySQL query statement below
WITH
T AS (
SELECT
*,
SUM(free = 1) OVER (
ORDER BY seat_id
ROWS BETWEEN 1 PRECEDING AND 1 FOLLOWING
) AS cnt
FROM Cinema
)
SELECT seat_id
FROM T
WHERE free = 1 AND cnt > 1
ORDER BY 1;