summaryrefslogtreecommitdiff
path: root/mysql-test/t/view_grant.test
blob: 39444a97984ddb33c84fadda05749e17d9165bcf (plain)
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
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
641
642
643
644
645
646
647
648
649
650
651
652
653
654
655
656
657
658
659
660
661
662
663
664
665
666
667
668
669
670
671
672
673
674
675
676
677
678
679
680
681
682
683
684
685
686
687
688
689
690
691
692
693
694
695
696
697
698
699
700
701
702
703
704
705
706
707
708
709
710
711
712
713
714
715
716
717
718
719
720
721
722
723
724
725
726
727
728
729
730
731
732
733
734
735
736
737
738
739
740
741
742
743
744
745
746
747
748
749
750
751
752
753
754
755
756
757
758
759
760
761
762
763
764
765
766
767
768
769
770
771
772
773
774
775
776
777
778
779
780
781
782
783
784
785
786
787
788
789
790
791
792
793
794
795
796
797
798
799
800
801
802
803
804
805
806
807
808
809
810
811
812
813
814
815
816
817
818
819
820
821
822
823
824
825
826
827
828
829
830
831
832
833
834
835
836
837
838
839
840
841
842
843
844
845
846
847
848
849
850
851
852
853
854
855
856
857
858
859
860
861
862
863
864
865
866
867
868
869
870
871
872
873
874
875
876
877
878
879
880
881
882
883
884
885
886
887
888
889
890
891
892
893
894
895
896
897
898
899
900
901
902
903
904
905
906
907
908
909
910
911
912
913
914
915
916
917
918
919
920
921
922
923
924
925
926
927
928
929
930
931
932
933
934
935
936
# Can't test with embedded server
-- source include/not_embedded.inc

--disable_warnings
drop database if exists mysqltest;
drop view if exists v1,v2,v3;
--enable_warnings


# simple test of grants
grant create view on test.* to test@localhost;
show grants for test@localhost;
revoke create view on test.* from test@localhost;
show grants for test@localhost;
# The grant above creates a new user test@localhost, delete it
drop user test@localhost;

# grant create view test
#
connect (root,localhost,root,,test);
connection root;
--disable_warnings
create database mysqltest;
--enable_warnings

create table mysqltest.t1 (a int, b int);
create table mysqltest.t2 (a int, b int);

grant select on mysqltest.t1 to mysqltest_1@localhost;
grant create view,select on test.* to mysqltest_1@localhost;

connect (user1,localhost,mysqltest_1,,test);
connection user1;

-- error ER_SPECIFIC_ACCESS_DENIED_ERROR
create definer=root@localhost view v1 as select * from mysqltest.t1;
create view v1 as select * from mysqltest.t1;
# try to modify view without DROP privilege on it
-- error 1142
alter view v1 as select * from mysqltest.t1;
-- error 1142
create or replace view v1 as select * from mysqltest.t1;
# no CRETE VIEW privilege
-- error 1142
create view mysqltest.v2  as select * from mysqltest.t1;
# no SELECT privilege
-- error 1142
create view v2 as select * from mysqltest.t2;

connection root;
# check view definer information
show create view v1;

grant create view,drop,select on test.* to mysqltest_1@localhost;

connection user1;
# following 'use' command is workaround of bug #9582 and should be removed
# when that bug will be fixed
use test;
alter view v1 as select * from mysqltest.t1;
create or replace view v1 as select * from mysqltest.t1;

connection root;
revoke all privileges on mysqltest.t1 from mysqltest_1@localhost;
revoke all privileges on test.* from mysqltest_1@localhost;

drop database mysqltest;
drop view test.v1;

#
# grants per columns
#
# MERGE algorithm
--disable_warnings
create database mysqltest;
--enable_warnings

create table mysqltest.t1 (a int, b int);
create view mysqltest.v1 (c,d) as select a+1,b+1 from mysqltest.t1;
grant select (c) on mysqltest.v1 to mysqltest_1@localhost;

connection user1;
select c from mysqltest.v1;
# there are no privileges on column 'd'
-- error 1143
select d from mysqltest.v1;

