Standard Deviation (variance) using columns in same row.

  • Is there a way to get a variance from two columns in the same row? 

    I have a row that has two numbers (current and previous) and I want to get the variance.


    DECLARE @test-2 TABLE
    (
     EmpName varchar(50),
     Deduction MONEY,
     YearMonth int
    )

    DECLARE @CurrentYearMonth INT,
      @PreviousYearMonth INT

    SELECT @CurrentYearMonth = 201805, @PreviousYearMonth = 201804

    INSERT @test-2 Values('John', 259.05, 201803)
    INSERT @test-2 Values('John', 325.50, 201804)
    INSERT @test-2 Values('John', 325.50, 201805)
    INSERT @test-2 Values('Mary', 410.10, 201804)
    INSERT @test-2 Values('Mary', 380.25, 201805)

    SELECT EmpName,
           Deduction,
           (
               SELECT Deduction
               FROM @test-2 t2
               WHERE t1.EmpName = t2.EmpName
                     AND YearMonth = @PreviousYearMonth
           ) AS PreviousDeduction
    FROM @test-2 t1
    WHERE YearMonth = @CurrentYearMonth

    I get the following result:

    data:image/png;base64,iVBORw0KGgoAAAANSUhEUgAAAOgAAAA6CAYAAAC6XxVcAAAAAXNSR0IArs4c6QAAAARnQU1BAACxjwv8YQUAAAAJcEhZcwAAHYcAAB2HAY/l8WUAAArrSURBVHhe7Z3PiyPXEce/s7nktLvgy7Inh1VPiNKXgANBui72asYEsYcO5KKbRJKDhInAB52CDoYxQTrYRrrpGAWbwWFGeDG5SRhsyKVXwaNe1qfFl8Bu/oAoVa9fSy2NWmqNRtKTVB9GTHf1U/+oV+9VvVa/6qO/f/6PIQRBMJKjIaGXD5ZXr17h4cOHeu0wER2YyR39XxAEA5EGKggGIw1UEAxmdgP16kgfHeFo6lPo6O03Qe0zjbqn1xmWpesIi4zimh7SpIMlz9b0a1zETB3obaawx/UU7UFTNQyGQ/A9pODTyOhtN6aHUm7HjDWsh0EFyaqF9EQvsybCBrNt45nQgQO3uuK5rON69rSeNhvikhJrdhtnpvXAcUlkUGzVgPbFZhtLoohut4iEXt0qiWPYvT4GevVGrPt69qielmugqocooFBIq1AiXe+grpZ1SBFsT+tQg5an2+JpOaIH7hRCYYoOoxYdj6Ey4eOtvdMMG2jUsUPydK5NcYMvm+hdw+teZ7wfdW10nbkSer0SLC4zUXbymEq/ajsdX+tppL814HXO4aaSsPQx/bqh85g6L18XdF10LmG9pHXZxdczW1dePXSN8yp7T+opuoHyQdVOgo8+SM9FstylMIJ6qFIVUMvc6HRvRVeZbPmhxsBxcTJ9BtTLVGZ50UwD3Vlh1NzjeaSg9uh4w1YS7bWH0BaSKRdXXtSxWV4CKgMlb1Vs/b0ouPwJ4PjlOTzDCV1npYYUh20TPfLkvif0S3rqZ1v+Pi7t1cPQMCFbsOjUnJY+J64bdcwyrmbqIoNsvkeOzD8T74IaQT5L0oA51zOTDs5KNi6VnsgGSme+Tc5kP+ppiTFow1dsysFpcCbh5QDqXQNZ4tRByr26dgKZBl3c9ImpHkf3LBb1Slo893jeBdo9GtdauhPh7/Xa0PawJgbo92wcI+LYHZKjhnLGP9GElURKLUXA18Dli4HSMmgMuyha/uoEQdlg32H9km4COeiYt0rYFroNBKeq6oOPOaceMuUg1PRA7RO1cuhGxrzrmQk3uiZOyE4KF8doDbRNzmQ/6mmzY9ARGZSdNnJnfb1OoYNFvVxF9yzkLecqa4K836OOPqQ0ff1rwbvyQzy1MuPYsyrsIIioh8QpHDLXC2W0Mzr0pUig2KV9typI9quwLB3VzWJP6un2GyjF/YEHUyGNfTxz0JwoVmA3m2NPCQoxLL+kd9EPyefAlU896nkwqAiPAdYBjUE4dLErFM5EHVsZZIlCeF+udMALekw00s1Ad05B+dF+9Lht1l2YWfuO0O9GmVsPCZADobCS3KdzOnmuUdcTpSvuyFk31MEXGy3UVAirN4XZo3paYgxKA+mRx5sDKa2f88tbbQeDyN9myIvWAj/Jy1SJOgzJtV0tXwT1qK1L/qJ/jrn+eHx0W4T1QAOwPo0r/EuKOjbLa3BPfDmJdTTA1+jqUCuNs3MlJKb2w4O8yxaKmWNVyVYw9lf4+0bVLztfv5tkfj1wiMfW71xzn1HXE6UrltvaTiy0HdJTsMs9rafbfViee6cc0DLlJ4GYyIPiogNT2dIYVBCEOMh0M0K8h+jAVMSDCoLBSAMVBIM5os/w9evXuH//Pg75vyCYyNGP//nvwY9BH7x1V/2Afci8efMG9+7d02uCKdxh4zx0xIMKpnKHPKhePFw4zBUEExEPShjpQT2P/w4b0UFMD/ryU7z/5FP8oFevsWi74cTxoJ2IOXxjOc9XDayJn9P0ZcF3RptGRJdR+7RyyFm0z7nTrzaL6GDziAclFnrQTgEnruNPuVLzAPVzlyyHlg8HcNpWyHDDMyiiZtjMKOPVUVXH6qLL+3SrMwx7C4gOtoKMQYmFHjTTwDB4vjgRTATW8kbw3DHP2kjB5Q0TU50iiCoz6IdmPiRwbPfQXym/yC0hOtgKy3tQCmfLT+6qnyYePCnin1oMfI9nHzz25W89RvlrEqnQt4jmtNwwlhqDqsnJNo596wnBE5J7sIMNvTZyQTqNqO5/RhnvykUqOTZZK6kN3iREBxtjSQ/6As0/fAj8+V/g732TfY7ff/DM3/TtcwxOGkr+499+iX9/rMekUXKDiHsXV+XDsUqcFgDTk4e8eg4lNYteC1IOKpxmY3AJeyLsCxGnjGGIDjbLch705Vf4Eh/hT48fqdW333uKd/qe3+B+/XQkx6Of+/+ZKLlBxPWgiWJ3xjjLN9ocz/kbhYB+djeV2SKRQTkI+8LEKWMgooPNEu1Bd/zO7DIs9ztoaJxFsGHyhNzbmgObOLbRCw24Bv1QyGgMooNNEe1Bf5bAL779As9e0vKL7/Gdkr2H3+JDfPL1C17DD199ge+SCbyt1naXRR5UhXXkLrQ5jsdZXh05zjI3ZZgT5T3ORHc9m0BkGU5eNUqc5eHKTSE0HNsaooPtMGcM+i7OaMz45Tt38eB3z/GXz/5IDfER8p99BHz8K3XT5zfnT/HNX9/V5XeXRR40UWzhElWdUiOHvuOn0+iQRfXQxImSj290TJTn1Bi1IDUH/+7n/zwRWUanJbWO0khzWg+7EvHzxGYRHWwHNZslupEeBj/9yf/Me1Ccn6Ihn5TYkGEa+bD8hnVgIjKbheBoQGazyGwWE5EniQgjn8UVBGLJ30H3k+Xu4grC5hAPSogHFUzliIxzyB6EjfTQ/wuCaUjaTUJukIgOTEWy+gmCwUgDFQSDkQa6TiRlx2o6EP0taKD8MiR+DKsQngPkoc7z99b5mj8DiUr34dWDV/eTPDTnMU7KjpunCtkunUL4fDVkK8EjfAGx05as8t09Z7EHTaUm33qsJuvq5UMhKt2HelCc33Su5aWc35hIvjBlx8qpQrYEX1tTLyt0h22VMCmOk7Zkle8eBjFCXAeOHXqtPL/QNJ9f4g3Ye0BUug+GU3bwhkQG2bxOzREnZccqqUK2BjWoXBt2Plz7Cf+t18NL6lZCxEpbssp3D4NYY9DTrI22bqGdcxdONvRuffIEfojnh2PKC1APmE4XUAhCuFCIwuHRTkcs4XQf6k3KuvPyOjh388hmuI0tm7LjBqlCtkHnTM0sKYeqP4pV0pZIypMx8W4SWVQj7QsyIzZCB6fh7p08QTcIxwYO3Koem/ZcJLMtktWQap7r8QV9v+kb8S6i5i9OpPvgNylTE82lkc5VKdZtXEsDEocbpQrZODQ2Vpe4o5W3o8RroMpT9DHonMMdhR4a8paFtPaUZLyj4SkZ2SnnsuC5ffkmztnI6PvNfPZGRmwC19J9cKSg3ihOY6VuC8nq8jd0uNEvnSpkC3j1Klzneh4iYb3Ea6BkOqeOi2rVhT3h/qhXtdpIVshTKg9K3lJvCZPJ5tGkFsrhcW3kJnaV8XjRu2hzCgDdYbGcAw0vdsoObpy3mSpkffgheK9kqY7YKvnL88LvVdKWSMqTMTEbKCmNrY/GXtfDU5tCYF953gUN7tXSFJks8u6JuhM6lfViJ5hIzREaLypDUqH/pDxWyg7yvjdNFbJ5gps5/mdQSyFVG6A77/byKmlLJOXJiNgNVIVew+kxFoVgNfIaln9DI9d2tXyaDLLUjlMjb7NbRKX74PH3pUrNwXJOzXHpyyNTdozTfSyfKmTHiKGDSCK/e3hs6GF5qpT0ObLdm91EWTdre1Ccn4ShLmkXUnYYqYMd0t+6WH8D7RRwdNJcHBJtEZnJITowFZluRohxig5MJf4YVBCEjSMNVBAMRqU80cuCIBgF8H/tiVn8DsSEXwAAAABJRU5ErkJggg==

    I would like to have a column next to the PreviousDeduction that has the variance.

    Thanks,

    Tom

  • Yes, do an "UNPIVOT" first.  I'm using CROSS APPLY to do the "UNPIVOT".

    SELECT EmpName,
    Deduction,
    (
    SELECT Deduction
    FROM @test-2 t2
    WHERE t1.EmpName = t2.EmpName
    AND YearMonth = @PreviousYearMonth
    ) AS PreviousDeduction
    FROM @test-2 t1
    CROSS APPLY ( VALUES(t1.Deduction), (Previous_Deduction.Deduction)) d(Deduction)
    WHERE YearMonth = @CurrentYearMonth

    If your on a newer version of SQL Server, you can also improve this by using a windowed function.
    SELECT EmpName,
           Deduction,
        LAG(Deduction) OVER(PARTITION BY EmpName ORDER BY YearMonth) AS PreviousDeduction,
        VAR(Deduction) OVER(PARTITION BY EmpName ORDER YearMonth ROWS BETWEEN 1 PRECEDING AND CURRENT ROW) AS Variance
    FROM @test-2 t1
    WHERE YearMonth = @CurrentYearMonth

    Drew

    J. Drew Allen
    Business Intelligence Analyst
    Philadelphia, PA

  • tshad - Tuesday, July 31, 2018 2:47 PM

    Is there a way to get a variance from two columns in the same row? 

    I have a row that has two numbers (current and previous) and I want to get the variance.


    DECLARE @test-2 TABLE
    (
     EmpName varchar(50),
     Deduction MONEY,
     YearMonth int
    )

    DECLARE @CurrentYearMonth INT,
      @PreviousYearMonth INT

    SELECT @CurrentYearMonth = 201805, @PreviousYearMonth = 201804

    INSERT @test-2 Values('John', 259.05, 201803)
    INSERT @test-2 Values('John', 325.50, 201804)
    INSERT @test-2 Values('John', 325.50, 201805)
    INSERT @test-2 Values('Mary', 410.10, 201804)
    INSERT @test-2 Values('Mary', 380.25, 201805)

    SELECT EmpName,
           Deduction,
           (
               SELECT Deduction
               FROM @test-2 t2
               WHERE t1.EmpName = t2.EmpName
                     AND YearMonth = @PreviousYearMonth
           ) AS PreviousDeduction
    FROM @test-2 t1
    WHERE YearMonth = @CurrentYearMonth

    I get the following result:

    data:image/png;base64,iVBORw0KGgoAAAANSUhEUgAAAOgAAAA6CAYAAAC6XxVcAAAAAXNSR0IArs4c6QAAAARnQU1BAACxjwv8YQUAAAAJcEhZcwAAHYcAAB2HAY/l8WUAAArrSURBVHhe7Z3PiyPXEce/s7nktLvgy7Inh1VPiNKXgANBui72asYEsYcO5KKbRJKDhInAB52CDoYxQTrYRrrpGAWbwWFGeDG5SRhsyKVXwaNe1qfFl8Bu/oAoVa9fSy2NWmqNRtKTVB9GTHf1U/+oV+9VvVa/6qO/f/6PIQRBMJKjIaGXD5ZXr17h4cOHeu0wER2YyR39XxAEA5EGKggGIw1UEAxmdgP16kgfHeFo6lPo6O03Qe0zjbqn1xmWpesIi4zimh7SpIMlz9b0a1zETB3obaawx/UU7UFTNQyGQ/A9pODTyOhtN6aHUm7HjDWsh0EFyaqF9EQvsybCBrNt45nQgQO3uuK5rON69rSeNhvikhJrdhtnpvXAcUlkUGzVgPbFZhtLoohut4iEXt0qiWPYvT4GevVGrPt69qielmugqocooFBIq1AiXe+grpZ1SBFsT+tQg5an2+JpOaIH7hRCYYoOoxYdj6Ey4eOtvdMMG2jUsUPydK5NcYMvm+hdw+teZ7wfdW10nbkSer0SLC4zUXbymEq/ajsdX+tppL814HXO4aaSsPQx/bqh85g6L18XdF10LmG9pHXZxdczW1dePXSN8yp7T+opuoHyQdVOgo8+SM9FstylMIJ6qFIVUMvc6HRvRVeZbPmhxsBxcTJ9BtTLVGZ50UwD3Vlh1NzjeaSg9uh4w1YS7bWH0BaSKRdXXtSxWV4CKgMlb1Vs/b0ouPwJ4PjlOTzDCV1npYYUh20TPfLkvif0S3rqZ1v+Pi7t1cPQMCFbsOjUnJY+J64bdcwyrmbqIoNsvkeOzD8T74IaQT5L0oA51zOTDs5KNi6VnsgGSme+Tc5kP+ppiTFow1dsysFpcCbh5QDqXQNZ4tRByr26dgKZBl3c9ImpHkf3LBb1Slo893jeBdo9GtdauhPh7/Xa0PawJgbo92wcI+LYHZKjhnLGP9GElURKLUXA18Dli4HSMmgMuyha/uoEQdlg32H9km4COeiYt0rYFroNBKeq6oOPOaceMuUg1PRA7RO1cuhGxrzrmQk3uiZOyE4KF8doDbRNzmQ/6mmzY9ARGZSdNnJnfb1OoYNFvVxF9yzkLecqa4K836OOPqQ0ff1rwbvyQzy1MuPYsyrsIIioh8QpHDLXC2W0Mzr0pUig2KV9typI9quwLB3VzWJP6un2GyjF/YEHUyGNfTxz0JwoVmA3m2NPCQoxLL+kd9EPyefAlU896nkwqAiPAdYBjUE4dLErFM5EHVsZZIlCeF+udMALekw00s1Ad05B+dF+9Lht1l2YWfuO0O9GmVsPCZADobCS3KdzOnmuUdcTpSvuyFk31MEXGy3UVAirN4XZo3paYgxKA+mRx5sDKa2f88tbbQeDyN9myIvWAj/Jy1SJOgzJtV0tXwT1qK1L/qJ/jrn+eHx0W4T1QAOwPo0r/EuKOjbLa3BPfDmJdTTA1+jqUCuNs3MlJKb2w4O8yxaKmWNVyVYw9lf4+0bVLztfv5tkfj1wiMfW71xzn1HXE6UrltvaTiy0HdJTsMs9rafbfViee6cc0DLlJ4GYyIPiogNT2dIYVBCEOMh0M0K8h+jAVMSDCoLBSAMVBIM5os/w9evXuH//Pg75vyCYyNGP//nvwY9BH7x1V/2Afci8efMG9+7d02uCKdxh4zx0xIMKpnKHPKhePFw4zBUEExEPShjpQT2P/w4b0UFMD/ryU7z/5FP8oFevsWi74cTxoJ2IOXxjOc9XDayJn9P0ZcF3RptGRJdR+7RyyFm0z7nTrzaL6GDziAclFnrQTgEnruNPuVLzAPVzlyyHlg8HcNpWyHDDMyiiZtjMKOPVUVXH6qLL+3SrMwx7C4gOtoKMQYmFHjTTwDB4vjgRTATW8kbw3DHP2kjB5Q0TU50iiCoz6IdmPiRwbPfQXym/yC0hOtgKy3tQCmfLT+6qnyYePCnin1oMfI9nHzz25W89RvlrEqnQt4jmtNwwlhqDqsnJNo596wnBE5J7sIMNvTZyQTqNqO5/RhnvykUqOTZZK6kN3iREBxtjSQ/6As0/fAj8+V/g732TfY7ff/DM3/TtcwxOGkr+499+iX9/rMekUXKDiHsXV+XDsUqcFgDTk4e8eg4lNYteC1IOKpxmY3AJeyLsCxGnjGGIDjbLch705Vf4Eh/hT48fqdW333uKd/qe3+B+/XQkx6Of+/+ZKLlBxPWgiWJ3xjjLN9ocz/kbhYB+djeV2SKRQTkI+8LEKWMgooPNEu1Bd/zO7DIs9ztoaJxFsGHyhNzbmgObOLbRCw24Bv1QyGgMooNNEe1Bf5bAL779As9e0vKL7/Gdkr2H3+JDfPL1C17DD199ge+SCbyt1naXRR5UhXXkLrQ5jsdZXh05zjI3ZZgT5T3ORHc9m0BkGU5eNUqc5eHKTSE0HNsaooPtMGcM+i7OaMz45Tt38eB3z/GXz/5IDfER8p99BHz8K3XT5zfnT/HNX9/V5XeXRR40UWzhElWdUiOHvuOn0+iQRfXQxImSj290TJTn1Bi1IDUH/+7n/zwRWUanJbWO0khzWg+7EvHzxGYRHWwHNZslupEeBj/9yf/Me1Ccn6Ihn5TYkGEa+bD8hnVgIjKbheBoQGazyGwWE5EniQgjn8UVBGLJ30H3k+Xu4grC5hAPSogHFUzliIxzyB6EjfTQ/wuCaUjaTUJukIgOTEWy+gmCwUgDFQSDkQa6TiRlx2o6EP0taKD8MiR+DKsQngPkoc7z99b5mj8DiUr34dWDV/eTPDTnMU7KjpunCtkunUL4fDVkK8EjfAGx05as8t09Z7EHTaUm33qsJuvq5UMhKt2HelCc33Su5aWc35hIvjBlx8qpQrYEX1tTLyt0h22VMCmOk7Zkle8eBjFCXAeOHXqtPL/QNJ9f4g3Ye0BUug+GU3bwhkQG2bxOzREnZccqqUK2BjWoXBt2Plz7Cf+t18NL6lZCxEpbssp3D4NYY9DTrI22bqGdcxdONvRuffIEfojnh2PKC1APmE4XUAhCuFCIwuHRTkcs4XQf6k3KuvPyOjh388hmuI0tm7LjBqlCtkHnTM0sKYeqP4pV0pZIypMx8W4SWVQj7QsyIzZCB6fh7p08QTcIxwYO3Koem/ZcJLMtktWQap7r8QV9v+kb8S6i5i9OpPvgNylTE82lkc5VKdZtXEsDEocbpQrZODQ2Vpe4o5W3o8RroMpT9DHonMMdhR4a8paFtPaUZLyj4SkZ2SnnsuC5ffkmztnI6PvNfPZGRmwC19J9cKSg3ihOY6VuC8nq8jd0uNEvnSpkC3j1Klzneh4iYb3Ea6BkOqeOi2rVhT3h/qhXtdpIVshTKg9K3lJvCZPJ5tGkFsrhcW3kJnaV8XjRu2hzCgDdYbGcAw0vdsoObpy3mSpkffgheK9kqY7YKvnL88LvVdKWSMqTMTEbKCmNrY/GXtfDU5tCYF953gUN7tXSFJks8u6JuhM6lfViJ5hIzREaLypDUqH/pDxWyg7yvjdNFbJ5gps5/mdQSyFVG6A77/byKmlLJOXJiNgNVIVew+kxFoVgNfIaln9DI9d2tXyaDLLUjlMjb7NbRKX74PH3pUrNwXJOzXHpyyNTdozTfSyfKmTHiKGDSCK/e3hs6GF5qpT0ObLdm91EWTdre1Ccn4ShLmkXUnYYqYMd0t+6WH8D7RRwdNJcHBJtEZnJITowFZluRohxig5MJf4YVBCEjSMNVBAMRqU80cuCIBgF8H/tiVn8DsSEXwAAAABJRU5ErkJggg==

    I would like to have a column next to the PreviousDeduction that has the variance.

    Thanks,

    Tom

    Can you kindly post the desired results?

    Saravanan

  • Something like:

    data:image/png;base64,iVBORw0KGgoAAAANSUhEUgAAATcAAAA1CAYAAAAknayNAAAAAXNSR0IArs4c6QAAAARnQU1BAACxjwv8YQUAAAAJcEhZcwAAHYcAAB2HAY/l8WUAACnKSURBVHhe7Z0FWFRZG8f/M0M3AgImiIqIgaBig6KI3d2x9voZ666tGGu3q6Kua60dq66Kha1rYmEHoiISMkz3+c69M5TAAC6IuvPzmUdu3/Oe97wn7rn/y5HL5QQ6Pn78CFtbW/B4PN2a/zZqtRoCgQD29va6NQb0YfCfosHgp1lhfJFDKLplJCUlwc7OzuCcOhin4fP5cHBw0K0xoA+D/xQNBj/NCuOLXN3f2aKUClmjZfeTKtS6vQoKDQQpfMhVGt1yOkJBChTqrOu/BtRyURbbCIUSqNPrjM9CJBQUkI01UGp0ttMokULvT/Pvbu2LIKXpF8tVuqXC4b+Td9qyldM9CQWfV56/RB79G/QENw2u7JiNyl5eqFGjxie/mhizYDfkBRhv5KI3GNrcDy2HzQdflm5oDXXA2SPbY/aOq/SOvj4eHFuOKlUy2qgmGjVshWEzliEqXqLbK58oJVg+oSeGzt7xr2xMiAbn9qzDhj8vQEmXRW9voHfLljjxkK/d4WtFI8fB5RMwZOpqSJgbLyT+K3mnECdico9AtB+9FCJF5ptSpDzDoCBfTAk7QYO6bmVe+EJ59G/Q23LTqOldezbD2cvXERkZmeF3E4vGdICp3qPzC4FUkIhLu5dg8+knmQKZUiqASKrQLX1dEA0NxBUz2OjWdRzcPAPmdw9jSN9JeC2Q6fbMH2q5GAKRVLf0eRCFBId3/Y4bL5PYZavSdbDj2DE0qWTHLn+1cE3R7ZflWDt9MCyMdesKgf9K3pmY26N1sD/unjyIFx8zB+3X107iwhsLBAT4gcfRrcwLXyiP/g28mRTd35BKpTAzMwOXy0QtguhbJ3HggQLjB3WBnbUluy31Z2rKpIjg8bnDOHorBpzk5/hj2y48eJEMD8/SeH37LDZs2YWbD+lyZQ9YGnO1+0a+BVccg01/bGe3uXm6w9rUCGoFH39t3gTXSt44ffIKgtu2gaOVCYhagZMHNgMewWju5w6OSobo+7ewfc8+HA8/gduP4uHsVg72lsbQqBKwfcU6yM3scOH4bhz8+xLgUBIO4OPA7u04cOQSZOauKFfSDkw+qmQS3LgUgS3bduLmrYewdCqD4sWs2G0MzHCkTCaDhYWFbk1W4h6dx45bAowboLORuTnsXNzQILAmDqydDrF7MOpVcmHPGR8Xjd1bt+PwsXDEpwBu7qVhYqStIWTieJwJ342de48gVszF+wcXkGBRFV2Ca+Deqb0Iv5+AyhXdwOyuSniMFWv3orhnFRSjnqWQpOBixC5s23kID1+mwN3LAxbUU8/99Qc27zqM2CQpjG0d4eXKw45NW2HlVh3FbUxo+kW4cSYcW3buYdNv4+wGJ3tLcGir4fZJes3IN1DEvcCWP6l9Hr6Eq7sX7CyM2PvNDpFQiD83HIZC8x47tu/GW44DPEsVR9KHrOk25mrw9/aVeCZzRPlSxVj7EJUUf21bjQSTMki+expnn6To0qxB/Oun2L19Bw4fP8Gew70cPQePC7UoBhtXr4dZGW2aaMTCucPbcCVaiUrlSoBDW1LXL2rz+NytW4ClM0o727O1+veTd1Hw9KwAGxtr9n6ywOHB0cUWO8I2wLxaK9T30qaJRlDsWrMIj639MGtYR5gReY5li7Hz778doq3ROF3e2kP6+DIuPNXlkSbncpmaRypTO5w+uAeHaB6mwB4eZZx1AVWDuOg72Lp9E46fuAnYu6KMs7aMMuizfU4wsUz/HrmiQtT5vzB9/CjMXLmHtq4ECJs9Ep2798HkZXsgpst7lg/HT0v3QqbW7jvzl5EYPX4uPoiluLhzFrp2+zm9hjQyRYtBk+CFR5hHC0mG3qkOgmu7l6Fdz3F4+Poj9WMJLmyfic5d/4cYgRwy0Tv8seBXDB8/Cf88eo/Y+3+jd/fOGDhiLLv88eVR/NC3O268FtCgKcOWeWMwaOp8JMoUiH92CX06d8WhyNe6a/07rJ08EOJfEedOnAUzLPHh/jn07tAWf918CLVGjH2LJ6D7z6sgoIkkihQsndwDExf/BYlMiUOrZ2H32efaE2mUuBm+A1sPn6fHaVeJ3kVh0dL1iBHSY1Vi/DapB0bM3IAk2ro9uHkWhs74A2KZHBwOh/o1j7qOCjQOQJn8AmsXL8PjBBV73PoZAzBw4hIkShSIuX8K3bv1wOHIGGpm7TWn/TgE88K2QaoQ4MCGmej+v4VIyZopaUhFIqyeOx3jFixArEgCZYoSiVHZp1solSH21hks+m0PJLquUlzkEUyZuQ0ynnGmNMfc/As9OnXEX1cfQ60WY8OcH9Fv2gbWdtLE9DSx0MrvPA0Me07choYGupO/h2LQuHlsGsUxzzC8Yw8cyCWPv7W847++Aa5Gf8/GpoQvejetgH1/7oNQl4dKGpSvXL2OpkEhYOoFfWWLsfPqOdPS85a2AO+cTE2b/nLJHPvb3DkYMWocbr14jY+xtzGsd1fsvqHNh+hrB9CpdXscux0DQeJ9DOjbF2cff2C36bN9rjBPS1NJTEwkKpVKt6QmEWFjiFP5GmTqtOmENvDSfqGzZpMHb4V0HwXZN7M/KV65HXkQL6CHyMjvY9oTh0rNya03Kez2Q7/2IxVChhG+RMLua1+mFjnz8AM9OyH8mEgSVKU0WXDoLpEIX5FOviVJWMRLEnVyDalYuirZdSuanlJIxnTyJWPCIohSISEn92wkB07fJQq1miiVMhJ1fBVxcfEh514LiTg5kjQs5kD+t/IY3U6I4N1F4mNvR4Yt2s8uiz/eJ0HlS5Bl4U9I7PXdpFr1+vReYth70ShEZNvM3sS/90ySItXagLEFYxN9RO6bSUoG9SfJYoVuTSoKsnd6X+LTfgwRiIVk7uBmpOeUVSRFrqTbNCTp6VXSwNeb/PlPNHl+ag0p7UXt8kh7LX7MXdK4ggNpNyaMyBQyEjamHQnsP5OkXiI5ch9xdfUhEa+EJO7mbuJZpjrZf5Paim57c3MPqVW1Ebn8OkVru3Y+pP/MffRuCBG+iiA+rq5kX2Qym/6Mx6mkfDJ/UFMS0G8eEUol7DXd/LqTR4lMPmvI0/ClpESpQHLvo5guZ0/08+ekUjFnMmvHFXpODVHS6+tL96vz60gZz0bkznt6DY2K7JozkNToOJbwpdL0NEvFZO7AINJy2CKSLNGeIybyIKlaxpP8ded9pjSxKMRkZv9A1nYSiZCM71qb9J6xjYhVGqKWi8jBTavI4UvP6Fm+n7xT0uvk5qcML8+uISVLepPzr7S2ir2+i3h71yPnXghoB0l/2WKuX9nBIS1vVXKtjzBpE4nzcKydPZm8/gy7XSFOJENCvEm/WQeJQiUlcwfp8lempOkWkDmDW5F+07YQiYzmvR7b64OxR64tN5lKA5ky4wgY7cuamLG/VDyqesHdzor2w7mwtbNDqYqVUNGJLoMHawd7iGjXLvUBVKU6TVC7vBPbZLR2Lg9f2kS+fe0B0h+ScuDZsCcGNrHHopkrESdKr5G4xuZo3KYLSqiiMX/2FIwaPQB9Ji1HikSO1IdKRmam8PGtTrs99OoWVrAzM0c13xraZWMrWFkRpIiEuHPxAvgKFSJ2/Y7ZoaGY9etiXHuejKcXryJOXjDje4TWvlz6k0ti8M+lB+DHvMCyeXMRGjoLKzYfhEKUiItXoxB19wHtVvnBz007nmLrUh6N/L3Yv/VD8OrhHYg9aiDAqwRr01K+nXDmwiH4lbTR7pItGjy+dQ2oXAeNvUuxx/HMbNGuQzBe3L2OJLl2hLhsFU+UsWHykQMn5zK0tcvHR2FmX/gUY1MTVPL0pOfkQKV4qyfdj+FYrTmqmUbj+LWXUErjcTLiMgKbMK2I1A4JIJd+wO27TxAYEgI7c6ZLzIGrZyBqV9Tg/M2n0Fd/c2kLsG7t6ji5ZQoG/TAOyzcehVdQJ7Sq55HW5cmJbynvONychwoy4lqjJeq4KHHgxD2oiRoXTp5CiTotUausVZ7KlolJet7yMnQLOXk51twMPn4+tBxyYUz3L+HihJSPidS+fEQ9eYJagY1hZ2oErqk1Jv62FysndARHoc/2j2mbVj/pd5gDVm41MGXadMyYMSPtN+WXn1DJKd2gFvTGGadLhWlS54QZDT6McRi4HC47nqWQitOCHwNT0IbOXAKz6L1YsuMiUmMroc38rfNHoP8vc/BeoEFl33ZYMn0MbC1NtTtQGIe0tsw8RsbLcj80YIvFkCoJlKr0CzuWr4VfRvWAfYbzfTZqNV7Hx8HFtSS9vgopCRJwSHp2cE0s0LLnjwjxKQOVRAIz6jhp90m7I8XtHZG7y2ogl0thRgOKUeqx9D9CfzyOvkdf9Dh2fNUUxhlsY2puBQ3tHsl0mZFdPqY6qz60Y7Z0X7VCT7rLwtLaBa0b++DKmct4e+8CLj+3QEiwf6bAw5xDJiKwYYOsFi4tzFY0j2WCXJ5oGpmi/Y/LsGX5RLiYpuCPpdMRUDcAk8KyG/LIwDeYd3nBzNoVfTrXxdm/D4CfHItT528iMDgY5jxOnsoWQ2reZoJ83rGEpkVDu9MyCYGlVXqZ1ahV0HCNc/Wf3GZT5hrcCpqYN28hV2pvljaFEfchDu7l3WHyyZ3alamO0FHdsHv1DNx/LWDXycWvcGDPOfSbvharFs3D6MFdYSbnQ6nIb0uLR1uXpWBi6oChP01MC9qTfx6HocO7wymXwcq8IHj3EGevPUVQcDNYmBZHSQ9rlKndHlPTKolpGDtmJFo18kL5ap40E99BoNC2mIhCime0tkrNUqYyUKrSMzjhw3uoVcy+PLiWKQv5u3f4qGttST8+QN8mjbDp/At2OXu4KFnODR9fvECCVK5bR/D04VNYl3KBvXHBPP4yMtKXbk9weGZo3rElHlw4ir0HDsGiZiD8y2ZutRgZ2aN4CSvcf/gyrZWmkL7D6+gklCrtnB5IdQGZdtKQ/DGB/VujFuPAljAYl2uDpb9twJUbl7ByVENsX74Bb/Q8zfz28i6PcE0Q0K0/uFHncST8L9wWeqJTcFW2Mvk3ZUsu+vxjeUY2cHa2wquXsbr8VeP42sloNTQUErWDfv9h98+Z3EuxUpploiM72fEzp2Yk3T6FFTtOIC4hEcc3L8Kpt45oG5K5tmahkbthz/Ho5klw9UEcu4rDsYEd9f3rN6/gTdJHvLx5EgvX74ZEIYBUlu5AucOFV0BPVDOOwqR5a/EkJgHvY19g1uhu6D3xN0gztObyRAYbJScn48mdy5g0ahwE7l3Qq3kVmFo4oHevNjgSNh1/RdxG4sdkXDy+CS2btMDByDh41GmPKvIbmL56G6LjExC+PQz7Tj3VnptnhIreFfDq1glE3IvCu1cPsPXPfRDrJlGVrB6Cqrz7WLzpuM6mG/HSrBqa+JVhWwIWtFvOT4pHijhjfnFRrk5bVKfpn73sT0R/SMSL6+FYui0cTVu1gaNZwbxhYKI33bHsPi60a1pVdR2r91xEY3ZgO7MnGFvYo2vHZjj9xxyEX3mIpI+x2L5sEW5za6B1Qy8Y27rBvRgHu/ftYG134chWhJ/TBQdqog93zmBG6DI8jHkHFVEg/qMIzhXcYEdbPizfQd69eXAZatoKzAs2JWuiUyM7zF24BuXqN4K7rXZ4ifsvyhaH+/nHGplaom3LZojYshxXo6Lx9sk1bN57FkFNguFgXzxX/9GH3uBmQrspeHoajevXzjDRUfvrPGYBRDSTTC2tYWmaXhiYZWvz9JqfOYddhuZpcffyeHtkPRrVrYMZ4S8wZ91GNCxnTbdwYW1rBx433blNrFwweuZkVC3pxD72N7VywvgZoVCEr0ET/9roPiMMDQaNR6MKNnj5JpEewYONnR3NKO3xzDIzBph+Ti5sdNewcvHE6vXrYPIoHC0C66Je8/aIUtTGnPFDYG6UuYDpg0czJ6ONfP380HF0KHh+nbF9zTQ4m1ET00DdbPAszOzVAPP+1w+1avph2LxD6Dx6Mdr4lISlc0UsXrEY/Ctr0aSeP5afeIOAZoEwN2bsykPttiPxg68zJnRqjZbdQ1G8WhBKl3Rk08keu3Ix4s/NR4O6tTH3bCxCF02Dh40JuLRbFty6BR4fnIte4xZAqNTaI/W4FevWQHl7D5rWr4P2g6aiTo+JmD60Jbvd3MomU77ShMLOzjqDbbMn9fwsuaSbwYx2Tdu0DgTXojK6tKuXVsmlXZ9jjKCBM2jaa2HG0B70HA1w6L4Mm35fiarOZvT4Upg6bQpSjq1EUJ2m2HhaiGYdA1jbcY0t2a5SffOn6Nk0EH41m+NErB1WzZ4AJ1Pud5N33YdMTnvinBtMt65z905QCY3Qsk0LpNYlJrmVLdrqy5S3lNQ8MrHM/7GW1rZaG1H7Nuk/FaNbOWNk76Zo1HkoHJqPxOieDWnQzN1/9KH33VKmzysQZj+uweFSY9tYQ6OSQyRVwsZaOybCLAslCnYbu8ycQyynkd0M+0OHYE6kHc5t/xWE7sc1MYGVhYUuwhJIhSnU221oojPGXAIxPwUa6ojaoEloE1oEqVJN7UKPtzSHnB6nNrGGFXVYZl8jaztoy6X2WK5l6jm119Duq02jSi6j9y+jCeLQbqoVrS216xny8s4e0aiQIhDplrRwjIxhYW7OBuSMEKKBRCSGkp6XY2QCaybtGXZRysUQU1vyTMxhzlNRh6XB2Nqc3cbYVUy7UhrqKNbWZhCkCGFpY8s+KGFIPZaxqU2GeXnMNUUpAnoczS9rSwjp3yZp9klPP4fDhRXNQ57uhtS0eyWWq9PylSYU/E+u+SmM/zCnNbdzSDs/Q27pZtLG+IiNrU1abfvp9TOew8TEDBYW6Q+06EbIJCL2wRdTmZpAlq3t6NVhQltDFmYm7PrvJe80GsLum+d3S+m+2eelnrJFo+Cn18+cR/k7VkXTnNFGbFpFAqg1HBo0rel+6TeWm+2zg/HFL/jivDItuF3cvYQNRF87hheS80fh+o+BnDD4aVYYX/yCEYaLSgFtMbxnCG1FZWifGjBgwEAhwGEmu+n+hlgsZqdm6JvK8V9Co9Gwr3FYWlrq1hjQh8F/igaDn2aF8UUOMwtft8wKvDHdimznsvwHYZwmJSXFIAKYRwz+UzQY/DQrBrHKXDCMZeQPg/8UDQY/zcoXHnMzYMCAgS/HF225iWJuY/3uu+g2vCdKWul5xYkwkjv7cFdSHD3bBmaaVvAlKcwakZG6uXLxIC5efw0rRx907xICV0edTRhZp6i7+Pv8aSQlq+Hj3wwhzepQO2jHsgTRNxC2Mzx9bhOHi4BOAxHonXXuD6NZdmLvelx7HK9bA/BKVsOYPm3TpsMUFEXdcvsebZoXvoqWG7Vv5KXzOHbxOsytnNC+Z1+Uc85ZKqyw+eItt8QXN7F42VYkqHKRK9FJ7mSUivme0Erd9MT4eQdoYVLj3qlV6N5PJ/1EA/v5rfPRpucIVj5GI0nCwnE98POqQ7r3IQmuH92FnUdvIG3eJs9E+8sGpTgaG+cvw8uk9PmKZsZc9vc9YbBpEULtG7FlHjqNmImYJCmeXdyDnr3G4MnnqhkXFEzLLZXMkkcFz6uIMOLqGkgik9Nlc6RiEUlOTiYCgYioNYwQDUWdLhXDF4q120VSkrqZqBWET9ep6b2m8PnsdpmSEX8pWBhb5EVKJr8k3D9K6nrXIccexLPLosSnpFXV0mTVqSdEJU0gYzv6k3GrGNkmmiaNitzdP4+U9mxM7n0QMdpEZNHoDmTS5ousbE9u8KOOEL8mA8gb4aeyPgVPYfuPPr5Xm+aFwvLTvCLnPyWd/TzIov03CVMMZfwYMijYh4wNO0+KxhvyKHlUeDBKv6cwuEsH+Pr6okG9AEyavwmJGQTZZTGRmD2qD/x8/VCzQRusPXSbfblW9OYK2tT1x6SJMxHSqCF8fKqhU/9JeFrUNUUecajcHMcunUCwtxO7rBQJoKLdIx7PGDwzB8zdHI7QH4JZeRhGRbV0hUowFaYgSUqgVkrx7i0f9rz3WDV3NpYuW4vn75lXz7LnzbMncCrrhKu7wzAndBYOhZ+H/DtsDhtsWnQkRl3BDVFFhDT2ZtWGTW1d0aGpH/45dwLSPL4WVhgUWXCTfbiP0T8MhlnNrrh08wZ2hoXixv5FCN10Jk3i6P6tJyjVeTT++ecMRre0xdxpv+KtrpuRGPsON+JU2HL8OI7uX4P429uw8e9bOmWBrxvm1TU7Oxtw1ALsWbsAvboPBrfeEHSpV5bZCnNru/SxG6LG+ZPUSZzLoXQxE8g/PsKV8zewbe1mvGEUdG+cQpfufXH5Sfr4Txq0e3/rWiQu79+LA1cfQyERY9XUUfhx4W5IPtHo+9Yx2LToSIiLhtLBFo5p441cOLg64k18LFS5DUEVIkUW3B5d/BuRGl9MGNsbJYo5oHK9EEwd0BSnDuxBsk5xxLt5Wwxs3ghOxd3Qs3M3cJJj8V6qVRkwNrdCn0HDUaFESXhXa4LmfuUR8/T1NzVGp5RKwFXawd+/DhJunsTpm88YIYsMaPDg3A7MDzuKEePGopy1CV1jhy4TQ7Ftx04soK2MRRs2on2pFMxZuSdr4dJo4ObfBCs3b8Dva1Zg1vz5CFv9C66HzcfFlzm3TL5lDDb98jCPJDnmZkh/25fLfo8i7UllEVFEwU2DD2/ewsGtLEqapw7a8lCuclWIYuORrIv2zGx3I51OBPNit0YjhVSn7MJMFLVhdFZ0GBnxIJNLityg+cHUygWdRw/FtEVLMCSgGH5d9jtEaSqKKjw4+yeGjpyEagPmYky3uqwlrEpUxk8/jUP1stqXzI0t7dA8pD4ePLkFhfKTWpJnioB2A9G/QxAsGME8DgelqzRFReckXH+olZH63jDY9MvDTtqWSCFP+6gqgVQio7bVlt2iolCDm0b0BvvXrcHjd1rlBUK7AxwbC5jxuLCwMYNELIKK1oSpiAQCcKzMYPKdz3BnPwYslKYFYkamubJXRSTzE9nZ5kzX5/q+MPQbOQ8NRi7H0vG9YKF7H/fTY+nRUKq5sDa3SFP0yAjzwd2MH7Tm0ALONSKwMM3+SeC3isGmRUfxUuXBS0pOa5QwjZf4uGS4u7jAxDhvEuiFQaFGEYn4A5bNm4cTD5kv2Wjw+vVr8JzsYcczRsWaAeA+vY5zT96zTqWS8hEefg6e1X3hnNaa+z55d+sAGgW1xIXnSWzaFRI+zl64ikruFWBmaoT7EVsxfNxv6DzpN8wc2hlWJunZpD22C66/0X6cV5ryFoePnIWvb02YfzLHSi0TYNHodhg5n/n6GL2SRvsFsnvJZVG7cmndXt8HBpsWHXYV6sLP4hkOnXvGfthZzn+L8HO3UKseo2tXdK23Qp3Eq5YLsHRkO2yL4qJN46q4cPYEfLvOxrIxnUHotg0zBmFNBB8tWtSF8MUdnH8qxuy1f6CjrzPWj++GnfwaOLp+BvvRV/6d/ajccg7+vHIRtXADDev1wtRjD9HJxw7MV75Dh7RCpF0P7F4ypMA+Fl1YkyOVknjMGdMDR17aolm9Kkh4fB/XY2VYHbYFDdwk6N80CJckJdGjXRBt5eoO4vLQqudwVHdRY87Injj2zgYt6nrjxZ0LeCIujnV/bEbNMpbsdzFXbjmE5j1GwrukBZ5EbEOfMUvg3aQFXDhChJ88j+CRszF3eEfkQ5MzTxTlJN7v1aZ5ocgn8WqUOLNtDgYvjEDblo0gfHQeUbLK+H3nKlRx0jNZvxBhfFHPR5n/PYyaaK2gFijNkSNBYYKQXuMwomtTmFIPYLbVCGiNKiWsERufhDKV/BE6ezL8K5ZgIi779aFSFarC18uNGdaAilYJRrbOaNiwNqx4BDxzR9Ru2BCOlsy9Ml0ELsp5+aJqeVd2/4KAifu5fZT5c+AZW6JhcEu4O8gRHy+Hh18IZk6dAB/3YpALPyIhhQfPSu7sY/VUmK8TefrUQSna8q0f3AIlrOmxSXJU9O+AaZPHonIJraijhP8B/zx4BS+/+tQ2PDi6VUVQQBUkJ8YCJqXQb+wU9G9THya6mfkFSUH7T374Xm2aFwrLT/MMhwf3qvXhX7443ickoJxPE0ydOhYVixfdGwqMLxpenNeD4YXk/GHwn6LB4KdZYXzxy1exBgwYMPAFMIhV6sEgApg/DP5TNBj8NCsGscpcMIgA5g+D/xQNBj/NikGsMhcMYxn5w+A/RYPBT7NiGHMzYMDAd0uhttw0ahHCd20Dca6ABgGBsM00W5ngzbP7uHTzNkrVCEHDSi669V8PBVsjahAXfRcH/j6GhI/m8A9oi2YNyyP184wqmRi3zp/B6et3YW7liLbdu6C8q6N2I0Xw4TUO7D+C1wkf4eMfghbNaoN5+yc7JPFxuHj1GK7fewNLK2d6rl70XNrvyBam0OJX03Ijalw7vhfR3PLoGFwzy7c5n107gWeK0mje0Jv9zirLZ4kt5nCuL0x+/FSW+Axbt0YgqF9feDhovxmaRjZ2y6+/5E30U7/d1LJE7N92CvV7dMwgaqu//HxKobfclNJEbJw3CUMGDEHYsSh2NloqakkcZv3YAwOGjkFE1Pf/Tl70tQPo2q4PLj9MhFocg+mjumDV4UitiglRYfeyyRgwcTESJXI8u7gLnbr2RuRrAXusPOEBRvTqig3HbkMhSsLi8YMwd/vlNPWUjCiTHmFM9zaYtzmcfS/y2cWd9Fzd0s71XxBafH/vJEaPHIGdJ25n8jmmgMQ+OIeRI0dib8Tj9G2fJbaYw7m+Yohagk0LJ2LCrBWIEX7yziwlO7vlz1/yIvqp324qqRA7aFn4ccraTKK2estPTjAtt1QKWmxQJnxFOvm6kF7dOpKggXOJUJ4uKBl7fRep27gZ8avgRGbui9StJUQllxJaC+UgUCkiCplWvFKikJMU+r9KnVFeUMWuy7TqX1BQIoAalZSsHNuJdB23iggUjFiighxbOoRUaj2K8CVKIhU8Im28S5PlRx8QxkLS5BjSrb4HGbXqFFESDTnx2zhSs+UwEp0s0wotHpxP3H06kFfJUu0F0tCQ+0dXEq86XcmD+BR2DSMcOCCoChm08DBhzF+YQosF7T+fg0ocS37pHkhciruQdmPCiEznchpq8yuH1pDAGp7E1saB9J+5j6RaIL9ii/rOVRTkzU815M6x30hAZTdiU6waiXgl1K3XkpPd8uUvuYh+5ma35JhHZPaIDqRiWWdi4xCQJmqbW/nJDsYeX6C65qFa83bg34jAi4+66E+bvxdOnYVnnSC4WKR3VSWv72D2j0PRoEED1KjhC/8GrTF/03FWCpoRqOzQoAvGTOgLv1q18ePCTRjSthGWHrmXFv1Tnp1By4DO+OeNWLfm64DDM8PQuX9gY+gPsKY1nkatgUTJgaW5KYxoF45ouCC0qktmtOoohNZHpnQ98+MqpTh35Qb8AkNQyo420Tk8VAhshwqSW7j6TPsuZDocVG4+FFdObIS3k1YxxZR2sSqVK4Hk93H0vN+50CL1q5ObVyDKogF6BHnqVmqRpjzF+mVH0W7sIvzQqqpurZb8ii3qO9fXiuT9PSxccQydRw6F5afvJ+qxW378JTfRT/12U+Lyvk3sa1vrVsyAtVl6XMit/OTEF+mLWLlUR0MPPo5efcEGIrU4DhH/PEHjZo3S3sUjGjl2hi3BJaEbDpw4j1s3z2FODw+snBaKB4kiZgfEvb2EeKu6iLhyDqF9O6Cxb1n8vf+orn9PcO1kOGQVqsHbpehe+8gJE3NrWFuZIPrGKUwbPQzTdkRi9KiBsDDhwNyqDCb81BsnV/+ESVOnY/jAfnhhH4TBXepRh1EgLu4V7F2Kp2UWz8ge9g5qPH+bVUyRS7sAdjba8TUGUdwjGhwfwr2CO0w437fQItOtWnEsCpN+Gglb08xz7cxsKmPpnp0Y3T0oy1hRfsUW9Z3ra4Tpjm5esRDWAd3RtW4F3dp0crRbPoU5cxP91G83YzQZMhu//xaKGmWL69alo6/85MQXCW5GphYI9K+O04e1gejllUO4oSqHRt7pieBwTdFn2hrsXP4/OJorkJD4HjFSArFMBKFOw83YzAKtWnRDWacSKFnaGSE9uiDh5im2RUgUAoSfvYBGjUNgoyfBRYsGMjkPpdy84O3Aw5H9h5AgUVLnU+MFDVRiqRS0mQ5bG0eIPr6nNkhhjyL0n5mFOW2XaWFsZU7jNyvlowe5iNagob8grngwhvZsBA7d/3sVWlRL3mPFwhUI6D4Jdcun6/ylwuVyYO9kna3DM4/U8iO2qO9cXx8E905uxrEoa4wf0ZVWcLrVOvTaLZ/+kpvoZ252M7c0hUWaqkF2ZF9+cuLL5A/HGP4tWuPD9dN4kZSCk+ER8PDyg8MnCYl9dBljB3SCr289dOz1E24+fQ8T4/R9mMmh1tbal5kZXL2D4e8Sz7YIU15fw4U7QEiwf1oQ+PrgoVKDJhj+889YF7YAr8LX4u9bsYi+vA3T/riOGet3YwnTnF+3Cd3LCzFj8RaI2RqSA6lUltb9BmSQ0cCvTyFAKorF0nEDsPU+F0tWzUUFW2Zg9zsVWqSt+lNbVuAfTXX0DPZCCp/PCi3IxULwxXLdTjnDTjr+CsUWCwJFwkPMXbAXIcMHwYlIWN06GtIgSGFspNZvt3z6S75EPz+L7MtPTnyxyqeYR13Udv6AQ6cicIZGocDmzZBBUgtq2QfMnTgW8kotabfzMq5EHMesHzrolZAxsSiGtk1r0xbhERw7cBAan0bwp4b9GvlU4NCmRDmUs1fjTQIfQn4C4O6Dhl4l2AzhmVmjVs3KeB79GBrCRYnipZH4PiktuKnliUhJMoabi/ZjKJ8i+fASM4f0wb4XxbB5+xY09k6fZvM9Ci1qFBL8c/0yHpzeRnsIvqhRuz5WH7iK87vnI2TwVPD11O4MX6vYYkEQ9ywSN55GYcHIrqhRowYa9xiP9+8fYXjnEKw8ciNXu+XHX/Ir+pkf9JWfnPhiwY0JRK2b1MK+RXPwj9IHwf7MhzvSUcgFiI0RoGr9YLi5usLKRIMzp09DJNNT83JNUK9jN/CvHMXGwxEI/Eq7pFqBw7YYFLoZIiXNetrcfxkZgSfvrOBV1gXOHtVh9foeLj/VDvqrpALcvv8MFd08YEFbqs0D6+DW6YN4n0JtwYgjng3HU6taqOedPg8uFaaSWDBuEC4leWDLtvXw93DWbUm9j+9PaJFraoXJa47h+bOHiIyMRCQtsINb10LTvtMRvm467BhBQD18rWKLBUHpOj0Q+fAp7jN2ob+zfy6Aq6s3NuwPx5AWtfTazZorzZe/5Ef0Mz/kVn5y4osFNyYQ1WxUD29ePkSdoMYoa5M58puYOaNJo4rYOmckJs6Yjv8NG4jNNz/A1piP2A9amfLscHSrg0Yeybj53PSr7ZLyzKzQ64dBeHpkCYZMmIgpEyag/+iF8B8xDW19isOxYiCGtS+FqYP6YeL06Rg9uC8231BgxLDeMOMZwa/9UJRXP0DvAWMwedxIjJq6Bb2Gj4IHY0PaJTt3aAs2HjwHOXXAKzvXYM2RW3AuaY39G5YgNDSU/a3cEQ4FzxK9+g7E3d1zMXz8REwaPxoDfl6LNqN+Qt2y3/ZL18yAMzOBOPVnZW7Magba2aY/XMkJM5uSGDmmD9ZNGYlxP0/B8N69cFteAwO6BLD+xIhVLl28AFE6ufxvCe1XwdLtorUHBxY22q+B6bMb67f6/CWT7wGu1UPQobIMowYOxPTp0zC4T2+c5ZfBmEFd/5WIZ27lJycKVaySGSjnGlmgau2GcLU1gXkxZzhYOKNl124o72zNbufwzNnt5VyKoWaTFihnrEaSTI1Kjdti4ugf4OFoC7cqfuw0iMwClVq4PC6eXjsFoVtz/NyP6eoWXHgjpKBEADlwLFMVLZtWBT8uFhpjF/T6cRKGdmRaBlzWmWo1aY+qJW1Z4c5SFf0xZdpk1K9cgi1cJpaOaNG8CYggAQojGqBG/ILebeuAHY7UKBD9OBJCbjHUqFgKSQkJsCtTES7MtJEM2DqXRu0q5eHkXnhCi0UpVpkZpvuSk3gps40H90o14OXmqK0McxFbzCxWmTFt2ZyrCMiPn2YUfbXNOC7E8qndqN/qE+bM6HuV3GBkYqlX9DMd/XZj7tGYvUdfWLLlWX/5yY5vXqxSJBTg49u76N9nBLrM2YVhId4F6mCGF5Lzx7fmP98LBj/NSqG/flWoqKTYueBHBLUagaqtxmFA08pFVnMaMGDg6+ObFqtUK6QQShQwt7SGaQ7N03+DQQQwfxjEKosGg59mxSBWmQsGEcD8YfCfosHgp1kxiFXmgmEsI38Y/KdoMPhpVpKSkvB/i69Td1mswfAAAAAASUVORK5CYII=

    Thanks.

  • DECLARE @test-2 TABLE
    (
    EmpName varchar(50),
    Deduction MONEY,
    YearMonth int
    )
    DECLARE @CurrentYearMonth INT,
    @PreviousYearMonth INT

    SELECT @CurrentYearMonth = 201805, @PreviousYearMonth = 201804

    INSERT @test-2 Values('John', 259.05, 201803)
    INSERT @test-2 Values('John', 325.50, 201804)
    INSERT @test-2 Values('John', 325.50, 201805)
    INSERT @test-2 Values('Mary', 410.10, 201804)
    INSERT @test-2 Values('Mary', 380.25, 201805)

    SELECT EmpName, 
           Deduction,
           PreviousDeduction,
           POWER(Deduction-T.Average,2)+POWER(PreviousDeduction-T.Average,2) AS Variance
    FROM @test-2 t1
    CROSS APPLY(SELECT Deduction PreviousDeduction
         FROM @test-2 t2
         WHERE t1.EmpName = t2.EmpName
         AND YearMonth = @PreviousYearMonth
       ) AS PreviousDeduction
    CROSS APPLY(VALUES ((Deduction+PreviousDeduction)/2.0)) T(Average)
    WHERE YearMonth = @CurrentYearMonth


  • It looks like it works. Just not sure why.

    I understand what the cross applys are doing just not sure why a couple of things are for.

    For example, not sure what the T(Average) is in the second apply, but I see how it is used.

    The same as the alias PreviousDeduction is for in the 1st apply.

    I assume the 1st cross apply is used instead of the sub query, so it can be used later in the select statement.

    Thanks,

    Tom

  • tshad - Tuesday, July 31, 2018 8:52 PM

    It looks like it works. Just not sure why.

    I understand what the cross applys are doing just not sure why a couple of things are for.

    For example, not sure what the T(Average) is in the second apply, but I see how it is used.

    The same as the alias PreviousDeduction is for in the 1st apply.

    I assume the 1st cross apply is used instead of the sub query, so it can be used later in the select statement.

    Thanks,

    Tom

    T(Average) is getting the mean of Deduction, PreviousDeduction. This is used in the calculation of the Variance. As the average needs to be subtracted twice (once from each number) in the calculation of variance it saves space.
    Likewise with PreviousDeduction, this is used to calculate the average and used in the select.

  • I did get my query to work using this and I figured out how the calculation worked,

    I was confused on the syntax of the 2nd Cross Apply:

    CROSS APPLY(VALUES ((Deduction+PreviousDeduction)/2.0)) AS f(Average)

    Then the value is accessed by f.Average.  I had never seen it used that way.  I always use an alias (such as "a").  Is this because there is no name returned just a value?

    Also, I assume you used the Cross Apply so you would have immediate access, instead of using a derived table.

    Thanks

  • tshad - Wednesday, August 1, 2018 11:44 AM

    I did get my query to work using this and I figured out how the calculation worked,

    I was confused on the syntax of the 2nd Cross Apply:

    CROSS APPLY(VALUES ((Deduction+PreviousDeduction)/2.0)) AS f(Average)

    Then the value is accessed by f.Average.  I had never seen it used that way.  I always use an alias (such as "a").  Is this because there is no name returned just a value?

    Also, I assume you used the Cross Apply so you would have immediate access, instead of using a derived table.

    Thanks

    When you have CROSS APPLY with VALUES instead of a SELECT you need to use the T(C) method of generating a TableName.ColumnName, instead of giving the column alias next to the column name.
    Instead of:
    SELECT t1.EmpName,
           t1.Deduction,
           PreviousDeduction.PreviousDeduction,
           POWER(t1.Deduction-T.Average,2)+POWER(PreviousDeduction.PreviousDeduction-T.Average,2) AS Variance
    FROM @test-2 t1
    CROSS APPLY(SELECT t2.Deduction PreviousDeduction
                  FROM @test-2 t2
                 WHERE t2.EmpName = t1.EmpName
                   AND t2.YearMonth = @PreviousYearMonth) AS PreviousDeduction
    CROSS APPLY(VALUES ((t1.Deduction+PreviousDeduction.PreviousDeduction)/2.0)) T(Average)
    WHERE t1.YearMonth = @CurrentYearMonth

    You could write it without CROSS APPLY as:

    SELECT t1.EmpName,
           t1.Deduction,
           t2.PreviousDeduction,
           POWER(t1.Deduction-(t1.Deduction+t2.PreviousDeduction)/2.0,2)+POWER(t2.PreviousDeduction-(t1.Deduction+t2.PreviousDeduction)/2.0,2) AS Variance
      FROM @test-2 t1
    INNER JOIN (SELECT t2.Deduction PreviousDeduction,
                        t2.EmpName,
                        t2.YearMonth
                    FROM @test-2 t2) AS t2
             ON t1.EmpName = t2.EmpName
            AND t2.YearMonth = @PreviousYearMonth
    WHERE t1.YearMonth = @CurrentYearMonth

    or like this:
    SELECT t1.EmpName,
           t1.Deduction,
           t2.Deduction PreviousDeduction,
           POWER(t1.Deduction-(t1.Deduction+t2.Deduction)/2.0,2)+POWER(t2.Deduction-(t1.Deduction+t2.Deduction)/2.0,2) AS Variance
    FROM @test-2 t1
    INNER JOIN @test-2 t2
             ON t1.EmpName = t2.EmpName
            AND t2.YearMonth = @PreviousYearMonth
    WHERE t1.YearMonth = @CurrentYearMonth

  • tshad - Wednesday, August 1, 2018 11:44 AM

    Then the value is accessed by f.Average.  I had never seen it used that way.  I always use an alias (such as "a").  Is this because there is no name returned just a value?

    It helps to realise these two SELECTs are equivalent:

    Drop Table If Exists #Temp
    Create Table #Temp(value int)
    Insert Into #Temp Values (1),(2),(3)

    Select 
    T.value,
    CA.Doubled,
    CA.Trebled
    From #Temp T
    Cross Apply (Select value * 2 As Doubled, value * 3 As Trebled) As CA

    Select 
    T.value,
    CA.Doubled,
    CA.Trebled
    From #Temp T
    Cross Apply (Select value * 2, value * 3) As CA(Doubled,Trebled)


    In the latter, the columns are named as part of the alias rather than inline with the select. This is particularly useful for things like a VALUES clause where there isn't a way to name columns inline. You also see it a lot with things like XML expansion using the nodes function.
  • Okay, I'm totally confused.   Since when has the term "variance" come to mean something other than the difference for a set of exactly two values?   If we were talking about a set of 20 or 50 or 100 values, I'd start thinking standard deviation, but for exactly two values, what would a mathematical "variance" actually mean?   How could it be used, or for that matter, why?  Any reason to NOT use just the mere difference?

    Steve (aka sgmunson) 🙂 🙂 🙂
    Rent Servers for Income (picks and shovels strategy)

  • sgmunson - Monday, August 6, 2018 9:43 AM

    Okay, I'm totally confused.   Since when has the term "variance" come to mean something other than the difference for a set of exactly two values?   If we were talking about a set of 20 or 50 or 100 values, I'd start thinking standard deviation, but for exactly two values, what would a mathematical "variance" actually mean?   How could it be used, or for that matter, why?  Any reason to NOT use just the mere difference?

    If you have n items (X_1, X_2,..,X_n) the Variance is: SUM((X_i - Mean)^2)/(N-1) 
    The variance is a measure of the spread from the mean. The Standard Deviation is the square root of the variance.
    The "difference" gives a different answer to the "variance" and difference has no relation to the mean.

  • It can be done without using a self join, using just windowed functions:
    ;WITH CTE AS
    (
        SELECT t1.EmpName,
               t1.Deduction,
               t1.YearMonth,
               LAG(t1.YearMonth) OVER (PARTITION BY t1.EmpName ORDER BY t1.YearMonth) AS PreviousYearMonth,
               LAG(t1.Deduction) OVER (PARTITION BY t1.EmpName ORDER BY t1.YearMonth) AS PreviousDeduction,
               VAR(t1.Deduction) OVER(PARTITION BY t1.EmpName ORDER BY t1.YearMonth ROWS BETWEEN 1 PRECEDING AND CURRENT ROW) AS Variance
          FROM @test-2 t1
    )
    SELECT CTE.EmpName,
            CTE.Deduction,
            CTE.PreviousDeduction,
            CTE.Variance
       FROM CTE
      WHERE CTE.YearMonth = @CurrentYearMonth
        AND CTE.PreviousYearMonth = @PreviousYearMonth

  • Jonathan AC Roberts - Monday, August 6, 2018 10:21 AM

    It can be done without using a self join, using just windowed functions:
    ;WITH CTE AS
    (
        SELECT t1.EmpName,
               t1.Deduction,
               t1.YearMonth,
               LAG(t1.YearMonth) OVER (PARTITION BY t1.EmpName ORDER BY t1.YearMonth) AS PreviousYearMonth,
               LAG(t1.Deduction) OVER (PARTITION BY t1.EmpName ORDER BY t1.YearMonth) AS PreviousDeduction,
               VAR(t1.Deduction) OVER(PARTITION BY t1.EmpName ORDER BY t1.YearMonth ROWS BETWEEN 1 PRECEDING AND CURRENT ROW) AS Variance
          FROM @test-2 t1
    )
    SELECT CTE.EmpName,
            CTE.Deduction,
            CTE.PreviousDeduction,
            CTE.Variance
       FROM CTE
      WHERE CTE.YearMonth = @CurrentYearMonth
        AND CTE.PreviousYearMonth = @PreviousYearMonth

    You do realize that I offered a similar solution five days ago?  It does require that he be on SQL 2012, which is not likely given that he posted in a SQL 2008 forum.

    Drew

    J. Drew Allen
    Business Intelligence Analyst
    Philadelphia, PA

  • drew.allen - Monday, August 6, 2018 1:37 PM

    Jonathan AC Roberts - Monday, August 6, 2018 10:21 AM

    It can be done without using a self join, using just windowed functions:
    ;WITH CTE AS
    (
        SELECT t1.EmpName,
               t1.Deduction,
               t1.YearMonth,
               LAG(t1.YearMonth) OVER (PARTITION BY t1.EmpName ORDER BY t1.YearMonth) AS PreviousYearMonth,
               LAG(t1.Deduction) OVER (PARTITION BY t1.EmpName ORDER BY t1.YearMonth) AS PreviousDeduction,
               VAR(t1.Deduction) OVER(PARTITION BY t1.EmpName ORDER BY t1.YearMonth ROWS BETWEEN 1 PRECEDING AND CURRENT ROW) AS Variance
          FROM @test-2 t1
    )
    SELECT CTE.EmpName,
            CTE.Deduction,
            CTE.PreviousDeduction,
            CTE.Variance
       FROM CTE
      WHERE CTE.YearMonth = @CurrentYearMonth
        AND CTE.PreviousYearMonth = @PreviousYearMonth

    You do realize that I offered a similar solution five days ago?  It does require that he be on SQL 2012, which is not likely given that he posted in a SQL 2008 forum.

    Drew

    I did see that but it doesn't work as your WHERE clause restricts YearMonth to be @CurrentYearMonth. So it can't get the previous month.

Viewing 15 posts - 1 through 15 (of 19 total)

You must be logged in to reply to this topic. Login to reply