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
|
mhouri > create table a (STID number, C1 number, C2 number, C3 number);
Table created.
mhouri > insert into a values (1, 20, 30, 40)
2 ;
1 row created.
mhouri > insert into a values (2, 40, 50, 60);
1 row created.
mhouri > insert into a values (3, 90, 80, 100);
1 row created.
mhouri > create table b as select *
2 from a where 1 = 0;
Table created.
mhouri > insert into b values (1, 10, 30, 40)
2 ;
1 row created.
mhouri > insert into b values (2, 40, 40, 70);
1 row created.
mhouri > insert into b values (3, 90, 90, 100);
1 row created.
mhouri > commit;
Commit complete.
mhouri > select * from a;
STID C1 C2 C3
---------- ---------- ---------- ----------
1 20 30 40
2 40 50 60
3 90 80 100
mhouri > select * from b;
STID C1 C2 C3
---------- ---------- ---------- ----------
1 10 30 40
2 40 40 70
3 90 90 100
mhouri > SELECT stid
2 ,c1
3 ,c2
4 ,c3
5 ,min(appl_1) appl_1
6 ,min(appl_2) appl_2
7 FROM
8 ( SELECT a.*,
9 1 src1,
10 to_number(NULL) src2
11 ,'table a' appl_1, null appl_2
12 FROM a
13 UNION ALL
14 SELECT b.*,
15 to_number(null) src1,
16 2 src2
17 ,'table b' appl_1, null appl_2
18 FROM b
19 )
20 GROUP BY stid , c1, c2, c3
21 HAVING count(src1) != count(src2)
22 order by stid;
STID C1 C2 C3 APPL_1 A
---------- ---------- ---------- ---------- ------- -
1 10 30 40 table b
1 20 30 40 table a
2 40 40 70 table b
2 40 50 60 table a
3 90 80 100 table a
3 90 90 100 table b
6 rows selected.
mhouri > update a set c2=90 where stid = 3;
1 row updated.
mhouri > SELECT stid
2 ,c1
3 ,c2
4 ,c3
5 ,min(appl_1) appl_1
6 ,min(appl_2) appl_2
7 FROM
8 ( SELECT a.*,
9 1 src1,
10 to_number(NULL) src2
11 ,'table a' appl_1, null appl_2
12 FROM a
13 UNION ALL
14 SELECT b.*,
15 to_number(null) src1,
16 2 src2
17 ,'table b' appl_1, null appl_2
18 FROM b
19 )
20 GROUP BY stid , c1, c2, c3
21 HAVING count(src1) != count(src2)
22 order by stid;
STID C1 C2 C3 APPL_1 A
---------- ---------- ---------- ---------- ------- -
1 10 30 40 table b
1 20 30 40 table a
2 40 40 70 table b
2 40 50 60 table a |
Partager