connection root;
revoke all privileges on mysqltest.v1 from mysqltest_1@localhost;
delete from mysql.user where user='mysqltest_1';
drop database mysqltest;

# TEMPORARY TABLE algorithm
--disable_warnings
create database mysqltest;
--enable_warnings

create table mysqltest.t1 (a int, b int);
create algorithm=temptable view mysqltest.v1 (c,d) as select a+1,b+1 from mysqltest.t1;
grant select (c) on mysqltest.v1 to mysqltest_1@localhost;

connection user1;
select c from mysqltest.v1;
# there are no privileges on column 'd'
-- error 1143
select d from mysqltest.v1;

connection root;
revoke all privileges on mysqltest.v1 from mysqltest_1@localhost;
delete from mysql.user where user='mysqltest_1';
drop database mysqltest;

#
# EXPLAIN rights
#
connection root;
--disable_warnings
create database mysqltest;
--enable_warnings
#prepare views and tables
create table mysqltest.t1 (a int, b int);
create table mysqltest.t2 (a int, b int);
create view mysqltest.v1 (c,d) as select a+1,b+1 from mysqltest.t1;
create algorithm=temptable view mysqltest.v2 (c,d) as select a+1,b+1 from mysqltest.t1;
create view mysqltest.v3 (c,d) as select a+1,b+1 from mysqltest.t2;
create algorithm=temptable view mysqltest.v4 (c,d) as select a+1,b+1 from mysqltest.t2;
grant select on mysqltest.v1 to mysqltest_1@localhost;
grant select on mysqltest.v2 to mysqltest_1@localhost;
grant select on mysqltest.v3 to mysqltest_1@localhost;
grant select on mysqltest.v4 to mysqltest_1@localhost;

connection user1;
# all selects works
select c from mysqltest.v1;
select c from mysqltest.v2;
select c from mysqltest.v3;
select c from mysqltest.v4;
# test of show coluns
show columns from mysqltest.v1;
show columns from mysqltest.v2;
# but explain/show do not
-- error 1345
explain select c from mysqltest.v1;
-- error 1142
show create view mysqltest.v1;
-- error 1345
explain select c from mysqltest.v2;
-- error 1142
show create view mysqltest.v2;
-- error 1345
explain select c from mysqltest.v3;
-- error 1142
show create view mysqltest.v3;
-- error 1345
explain select c from mysqltest.v4;
-- error 1142
show create view mysqltest.v4;

# allow to see one of underlying table
connection root;
grant select on mysqltest.t1 to mysqltest_1@localhost;
connection user1;
# EXPLAIN of view on above table works
explain select c from mysqltest.v1;
-- error 1142
show create view mysqltest.v1;
explain select c from mysqltest.v2;
-- error 1142
show create view mysqltest.v2;
# but other EXPLAINs do not
-- error 1345
explain select c from mysqltest.v3;
-- error 1142
show create view mysqltest.v3;
-- error 1345
explain select c from mysqltest.v4;
-- error 1142
show create view mysqltest.v4;

# allow to see any view in mysqltest database
connection root;
grant show view on mysqltest.* to mysqltest_1@localhost;
connection user1;
explain select c from mysqltest.v1;
show create view mysqltest.v1;
explain select c from mysqltest.v2;
show create view mysqltest.v2;
explain select c from mysqltest.v3;
show create view mysqltest.v3;
explain select c from mysqltest.v4;
show create view mysqltest.v4;

connection root;
revoke all privileges on mysqltest.* from mysqltest_1@localhost;
delete from mysql.user where user='mysqltest_1';
drop database mysqltest;

#
# UPDATE privileges on VIEW columns and whole VIEW
#
connection root;
--disable_warnings
create database mysqltest;
--enable_warnings

