1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176 177 178 179 180 181 182 183 184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213 214 215 216 217 218 219 220 221 222 223 224 225 226 227 228 229 230 231 232 233 234 235 236 237 238 239 240 241 242 243 244 245 246 247 248 249 250 251
| #5.综合案例 # 1、创建数据库test01_library CREATE DATABASE IF NOT EXISTS test01_library CHARACTER SET 'utf8';
USE test01_library;
# 2、创建表 books,表结构如下: CREATE TABLE IF NOT EXISTS books( id INT, `name` VARCHAR(50), `authors` VARCHAR(100), price FLOAT, pubdate YEAR, note VARCHAR(100), num INT );
DESC books; /* +---------+--------------+------+-----+---------+-------+ | Field | Type | Null | Key | Default | Extra | +---------+--------------+------+-----+---------+-------+ | id | int | YES | | NULL | | | name | varchar(50) | YES | | NULL | | | authors | varchar(100) | YES | | NULL | | | price | float | YES | | NULL | | | pubdate | year | YES | | NULL | | | note | varchar(100) | YES | | NULL | | | num | int | YES | | NULL | | +---------+--------------+------+-----+---------+-------+ */ SELECT * FROM books;
# 3、向books表中插入记录 # 1)不指定字段名称,插入第一条记录 INSERT INTO books VALUES(1,'Tal of AAA','Dickes',23,'1995','novel',11); # 2)指定所有字段名称,插入第二记录 INSERT INTO books(id,NAME,AUTHORS,price,pubdate,note,num) VALUES(2,'EmmaT','Jane lura',35,'1993','joke',22); # 3)同时插入多条记录(剩下的所有记录) INSERT INTO books(id,NAME,AUTHORS,price,pubdate,note,num) VALUES (3,'Story of Jane','Jane Tim',40,2001,'novel',0), (4,'Lovey Day','George Byron',20,2005,'novel',30), (5,'Old land','Honore Blade',30,2010,'Law',0), (6,'The Battle','Upton Sara',30,1999,'medicine',40), (7,'Rose Hood','Richard haggard',28,2008,'cartoon',28);
/*SELECT * FROM books +------+---------------+-----------------+-------+---------+----------+------+ | id | name | authors | price | pubdate | note | num | +------+---------------+-----------------+-------+---------+----------+------+ | 1 | Tal of AAA | Dickes | 23 | 1995 | novel | 11 | | 2 | EmmaT | Jane lura | 35 | 1993 | joke | 22 | | 3 | Story of Jane | Jane Tim | 40 | 2001 | novel | 0 | | 4 | Lovey Day | George Byron | 20 | 2005 | novel | 30 | | 5 | Old land | Honore Blade | 30 | 2010 | Law | 0 | | 6 | The Battle | Upton Sara | 30 | 1999 | medicine | 40 | | 7 | Rose Hood | Richard haggard | 28 | 2008 | cartoon | 28 | +------+---------------+-----------------+-------+---------+----------+------+ */ # 4、将小说类型(novel)的书的价格都增加5。 UPDATE books SET price = price + 5 WHERE note = 'novel'; /* +------+---------------+-----------------+-------+---------+----------+------+ | id | name | authors | price | pubdate | note | num | +------+---------------+-----------------+-------+---------+----------+------+ | 1 | Tal of AAA | Dickes | 28 | 1995 | novel | 11 | | 2 | EmmaT | Jane lura | 35 | 1993 | joke | 22 | | 3 | Story of Jane | Jane Tim | 45 | 2001 | novel | 0 | | 4 | Lovey Day | George Byron | 25 | 2005 | novel | 30 | | 5 | Old land | Honore Blade | 30 | 2010 | Law | 0 | | 6 | The Battle | Upton Sara | 30 | 1999 | medicine | 40 | | 7 | Rose Hood | Richard haggard | 28 | 2008 | cartoon | 28 | +------+---------------+-----------------+-------+---------+----------+------+ */
# 5、将名称为EmmaT的书的价格改为40,并将说明改为drama。 UPDATE books SET price = 40,note = 'drama' WHERE NAME = 'EmmaT';
# 6、删除库存为0的记录。 DELETE FROM books WHERE num = 0;
# 7、统计书名中包含a字母的书 SELECT NAME FROM books WHERE NAME LIKE '%a%'; /* +------------+ | NAME | +------------+ | Tal of AAA | | EmmaT | | Lovey Day | | The Battle | +------------+ */
# 8、统计书名中包含a字母的书的数量和库存总量 SELECT COUNT(*),SUM(num) FROM books WHERE NAME LIKE '%a%';
# 9、找出“novel”类型的书,按照价格降序排列
SELECT NAME,note,price FROM books WHERE note = 'novel' ORDER BY price DESC;
# 10、查询图书信息,按照库存量降序排列,如果库存量相同的按照note升序排列 SELECT * FROM books ORDER BY num DESC,note ASC;
# 11、按照note分类统计书的数量 SELECT note,COUNT(*) FROM books GROUP BY note;
# 12、按照note分类统计书的库存量,显示库存量超过30本的 SELECT note,SUM(num) FROM books GROUP BY note HAVING SUM(num) > 30;
# 13、查询所有图书,每页显示5本,显示第二页 SELECT * FROM books LIMIT 5,5;
# 14、按照note分类统计书的库存量,显示库存量最多的 SELECT note,SUM(num) sum_num FROM books GROUP BY note ORDER BY sum_num DESC LIMIT 0,1;
# 15、查询书名达到10个字符的书,不包括里面的空格 SELECT CHAR_LENGTH(REPLACE(NAME,' ','')) FROM books;
SELECT NAME FROM books WHERE CHAR_LENGTH(REPLACE(NAME,' ','')) >= 10;
# 16、查询书名和类型,其中note值为novel显示小说,law显示法律,medicine显示医药, #cartoon显示卡通,joke显示笑话 SELECT NAME "书名",note,CASE note WHEN 'novel' THEN '小说' WHEN 'law' THEN '法律' WHEN 'medicine' THEN '医药' WHEN 'cartoon' THEN '卡通' WHEN 'joke' THEN '笑话' ELSE '其他' END "类型" FROM books; /* +------------+----------+--------+ | 书名 | note | 类型 | +------------+----------+--------+ | Tal of AAA | novel | 小说 | | EmmaT | drama | 其他 | | Lovey Day | novel | 小说 | | The Battle | medicine | 医药 | | Rose Hood | cartoon | 卡通 | +------------+----------+--------+ */
# 17、查询书名、库存,其中num值超过30本的,显示滞销,大于0并低于10的, #显示畅销,为0的显示需要无货 SELECT NAME AS "书名",num AS "库存", CASE WHEN num > 30 THEN '滞销' WHEN num > 0 AND num < 10 THEN '畅销' WHEN num = 0 THEN '无货' ELSE '正常' END "显示状态" FROM books; /* +------------+--------+--------------+ | 书名 | 库存 | 显示状态 | +------------+--------+--------------+ | Tal of AAA | 11 | 正常 | | EmmaT | 22 | 正常 | | Lovey Day | 30 | 正常 | | The Battle | 40 | 滞销 | | Rose Hood | 28 | 正常 | +------------+--------+--------------+*/
# 18、统计每一种note的库存量,并合计总量 SELECT IFNULL(note,'合计库存总量') AS note,SUM(num) FROM books GROUP BY note WITH ROLLUP; /* +--------------------+----------+ | note | SUM(num) | +--------------------+----------+ | cartoon | 28 | | drama | 22 | | medicine | 40 | | novel | 41 | | 合计库存总量 | 131 | +--------------------+----------+ */
# 19、统计每一种note的数量,并合计总量 SELECT IFNULL(note,'合计总量') AS note,COUNT(*) FROM books GROUP BY note WITH ROLLUP; /* +--------------+----------+ | note | COUNT(*) | +--------------+----------+ | cartoon | 1 | | drama | 1 | | medicine | 1 | | novel | 2 | | 合计总量 | 5 | +--------------+----------+ */
# 20、统计库存量前三名的图书 SELECT * FROM books ORDER BY num DESC LIMIT 0,3;
# 21、找出最早出版的一本书 SELECT * FROM books ORDER BY pubdate ASC LIMIT 0,1;
# 22、找出novel中价格最高的一本书 SELECT * FROM books WHERE note = 'novel' ORDER BY price DESC LIMIT 0,1;
# 23、找出书名中字数最多的一本书,不含空格 SELECT * FROM books ORDER BY CHAR_LENGTH(REPLACE(NAME,' ','')) DESC LIMIT 0,1;
|