Credit debit

From SQLZoo

In this example you are shown how to split a single column into two separate columns and also below you are

told how to combine two tables into a single table. Here we are splitting cash amounts into credit and debit.

Table 1 shows the results without the split column and Table 2 shows what we get when the column is split into two.

Table 1
whndescriptionamount
2006-11-01Wages50
2006-11-02Company Store-10
2006-11-03Company Store-10
2006-11-04Company Store-10
2006-11-05Company Store-10
2006-11-06Company Store-10
Table 2
whndescriptioncshINcshOUT
2006-11-01Wages50
2006-11-02Company Store10
2006-11-03Company Store10
2006-11-04Company Store10
2006-11-05Company Store10
2006-11-06Company Store10
schema:scott
DROP TABLE transact
 CREATE TABLE transact(
  whn DATE,
  description VARCHAR(20),
  amount INTEGER );
INSERT INTO transact VALUES ('2006-11-01','Wages',50);
INSERT INTO transact VALUES ('2006-11-02','Company Store',-10);
INSERT INTO transact VALUES ('2006-11-03','Company Store',-10);
INSERT INTO transact VALUES ('2006-11-04','Company Store',-10);
INSERT INTO transact VALUES ('2006-11-05','Company Store',-10);
INSERT INTO transact VALUES ('2006-11-06','Company Store',-10);

To split a column into two you have to use a CASE function as shown in the example. The SUBSTRING used in the example is used to get rid of the negative sign infront of the number so that there are only positive numbers in the table.

To combine two columns into a single one you also use a CASE function to do this with this example you can use this code:

SELECT w AS dte, d AS description, 
   CASE WHEN (a>=0) 
   THEN a ELSE NULL END AS amount,
   CASE WHEN (b>=0) 
   THEN b ELSE NULL END AS amount
  FROM
  (SELECT x.whn AS w, x.description AS d, 
          x.cshIN AS a, x.cshOUT AS b
     FROM transact x
     JOIN transact y ON (x.whn>=y.whn)
     GROUP BY x.whn, x.description, x.amount) t
SELECT w AS dte, d AS description, 
   CASE WHEN (a>=0) THEN a ELSE NULL END AS cshIN,
   CASE WHEN (a<0) THEN SUBSTRING(a,2,10) ELSE NULL END AS cshOUT
  FROM
  (SELECT x.whn AS w, x.description AS d, 
          x.amount AS a
     FROM transact x
     JOIN transact y ON (x.whn>=y.whn)
     GROUP BY x.whn, x.description, x.amount) t
SELECT w AS dte, d AS description, 
   CASE WHEN (a>=0) THEN a ELSE NULL END AS cshIN,
   CASE WHEN (a<0) THEN SUBSTR(a,2,10) ELSE NULL END AS cshOUT
  FROM
  (SELECT x.whn AS w, x.description AS d, 
          x.amount AS a
     FROM transact x
     JOIN transact y ON (x.whn>=y.whn)
     GROUP BY x.whn, x.description, x.amount) t
DataWars, Data Science Practice Projects - LogoDataWars: Practice Data Science/Analysis with +100 Real Life Projects
  • Your server today is: Laa-Laa