create table mysqltest.t1 (a int, b int, primary key(a));
insert into mysqltest.t1 values (10,2), (20,3), (30,4), (40,5), (50,10);
create table mysqltest.t2 (x int);
insert into mysqltest.t2 values (3), (4), (5), (6);
create view mysqltest.v1 (a,c) as select a, b+1 from mysqltest.t1;
create view mysqltest.v2 (a,c) as select a, b from mysqltest.t1;
create view mysqltest.v3 (a,c) as select a, b+1 from mysqltest.t1;

grant update (a) on mysqltest.v2 to mysqltest_1@localhost;
grant update on mysqltest.v1 to mysqltest_1@localhost;
grant select on mysqltest.* to mysqltest_1@localhost;

connection user1;
use mysqltest;
# update with rights on VIEW column
update t2,v1 set v1.a=v1.a+v1.c where t2.x=v1.c;
select * from t1;
update v1 set a=a+c;
select * from t1;
# update with rights on whole VIEW
update t2,v2 set v2.a=v2.a+v2.c where t2.x=v2.c;
select * from t1;
update v2 set a=a+c;
select * from t1;
# no rights on column
-- error 1143
update t2,v2 set v2.c=v2.a+v2.c where t2.x=v2.c;
-- error 1143
update v2 set c=a+c;
# no rights for view
-- error 1142
update t2,v3 set v3.a=v3.a+v3.c where t2.x=v3.c;
-- error 1142
update v3 set a=a+c;

use test;
connection root;
REVOKE ALL PRIVILEGES, GRANT OPTION FROM mysqltest_1@localhost;
drop database mysqltest;

#
# DELETE privileges on VIEW
#
connection root;
--disable_warnings
create database mysqltest;
--enable_warnings

create table mysqltest.t1 (a int, b int, primary key(a));
insert into mysqltest.t1 values (1,2), (2,3), (3,4), (4,5), (5,10);
create table mysqltest.t2 (x int);
insert into mysqltest.t2 values (3), (4), (5), (6);
create view mysqltest.v1 (a,c) as select a, b+1 from mysqltest.t1;
create view mysqltest.v2 (a,c) as select a, b+1 from mysqltest.t1;

grant delete on mysqltest.v1 to mysqltest_1@localhost;
grant select on mysqltest.* to mysqltest_1@localhost;

connection user1;
use mysqltest;
# update with rights on VIEW column
delete from v1 where c < 4;
select * from t1;
delete v1 from t2,v1 where t2.x=v1.c;
select * from t1;
# no rights for view
-- error 1142
delete v2 from t2,v2 where t2.x=v2.c;
-- error 1142
delete from v2 where c < 4;

use test;
connection root;
REVOKE ALL PRIVILEGES, GRANT OPTION FROM mysqltest_1@localhost;
drop database mysqltest;

#
# insert privileges on VIEW
#
connection root;
--disable_warnings
create database mysqltest;
--enable_warnings

create table mysqltest.t1 (a int, b int, primary key(a));
insert into mysqltest.t1 values (1,2), (2,3);
create table mysqltest.t2 (x int, y int);
insert into mysqltest.t2 values (3,4);
create view mysqltest.v1 (a,c) as select a, b from mysqltest.t1;
create view mysqltest.v2 (a,c) as select a, b from mysqltest.t1;

grant insert on mysqltest.v1 to mysqltest_1@localhost;
grant select on mysqltest.* to mysqltest_1@localhost;

connection user1;
use mysqltest;
# update with rights on VIEW column
insert into v1 values (5,6);
select * from t1;
insert into v1 select x,y from t2;
select * from t1;
# no rights for view
-- error 1142
insert into v2 values (5,6);
-- error 1142
insert into v2 select x,y from t2;

use test;
connection root;
REVOKE ALL PRIVILEGES, GRANT OPTION FROM mysqltest_1@localhost;
drop database mysqltest;

#
# test of CREATE VIEW privileges if we have limited privileges
#
connection root;
--disable_warnings
create database mysqltest;
--enable_warnings

create table mysqltest.t1 (a int, b int);
create table mysqltest.t2 (a int, b int);

grant update on mysqltest.t1 to mysqltest_1@localhost;
grant update(b) on mysqltest.t2 to mysqltest_1@localhost;
grant create view,update on test.* to mysqltest_1@localhost;

connection user1;

create view v1 as select * from mysqltest.t1;
create view v2 as select b from mysqltest.t2;
# There are not rights on mysqltest.v1
-- error 1142
create view mysqltest.v1 as select * from mysqltest.t1;
# There are not any rights on mysqltest.t2.a
-- error 1143
create view v3 as select a from mysqltest.t2;

# give CREATE VIEW privileges (without any privileges for result column)
connection root;
create table mysqltest.v3 (b int);
grant create view on mysqltest.v3 to mysqltest_1@localhost;
drop table mysqltest.v3;
connection user1;
create view mysqltest.v3 as select b from mysqltest.t2;

# give UPDATE privileges
connection root;
grant create view, update on mysqltest.v3 to mysqltest_1@localhost;
drop view mysqltest.v3;
connection user1;
create view mysqltest.v3 as select b from mysqltest.t2;

# give UPDATE and INSERT privilege (to get more privileges then underlying
# table)
connection root;
grant create view, update, insert on mysqltest.v3 to mysqltest_1@localhost;
drop view mysqltest.v3;
connection user1;
-- error 1143
create view mysqltest.v3 as select b from mysqltest.t2;


# If we would get more privileges on VIEW then we have on
# underlying tables => creation prohibited
connection root;
create table mysqltest.v3 (b int);
grant select(b) on mysqltest.v3 to mysqltest_1@localhost;
drop table mysqltest.v3;
connection user1;
-- error 1143
create view mysqltest.v3 as select b from mysqltest.t2;

# Expression need select privileges
-- error 1143
create view v4 as select b+1 from mysqltest.t2;

connection root;
grant create view,update,select on test.* to mysqltest_1@localhost;
connection user1;
-- error 1143
create view v4 as select b+1 from mysqltest.t2;

connection root;
grant update,select(b) on mysqltest.t2 to mysqltest_1@localhost;
connection user1;
create view v4 as select b+1 from mysqltest.t2;

connection root;
REVOKE ALL PRIVILEGES, GRANT OPTION FROM mysqltest_1@localhost;
drop database mysqltest;
drop view v1,v2,v4;

#
# user with global DB privileges
#
connection root;
--disable_warnings
create database mysqltest;
--enable_warnings
create table mysqltest.t1 (a int);
grant all privileges on mysqltest.* to mysqltest_1@localhost;

connection user1;
use mysqltest;
create view v1 as select * from t1;
use test;

connection root;
revoke all privileges on mysqltest.* from mysqltest_1@localhost;
drop database mysqltest;

#
# view definer grants revoking
#
connection root;
--disable_warnings
create database mysqltest;
--enable_warnings

create table mysqltest.t1 (a int, b int);

grant select on mysqltest.t1 to mysqltest_1@localhost;
grant create view,select on test.* to mysqltest_1@localhost;

connection user1;

create view v1 as select * from mysqltest.t1;

connection root;
# check view definer information
show create view v1;
revoke select on mysqltest.t1 from mysqltest_1@localhost;
-- error ER_VIEW_INVALID
select * from v1;
grant select on mysqltest.t1 to mysqltest_1@localhost;
select * from v1;
REVOKE ALL PRIVILEGES, GRANT OPTION FROM mysqltest_1@localhost;
drop view v1;
drop database mysqltest;

#
# rights on execution of view underlying functiond (BUG#9505)
#
connection root;
--disable_warnings
create database mysqltest;
--enable_warnings

use mysqltest;
create table t1 (a int);
insert into t1 values (1);
create table t2 (s1 int);
--disable_warnings
drop function if exists f2;
--enable_warnings
delimiter //;
create function f2 () returns int begin declare v int; select s1 from t2
into v; return v; end//
delimiter ;//
create algorithm=TEMPTABLE view v1 as select f2() from t1;
create algorithm=MERGE view v2 as select f2() from t1;
create algorithm=TEMPTABLE SQL SECURITY INVOKER view v3 as select f2() from t1;
create algorithm=MERGE SQL SECURITY INVOKER view v4 as select f2() from t1;
create SQL SECURITY INVOKER view v5 as select * from v4;
grant select on v1 to mysqltest_1@localhost;
grant select on v2 to mysqltest_1@localhost;
grant select on v3 to mysqltest_1@localhost;
grant select on v4 to mysqltest_1@localhost;
grant select on v5 to mysqltest_1@localhost;

connection user1;
use mysqltest;
select * from v1;
select * from v2;
-- error ER_VIEW_INVALID
select * from v3;
-- error ER_VIEW_INVALID
select * from v4;
-- error ER_VIEW_INVALID
select * from v5;
use test;

connection root;
drop view v1, v2, v3, v4, v5;
drop function f2;
drop table t1, t2;
use test;
REVOKE ALL PRIVILEGES, GRANT OPTION FROM mysqltest_1@localhost;
drop database mysqltest;

#
# revertion of previous test, definer of view lost his/her rights to execute
# function
#

connection root;
--disable_warnings
create database mysqltest;
--enable_warnings

use mysqltest;
create table t1 (a int);
insert into t1 values (1);
create table t2 (s1 int);
--disable_warnings
drop function if exists f2;
--enable_warnings
delimiter //;
create function f2 () returns int begin declare v int; select s1 from t2
into v; return v; end//
delimiter ;//
grant select on t1 to mysqltest_1@localhost;
grant execute on function f2 to mysqltest_1@localhost;
grant create view on mysqltest.* to mysqltest_1@localhost;

connection user1;
use mysqltest;
create algorithm=TEMPTABLE view v1 as select f2() from t1;
create algorithm=MERGE view v2 as select f2() from t1;
create algorithm=TEMPTABLE SQL SECURITY INVOKER view v3 as select f2() from t1;
create algorithm=MERGE SQL SECURITY INVOKER view v4 as select f2() from t1;
use test;

connection root;
create view v5 as select * from v1;
revoke execute on function f2 from mysqltest_1@localhost;
-- error ER_VIEW_INVALID
select * from v1;
-- error ER_VIEW_INVALID
select * from v2;
select * from v3;
select * from v4;
-- error ER_VIEW_INVALID
select * from v5;

drop view v1, v2, v3, v4, v5;
drop function f2;
drop table t1, t2;
use test;
REVOKE ALL PRIVILEGES, GRANT OPTION FROM mysqltest_1@localhost;
drop database mysqltest;

#
# definer/invoker rights for columns
#
connection root;
--disable_warnings
create database mysqltest;
--enable_warnings

use mysqltest;
create table t1 (a int);
create table v1 (a int);
insert into t1 values (1);
grant select on t1 to mysqltest_1@localhost;
grant select on v1 to mysqltest_1@localhost;
grant create view on mysqltest.* to mysqltest_1@localhost;
drop table v1;

connection user1;
use mysqltest;
create algorithm=TEMPTABLE view v1 as select *, a as b from t1;
create algorithm=MERGE view v2 as select *, a as b from t1;
create algorithm=TEMPTABLE SQL SECURITY INVOKER view v3 as select *, a as b from t1;
create algorithm=MERGE SQL SECURITY INVOKER view v4 as select *, a as b from t1;
create view v5 as select * from v1;
use test;

connection root;
revoke select on t1 from mysqltest_1@localhost;
-- error ER_VIEW_INVALID
select * from v1;
-- error ER_VIEW_INVALID
select * from v2;
select * from v3;
select * from v4;
-- error ER_VIEW_INVALID
select * from v5;

#drop view v1, v2, v3, v4, v5;
drop table t1;
use test;
REVOKE ALL PRIVILEGES, GRANT OPTION FROM mysqltest_1@localhost;
drop database mysqltest;


connection root;
--disable_warnings
create database mysqltest;
--enable_warnings

use mysqltest;
create table t1 (a int);
insert into t1 values (1);
create algorithm=TEMPTABLE view v1 as select *, a as b from t1;
create algorithm=MERGE view v2 as select *, a as b from t1;
create algorithm=TEMPTABLE SQL SECURITY INVOKER view v3 as select *, a as b from t1;
create algorithm=MERGE SQL SECURITY INVOKER view v4 as select *, a as b from t1;
create SQL SECURITY INVOKER view v5 as select * from v4;
grant select on v1 to mysqltest_1@localhost;
grant select on v2 to mysqltest_1@localhost;
grant select on v3 to mysqltest_1@localhost;
grant select on v4 to mysqltest_1@localhost;
grant select on v5 to mysqltest_1@localhost;

connection user1;
use mysqltest;
select * from v1;
select * from v2;
-- error ER_VIEW_INVALID
select * from v3;
-- error ER_VIEW_INVALID
select * from v4;
-- error ER_VIEW_INVALID
select * from v5;
use test;

connection root;
drop view v1, v2, v3, v4, v5;
drop table t1;
use test;
REVOKE ALL PRIVILEGES, GRANT OPTION FROM mysqltest_1@localhost;
drop database mysqltest;

#
# BUG#14256: definer in view definition is not fully qualified
#
--disable_warnings
drop view if exists v1;
--enable_warnings

# Backup anonymous users and remove them. (They get in the way of
# the one we test with here otherwise.)
create table t1 as select * from mysql.user where user='';
delete from mysql.user where user='';
flush privileges;

# Create the test user
grant all on test.* to 'test14256'@'%';

connect (test14256,localhost,test14256,,test);
connection test14256;
use test;

create view v1 as select 42;
show create view v1;

select definer into @v1def1 from information_schema.views
  where table_schema = 'test' and table_name='v1';
drop view v1;

create definer=`test14256`@`%` view v1 as select 42;
show create view v1;

select definer into @v1def2 from information_schema.views
  where table_schema = 'test' and table_name='v1';
drop view v1;

select @v1def1, @v1def2, @v1def1=@v1def2;

connection root;
drop user test14256;

# Restore the anonymous users.
insert into mysql.user select * from t1;
flush privileges;

drop table t1;

#
# BUG#14726: freeing stack variable in case of an error of opening
# a view when we have locked tables with LOCK TABLES statement.
#
connection root;
--disable_warnings
create database mysqltest;
--enable_warnings

use mysqltest;
CREATE TABLE t1 (i INT);
CREATE VIEW  v1 AS SELECT * FROM t1;
SHOW CREATE VIEW v1;
GRANT SELECT, LOCK TABLES ON mysqltest.* TO mysqltest_1@localhost;

connection user1;

use mysqltest;
LOCK TABLES v1 READ;
-- error ER_TABLEACCESS_DENIED_ERROR
SHOW CREATE TABLE v1;
UNLOCK TABLES;
use test;

connection root;
use test;
drop user mysqltest_1@localhost;
drop database mysqltest;

#
# switch to default connaction
#
disconnect user1;
disconnect root;
connection default;

#
# DEFINER information check
#
create definer=some_user@`` sql security invoker view v1 as select 1;
create definer=some_user@localhost sql security invoker view v2 as select 1;
show create view v1;
show create view v2;
drop view v1;
drop view v2;

#
# Bug#18681: View privileges are broken
#
CREATE DATABASE mysqltest1;
CREATE USER readonly@localhost;
CREATE TABLE mysqltest1.t1 (x INT);
INSERT INTO mysqltest1.t1 VALUES (1), (2);
CREATE SQL SECURITY INVOKER VIEW mysqltest1.v_t1 AS SELECT * FROM mysqltest1.t1;
CREATE SQL SECURITY DEFINER VIEW mysqltest1.v_ts AS SELECT * FROM mysqltest1.t1;
CREATE SQL SECURITY DEFINER VIEW mysqltest1.v_ti AS SELECT * FROM mysqltest1.t1;
CREATE SQL SECURITY DEFINER VIEW mysqltest1.v_tu AS SELECT * FROM mysqltest1.t1;
CREATE SQL SECURITY DEFINER VIEW mysqltest1.v_tus AS SELECT * FROM mysqltest1.t1;
CREATE SQL SECURITY DEFINER VIEW mysqltest1.v_td AS SELECT * FROM mysqltest1.t1;
CREATE SQL SECURITY DEFINER VIEW mysqltest1.v_tds AS SELECT * FROM mysqltest1.t1;
GRANT SELECT, INSERT, UPDATE, DELETE ON mysqltest1.v_t1 TO readonly;
GRANT SELECT ON mysqltest1.v_ts TO readonly;
GRANT INSERT ON mysqltest1.v_ti TO readonly;
GRANT UPDATE ON mysqltest1.v_tu TO readonly;
GRANT UPDATE,SELECT ON mysqltest1.v_tus TO readonly;
GRANT DELETE ON mysqltest1.v_td TO readonly;
GRANT DELETE,SELECT ON mysqltest1.v_tds TO readonly;

CONNECT (n1,localhost,readonly,,);
CONNECTION n1;

--error 1356
SELECT * FROM mysqltest1.v_t1;
--error 1356
INSERT INTO mysqltest1.v_t1 VALUES(4);
--error 1356
DELETE FROM mysqltest1.v_t1 WHERE x = 1;
--error 1356
UPDATE mysqltest1.v_t1 SET x = 3 WHERE x = 2;
--error 1356
UPDATE mysqltest1.v_t1 SET x = 3;
--error 1356
DELETE FROM mysqltest1.v_t1;
--error 1356
SELECT 1 FROM mysqltest1.v_t1;
--error 1142
SELECT * FROM mysqltest1.t1;

SELECT * FROM mysqltest1.v_ts;
--error 1142
SELECT * FROM mysqltest1.v_ts, mysqltest1.t1 WHERE mysqltest1.t1.x = mysqltest1.v_ts.x;
--error 1142
SELECT * FROM mysqltest1.v_ti;

--error 1142
INSERT INTO mysqltest1.v_ts VALUES (100);
INSERT INTO mysqltest1.v_ti VALUES (100);

--error 1142
UPDATE mysqltest1.v_ts SET x= 200 WHERE x = 100;
--error 1142
UPDATE mysqltest1.v_ts SET x= 200;
UPDATE mysqltest1.v_tu SET x= 200 WHERE x = 100;
UPDATE mysqltest1.v_tus SET x= 200 WHERE x = 100;
UPDATE mysqltest1.v_tu SET x= 200;

--error 1142
DELETE FROM mysqltest1.v_ts WHERE x= 200;
--error 1142
DELETE FROM mysqltest1.v_ts;
--error 1143
DELETE FROM mysqltest1.v_td WHERE x= 200;
DELETE FROM mysqltest1.v_tds WHERE x= 200;
DELETE FROM mysqltest1.v_td;

CONNECTION default;
DROP VIEW mysqltest1.v_tds;
DROP VIEW mysqltest1.v_td;
DROP VIEW mysqltest1.v_tus;
DROP VIEW mysqltest1.v_tu;
DROP VIEW mysqltest1.v_ti;
DROP VIEW mysqltest1.v_ts;
DROP VIEW mysqltest1.v_t1;
DROP TABLE mysqltest1.t1;
DROP USER readonly@localhost; 
DROP DATABASE mysqltest1;

#
# BUG#14875: Bad view DEFINER makes SHOW CREATE VIEW fail
#
CREATE TABLE t1 (a INT PRIMARY KEY);
INSERT INTO t1 VALUES (1), (2), (3);
CREATE DEFINER = 'no-such-user'@localhost VIEW v AS SELECT a from t1;
#--warning 1448
SHOW CREATE VIEW v;
--error 1449
SELECT * FROM v;
DROP VIEW v;
DROP TABLE t1;
USE test;

#
# Bug#20363: Create view on just created view is now denied
#
eval CREATE USER mysqltest_db1@localhost identified by 'PWD';
eval GRANT ALL ON mysqltest_db1.* TO mysqltest_db1@localhost WITH GRANT OPTION;

# The session with the non root user is needed.
--replace_result $MASTER_MYPORT MYSQL_PORT $MASTER_MYSOCK MYSQL_SOCK
connect (session1,localhost,mysqltest_db1,PWD,test);

CREATE SCHEMA mysqltest_db1 ;
USE mysqltest_db1 ;

CREATE TABLE t1 (f1 INTEGER);

CREATE VIEW view1 AS
SELECT * FROM t1;
SHOW CREATE VIEW view1;

CREATE VIEW view2 AS
SELECT * FROM view1;
--echo # Here comes a suspicious warning
SHOW CREATE VIEW view2;
--echo # But the view view2 is usable
SELECT * FROM view2;

CREATE VIEW view3 AS
SELECT * FROM view2;

SELECT * from view3;

connection default;
DROP VIEW mysqltest_db1.view3;
DROP VIEW mysqltest_db1.view2;
DROP VIEW mysqltest_db1.view1;
DROP TABLE mysqltest_db1.t1;
DROP SCHEMA mysqltest_db1;
DROP USER mysqltest_db1@localhost;
#
# BUG#20482: failure on Create join view with sources views/tables 
#             in different schemas
#
--disable_warnings
CREATE DATABASE test1;
CREATE DATABASE test2;
--enable_warnings

CREATE TABLE test1.t0 (a VARCHAR(20));
CREATE TABLE test2.t1 (a VARCHAR(20));
CREATE VIEW  test2.t3 AS SELECT * FROM test1.t0;
CREATE OR REPLACE VIEW test.v1 AS 
  SELECT ta.a AS col1, tb.a AS col2 FROM test2.t3 ta, test2.t1 tb;

DROP VIEW test.v1;
DROP VIEW test2.t3;
DROP TABLE test2.t1, test1.t0;
DROP DATABASE test2;
DROP DATABASE test1;


#
# BUG#20570: CURRENT_USER() in a VIEW with SQL SECURITY DEFINER
# returns invoker name
#
--disable_warnings
DROP VIEW IF EXISTS v1;
DROP VIEW IF EXISTS v2;
DROP VIEW IF EXISTS v3;
DROP FUNCTION IF EXISTS f1;
DROP FUNCTION IF EXISTS f2;
DROP PROCEDURE IF EXISTS p1;
--enable_warnings

CREATE SQL SECURITY DEFINER VIEW v1 AS SELECT CURRENT_USER() AS cu;

CREATE FUNCTION f1() RETURNS VARCHAR(77) SQL SECURITY INVOKER
  RETURN CURRENT_USER();
CREATE SQL SECURITY DEFINER VIEW v2 AS SELECT f1() AS cu;

CREATE PROCEDURE p1(OUT cu VARCHAR(77)) SQL SECURITY INVOKER
  SET cu= CURRENT_USER();
delimiter |;
CREATE FUNCTION f2() RETURNS VARCHAR(77) SQL SECURITY INVOKER
BEGIN
  DECLARE cu VARCHAR(77);
  CALL p1(cu);
  RETURN cu;
END|
delimiter ;|
CREATE SQL SECURITY DEFINER VIEW v3 AS SELECT f2() AS cu;

CREATE USER mysqltest_u1@localhost;
GRANT ALL ON test.* TO mysqltest_u1@localhost;

connect (conn1, localhost, mysqltest_u1,,);

--echo
--echo The following tests should all return 1.
--echo
SELECT CURRENT_USER() = 'mysqltest_u1@localhost';
SELECT f1() = 'mysqltest_u1@localhost';
CALL p1(@cu);
SELECT @cu = 'mysqltest_u1@localhost';
SELECT f2() = 'mysqltest_u1@localhost';
SELECT cu = 'root@localhost' FROM v1;
SELECT cu = 'root@localhost' FROM v2;
SELECT cu = 'root@localhost' FROM v3;

disconnect conn1;
connection default;

DROP VIEW v3;
DROP FUNCTION f2;
DROP PROCEDURE p1;
DROP FUNCTION f1;
DROP VIEW v2;
DROP VIEW v1;
DROP USER mysqltest_u1@localhost;

# End of 5.0 tests.